migrations: fix conflict in migration files

This commit is contained in:
Sosokker 2025-04-01 18:19:28 +07:00
parent f8752a94de
commit 2c0a628613
18 changed files with 602 additions and 246 deletions

View File

@ -11,7 +11,9 @@ CREATE TABLE users (
);
CREATE UNIQUE INDEX idx_users_uuid ON users(uuid);
CREATE UNIQUE INDEX idx_users_email ON users(email); -- Added unique constraint for email
-- +goose Down
DROP INDEX IF EXISTS idx_users_email;
DROP INDEX IF EXISTS idx_users_uuid;
DROP TABLE IF EXISTS users;

View File

@ -45,7 +45,7 @@ CREATE TABLE farms (
name TEXT NOT NULL,
lat DOUBLE PRECISION[] NOT NULL,
lon DOUBLE PRECISION[] NOT NULL,
plant_types UUID[],
plant_types UUID[], -- This column will be dropped in the next migration
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
owner_id UUID NOT NULL,
@ -55,10 +55,10 @@ CREATE TABLE farms (
CREATE TABLE croplands (
uuid UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name TEXT NOT NULL,
status TEXT NOT NULL,
status TEXT NOT NULL, -- Consider creating a status table if values are fixed
priority INT NOT NULL,
land_size DOUBLE PRECISION NOT NULL,
growth_stage TEXT NOT NULL,
growth_stage TEXT NOT NULL, -- Consider creating a growth_stage table
plant_id UUID NOT NULL,
farm_id UUID NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),

View File

@ -1,6 +1,8 @@
-- +goose Up
ALTER TABLE farms DROP COLUMN plant_types;
-- This column was initially created in 00002 but deemed unnecessary.
ALTER TABLE farms DROP COLUMN IF EXISTS plant_types; -- Use IF EXISTS for safety
-- +goose Down
-- Add the column back if rolling back.
ALTER TABLE farms
ADD COLUMN plant_types UUID[];

View File

@ -1,14 +1,16 @@
-- +goose Up
-- Creates the initial inventory_items table.
-- Note: 'category', 'type', 'unit', and 'status' columns will be modified/replaced by later migrations.
CREATE TABLE inventory_items (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL,
name TEXT NOT NULL,
category TEXT NOT NULL,
type TEXT NOT NULL,
category TEXT NOT NULL, -- To be replaced by category_id
type TEXT NOT NULL, -- To be dropped
quantity DOUBLE PRECISION NOT NULL,
unit TEXT NOT NULL,
unit TEXT NOT NULL, -- To be replaced by unit_id
date_added TIMESTAMPTZ NOT NULL,
status TEXT NOT NULL,
status TEXT NOT NULL, -- To be replaced by status_id
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
CONSTRAINT fk_inventory_items_user FOREIGN KEY (user_id) REFERENCES users(uuid) ON DELETE CASCADE
@ -18,3 +20,6 @@ CREATE TABLE inventory_items (
CREATE INDEX idx_inventory_items_user_id ON inventory_items(user_id);
CREATE INDEX idx_inventory_items_user_category ON inventory_items(user_id, category);
CREATE INDEX idx_inventory_items_user_status ON inventory_items(user_id, status);
-- +goose Down
DROP TABLE IF EXISTS inventory_items; -- Indexes are dropped automatically

View File

@ -1,17 +0,0 @@
-- +goose Up
ALTER TABLE farms
ADD COLUMN farm_type TEXT,
ADD COLUMN total_size TEXT;
ALTER TABLE farms
ALTER COLUMN lat TYPE DOUBLE PRECISION USING lat[1],
ALTER COLUMN lon TYPE DOUBLE PRECISION USING lon[1];
-- +goose Down
ALTER TABLE farms
ALTER COLUMN lat TYPE DOUBLE PRECISION[] USING ARRAY[lat],
ALTER COLUMN lon TYPE DOUBLE PRECISION[] USING ARRAY[lon];
ALTER TABLE farms
DROP COLUMN farm_type,
DROP COLUMN total_size;

View File

@ -14,14 +14,15 @@ CREATE INDEX idx_analytics_events_farm_id ON public.analytics_events(farm_id);
CREATE INDEX idx_analytics_events_event_type ON public.analytics_events(event_type);
CREATE INDEX idx_analytics_events_created_at ON public.analytics_events(created_at);
-- Create a simple materialized view for farm analytics
-- Create a simple materialized view for farm analytics (Version 1)
CREATE MATERIALIZED VIEW public.farm_analytics_view AS
SELECT
f.uuid AS farm_id,
f.name AS farm_name,
f.owner_id,
f.farm_type,
f.total_size,
-- Columns added in migration 00006 will be added to the view later
-- f.farm_type,
-- f.total_size,
f.created_at,
f.updated_at,
COUNT(ae.id) AS total_events,
@ -31,44 +32,45 @@ FROM
LEFT JOIN
public.analytics_events ae ON f.uuid = ae.farm_id
GROUP BY
f.uuid, f.name, f.owner_id, f.farm_type, f.total_size, f.created_at, f.updated_at;
f.uuid, f.name, f.owner_id, f.created_at, f.updated_at;
-- Create index for faster queries
-- Create index for faster queries on the view
-- UNIQUE index is required for CONCURRENTLY refresh
CREATE UNIQUE INDEX idx_farm_analytics_view_farm_id ON public.farm_analytics_view(farm_id);
CREATE INDEX idx_farm_analytics_view_owner_id ON public.farm_analytics_view(owner_id);
-- Create function to refresh the materialized view
-- Create function to refresh the materialized view CONCURRENTLY
-- +goose StatementBegin
CREATE OR REPLACE FUNCTION public.refresh_farm_analytics_view()
RETURNS TRIGGER AS $$
BEGIN
REFRESH MATERIALIZED VIEW public.farm_analytics_view;
RETURN NULL;
-- Use CONCURRENTLY to avoid locking the view during refresh
REFRESH MATERIALIZED VIEW CONCURRENTLY public.farm_analytics_view;
RETURN NULL; -- result is ignored since this is an AFTER trigger
END;
$$ LANGUAGE plpgsql;
-- +goose StatementEnd
-- Create trigger to refresh the view when new events are added
CREATE TRIGGER refresh_farm_analytics_view_trigger
CREATE TRIGGER refresh_farm_analytics_view_trigger_events
AFTER INSERT ON public.analytics_events
FOR EACH STATEMENT
EXECUTE FUNCTION public.refresh_farm_analytics_view();
-- Create trigger to refresh the view when farms are updated
CREATE TRIGGER refresh_farm_analytics_view_farms_trigger
-- Note: This trigger will need to be updated if the view definition changes significantly
CREATE TRIGGER refresh_farm_analytics_view_trigger_farms
AFTER INSERT OR UPDATE OR DELETE ON public.farms
FOR EACH STATEMENT
EXECUTE FUNCTION public.refresh_farm_analytics_view();
-- +goose Down
-- Drop triggers first
DROP TRIGGER IF EXISTS refresh_farm_analytics_view_trigger ON public.analytics_events;
DROP TRIGGER IF EXISTS refresh_farm_analytics_view_farms_trigger ON public.farms;
DROP TRIGGER IF EXISTS refresh_farm_analytics_view_trigger_events ON public.analytics_events;
DROP TRIGGER IF EXISTS refresh_farm_analytics_view_trigger_farms ON public.farms;
-- Drop function
-- +goose StatementBegin
DROP FUNCTION IF EXISTS public.refresh_farm_analytics_view() CASCADE;
-- +goose StatementEnd
-- Drop materialized view
DROP MATERIALIZED VIEW IF EXISTS public.farm_analytics_view CASCADE;

View File

@ -1,5 +0,0 @@
-- +goose Up
CREATE TABLE inventory_status (
id SERIAL PRIMARY KEY,
name TEXT NOT NULL UNIQUE
);

View File

@ -1,106 +0,0 @@
-- +goose Up
-- Drop the existing materialized view
DROP MATERIALIZED VIEW IF EXISTS public.farm_analytics_view;
-- Create a new materialized view that matches the GetFarmAnalytics function
CREATE MATERIALIZED VIEW public.farm_analytics_view AS
SELECT
f.uuid AS farm_id,
f.name AS farm_name,
f.owner_id,
COALESCE(MAX(ae.created_at), f.updated_at) AS last_updated,
-- Weather data aggregation
(
SELECT jsonb_build_object(
'temperature', AVG((ae_w.event_data->>'temperature')::float) FILTER (WHERE ae_w.event_data ? 'temperature'),
'humidity', AVG((ae_w.event_data->>'humidity')::float) FILTER (WHERE ae_w.event_data ? 'humidity'),
'forecast', jsonb_agg(ae_w.event_data->'forecast') FILTER (WHERE ae_w.event_data ? 'forecast')
)
FROM analytics_events ae_w
WHERE ae_w.farm_id = f.uuid AND ae_w.event_type = 'weather.updated'
GROUP BY ae_w.farm_id
) AS weather_data,
-- Inventory data aggregation
(
SELECT jsonb_build_object(
'items', COALESCE(jsonb_agg(ae_i.event_data->'items'), '[]'::jsonb),
'last_updated', MAX(ae_i.created_at)
)
FROM analytics_events ae_i
WHERE ae_i.farm_id = f.uuid AND ae_i.event_type = 'inventory.updated'
GROUP BY ae_i.farm_id
) AS inventory_data,
-- Plant health data aggregation
(
SELECT jsonb_build_object(
'status', MAX(ae_p.event_data->>'status'),
'issues', COALESCE(jsonb_agg(ae_p.event_data->'issues') FILTER (WHERE ae_p.event_data ? 'issues'), '[]'::jsonb)
)
FROM analytics_events ae_p
WHERE ae_p.farm_id = f.uuid AND ae_p.event_type = 'plant_health.updated'
GROUP BY ae_p.farm_id
) AS plant_health_data,
-- Financial data aggregation
(
SELECT jsonb_build_object(
'revenue', SUM((ae_f.event_data->>'revenue')::float) FILTER (WHERE ae_f.event_data ? 'revenue'),
'expenses', SUM((ae_f.event_data->>'expenses')::float) FILTER (WHERE ae_f.event_data ? 'expenses'),
'profit', SUM((ae_f.event_data->>'profit')::float) FILTER (WHERE ae_f.event_data ? 'profit')
)
FROM analytics_events ae_f
WHERE ae_f.farm_id = f.uuid AND ae_f.event_type = 'financial.updated'
GROUP BY ae_f.farm_id
) AS financial_data,
-- Production data aggregation
(
SELECT jsonb_build_object(
'yield', SUM((ae_pr.event_data->>'yield')::float) FILTER (WHERE ae_pr.event_data ? 'yield'),
'forecast', MAX(ae_pr.event_data->'forecast')
)
FROM analytics_events ae_pr
WHERE ae_pr.farm_id = f.uuid AND ae_pr.event_type = 'production.updated'
GROUP BY ae_pr.farm_id
) AS production_data
FROM
public.farms f
LEFT JOIN
public.analytics_events ae ON f.uuid = ae.farm_id
GROUP BY
f.uuid, f.name, f.owner_id;
-- Create indexes for faster queries
CREATE UNIQUE INDEX idx_farm_analytics_view_farm_id ON public.farm_analytics_view(farm_id);
CREATE INDEX idx_farm_analytics_view_owner_id ON public.farm_analytics_view(owner_id);
-- +goose Down
-- Drop the new materialized view
DROP MATERIALIZED VIEW IF EXISTS public.farm_analytics_view;
-- Restore the original materialized view
CREATE MATERIALIZED VIEW public.farm_analytics_view AS
SELECT
f.uuid AS farm_id,
f.name AS farm_name,
f.owner_id,
f.farm_type,
f.total_size,
f.created_at,
f.updated_at,
COUNT(ae.id) AS total_events,
MAX(ae.created_at) AS last_event_at
FROM
public.farms f
LEFT JOIN
public.analytics_events ae ON f.uuid = ae.farm_id
GROUP BY
f.uuid, f.name, f.owner_id, f.farm_type, f.total_size, f.created_at, f.updated_at;
-- Recreate indexes
CREATE UNIQUE INDEX idx_farm_analytics_view_farm_id ON public.farm_analytics_view(farm_id);
CREATE INDEX idx_farm_analytics_view_owner_id ON public.farm_analytics_view(owner_id);

View File

@ -1,15 +0,0 @@
-- +goose Up
ALTER TABLE inventory_items
ADD COLUMN status_id INT;
UPDATE inventory_items
SET status_id = (SELECT id FROM inventory_status WHERE name = inventory_items.status);
ALTER TABLE inventory_items
DROP COLUMN status;
ALTER TABLE inventory_items
ADD CONSTRAINT fk_inventory_items_status FOREIGN KEY (status_id) REFERENCES inventory_status(id) ON DELETE CASCADE;
CREATE INDEX idx_inventory_items_status_id ON inventory_items(status_id);

View File

@ -0,0 +1,25 @@
-- +goose Up
-- Add new columns for farm details
ALTER TABLE farms
ADD COLUMN farm_type TEXT,
ADD COLUMN total_size TEXT; -- Consider NUMERIC or DOUBLE PRECISION if it's always a number
-- Change lat/lon from array to single value
-- Assumes the first element of the array was the intended value
ALTER TABLE farms
ALTER COLUMN lat TYPE DOUBLE PRECISION USING lat[1],
ALTER COLUMN lon TYPE DOUBLE PRECISION USING lon[1];
-- Note: The farm_analytics_view created in 00005 does not yet include these new columns.
-- Subsequent migrations will update the view.
-- +goose Down
-- Revert lat/lon change
ALTER TABLE farms
ALTER COLUMN lat TYPE DOUBLE PRECISION[] USING ARRAY[lat],
ALTER COLUMN lon TYPE DOUBLE PRECISION[] USING ARRAY[lon];
-- Remove added columns
ALTER TABLE farms
DROP COLUMN IF EXISTS farm_type,
DROP COLUMN IF EXISTS total_size;

View File

@ -1,7 +1,18 @@
-- +goose Up
-- Insert default statuses into the inventory_status table
INSERT INTO inventory_status (name)
VALUES
('In Stock'),
('Low Stock'),
('Out Of Stock');
-- Create the lookup table for inventory item statuses
CREATE TABLE inventory_status (
id SERIAL PRIMARY KEY,
name TEXT NOT NULL UNIQUE
);
-- Insert common default statuses needed for the next migration (00008)
INSERT INTO inventory_status (name) VALUES
('In Stock'),
('Low Stock'),
('Out of Stock'),
('Expired'),
('Reserved');
-- Add any other statuses that might exist in the old 'status' text column
-- +goose Down
DROP TABLE IF EXISTS inventory_status;

View File

@ -1,70 +0,0 @@
-- +goose Up
-- Step 1: Create inventory_category table
CREATE TABLE inventory_category (
id SERIAL PRIMARY KEY,
name TEXT NOT NULL UNIQUE
);
-- Step 2: Insert sample categories
INSERT INTO inventory_category (name)
VALUES
('Seeds'),
('Tools'),
('Chemicals');
-- Step 3: Add category_id column to inventory_items
ALTER TABLE inventory_items
ADD COLUMN category_id INT;
-- Step 4: Link inventory_items to inventory_category
ALTER TABLE inventory_items
ADD CONSTRAINT fk_inventory_category FOREIGN KEY (category_id) REFERENCES inventory_category(id) ON DELETE SET NULL;
-- Step 5: Remove old columns (type, category, unit) from inventory_items
ALTER TABLE inventory_items
DROP COLUMN type,
DROP COLUMN category,
DROP COLUMN unit;
-- Step 6: Add unit_id column to inventory_items
ALTER TABLE inventory_items
ADD COLUMN unit_id INT;
-- Step 7: Link inventory_items to harvest_units
ALTER TABLE inventory_items
ADD CONSTRAINT fk_inventory_unit FOREIGN KEY (unit_id) REFERENCES harvest_units(id) ON DELETE SET NULL;
-- Step 8: Insert new unit values into harvest_units
INSERT INTO harvest_units (name)
VALUES
('Tonne'),
('KG');
-- +goose Down
-- Reverse Step 8: Remove inserted unit values
DELETE FROM harvest_units WHERE name IN ('Tonne', 'KG');
-- Reverse Step 7: Remove the foreign key constraint
ALTER TABLE inventory_items
DROP CONSTRAINT fk_inventory_unit;
-- Reverse Step 6: Remove unit_id column from inventory_items
ALTER TABLE inventory_items
DROP COLUMN unit_id;
-- Reverse Step 5: Add back type, category, and unit columns
ALTER TABLE inventory_items
ADD COLUMN type TEXT NOT NULL,
ADD COLUMN category TEXT NOT NULL,
ADD COLUMN unit TEXT NOT NULL;
-- Reverse Step 4: Remove foreign key constraint from inventory_items
ALTER TABLE inventory_items
DROP CONSTRAINT fk_inventory_category;
-- Reverse Step 3: Remove category_id column from inventory_items
ALTER TABLE inventory_items
DROP COLUMN category_id;
-- Reverse Step 2: Drop inventory_category table
DROP TABLE inventory_category;

View File

@ -0,0 +1,46 @@
-- +goose Up
-- Add the status_id column to link to the new inventory_status table
ALTER TABLE inventory_items
ADD COLUMN status_id INT;
-- Update the new status_id based on the old text status column
-- This relies on the inventory_status table being populated (done in 00007)
UPDATE inventory_items inv
SET status_id = (SELECT id FROM inventory_status stat WHERE stat.name = inv.status)
WHERE EXISTS (SELECT 1 FROM inventory_status stat WHERE stat.name = inv.status);
-- Handle cases where the old status might not be in the new table (optional: set to a default or log)
-- UPDATE inventory_items SET status_id = <default_status_id> WHERE status_id IS NULL;
-- Drop the old text status column
ALTER TABLE inventory_items
DROP COLUMN status;
-- Add the foreign key constraint
-- Make status_id NOT NULL if every item must have a status
ALTER TABLE inventory_items
ADD CONSTRAINT fk_inventory_items_status FOREIGN KEY (status_id) REFERENCES inventory_status(id) ON DELETE SET NULL; -- Or ON DELETE RESTRICT
-- Create an index on the new foreign key column
CREATE INDEX idx_inventory_items_status_id ON inventory_items(status_id);
-- +goose Down
-- Drop the index
DROP INDEX IF EXISTS idx_inventory_items_status_id;
-- Drop the foreign key constraint
ALTER TABLE inventory_items
DROP CONSTRAINT IF EXISTS fk_inventory_items_status;
-- Add the old status column back
ALTER TABLE inventory_items
ADD COLUMN status TEXT; -- Make NOT NULL if it was originally
-- Attempt to restore the status text from status_id (data loss if status was deleted)
UPDATE inventory_items inv
SET status = (SELECT name FROM inventory_status stat WHERE stat.id = inv.status_id)
WHERE inv.status_id IS NOT NULL;
-- Drop the status_id column
ALTER TABLE inventory_items
DROP COLUMN status_id;

View File

@ -0,0 +1,119 @@
-- +goose Up
-- Description: Recreates farm_analytics_view (Version 2) to include aggregated data
-- from analytics_events and new columns from the farms table.
-- Drop the existing materialized view (from migration 00005)
DROP MATERIALIZED VIEW IF EXISTS public.farm_analytics_view;
-- Recreate the materialized view with aggregated data
CREATE MATERIALIZED VIEW public.farm_analytics_view AS
SELECT
f.uuid AS farm_id,
f.name AS farm_name,
f.owner_id,
f.farm_type, -- Added in 00006
f.total_size, -- Added in 00006
-- Determine last update time based on farm update or latest event
COALESCE(
(SELECT MAX(ae_max.created_at) FROM public.analytics_events ae_max WHERE ae_max.farm_id = f.uuid),
f.updated_at
) AS last_updated,
-- Weather data aggregation (Example: Average Temp/Humidity, Forecast List)
(
SELECT jsonb_build_object(
'temperature_avg', AVG((ae_w.event_data->>'temperature')::float) FILTER (WHERE ae_w.event_data ? 'temperature'),
'humidity_avg', AVG((ae_w.event_data->>'humidity')::float) FILTER (WHERE ae_w.event_data ? 'humidity'),
'forecasts', jsonb_agg(ae_w.event_data->'forecast') FILTER (WHERE ae_w.event_data ? 'forecast')
)
FROM analytics_events ae_w
WHERE ae_w.farm_id = f.uuid AND ae_w.event_type = 'weather.updated' -- Ensure event type is correct
-- GROUP BY ae_w.farm_id -- Not needed inside subquery selecting for one farm
) AS weather_data,
-- Inventory data aggregation (Example: Item List, Last Update)
(
SELECT jsonb_build_object(
'items', COALESCE(jsonb_agg(ae_i.event_data->'items' ORDER BY (ae_i.event_data->>'timestamp') DESC) FILTER (WHERE ae_i.event_data ? 'items'), '[]'::jsonb),
'last_updated', MAX(ae_i.created_at)
)
FROM analytics_events ae_i
WHERE ae_i.farm_id = f.uuid AND ae_i.event_type = 'inventory.updated' -- Ensure event type is correct
-- GROUP BY ae_i.farm_id
) AS inventory_data,
-- Plant health data aggregation (Example: Latest Status, Issues List)
(
SELECT jsonb_build_object(
'status', MAX(ae_p.event_data->>'status'), -- MAX works on text, gets latest alphabetically if not timestamped
'issues', COALESCE(jsonb_agg(ae_p.event_data->'issues') FILTER (WHERE ae_p.event_data ? 'issues'), '[]'::jsonb)
-- Consider adding 'last_updated': MAX(ae_p.created_at)
)
FROM analytics_events ae_p
WHERE ae_p.farm_id = f.uuid AND ae_p.event_type = 'plant_health.updated' -- Ensure event type is correct
-- GROUP BY ae_p.farm_id
) AS plant_health_data,
-- Financial data aggregation (Example: Sums)
(
SELECT jsonb_build_object(
'revenue', SUM((ae_f.event_data->>'revenue')::float) FILTER (WHERE ae_f.event_data ? 'revenue'),
'expenses', SUM((ae_f.event_data->>'expenses')::float) FILTER (WHERE ae_f.event_data ? 'expenses'),
'profit', SUM((ae_f.event_data->>'profit')::float) FILTER (WHERE ae_f.event_data ? 'profit')
-- Consider adding 'last_updated': MAX(ae_f.created_at)
)
FROM analytics_events ae_f
WHERE ae_f.farm_id = f.uuid AND ae_f.event_type = 'financial.updated' -- Ensure event type is correct
-- GROUP BY ae_f.farm_id
) AS financial_data,
-- Production data aggregation (Example: Sum Yield, Latest Forecast)
(
SELECT jsonb_build_object(
'yield_total', SUM((ae_pr.event_data->>'yield')::float) FILTER (WHERE ae_pr.event_data ? 'yield'),
'forecast_latest', MAX(ae_pr.event_data->>'forecast') FILTER (WHERE ae_pr.event_data ? 'forecast') -- MAX on text
-- Consider adding 'last_updated': MAX(ae_pr.created_at)
)
FROM analytics_events ae_pr
WHERE ae_pr.farm_id = f.uuid AND ae_pr.event_type = 'production.updated' -- Ensure event type is correct
-- GROUP BY ae_pr.farm_id
) AS production_data
FROM
public.farms f; -- No need for LEFT JOIN and GROUP BY on the main query for this structure
-- Recreate indexes for faster queries on the new view structure
CREATE UNIQUE INDEX idx_farm_analytics_view_farm_id ON public.farm_analytics_view(farm_id);
CREATE INDEX idx_farm_analytics_view_owner_id ON public.farm_analytics_view(owner_id);
-- The refresh function and triggers from migration 00005 should still work
-- as they target the view by name ('public.farm_analytics_view').
-- +goose Down
-- Drop the recreated materialized view
DROP MATERIALIZED VIEW IF EXISTS public.farm_analytics_view;
-- Restore the original simple materialized view (from migration 00005)
CREATE MATERIALIZED VIEW public.farm_analytics_view AS
SELECT
f.uuid AS farm_id,
f.name AS farm_name,
f.owner_id,
-- farm_type and total_size did not exist in the view definition from 00005
f.created_at,
f.updated_at,
COUNT(ae.id) AS total_events,
MAX(ae.created_at) AS last_event_at
FROM
public.farms f
LEFT JOIN
public.analytics_events ae ON f.uuid = ae.farm_id
GROUP BY
f.uuid, f.name, f.owner_id, f.created_at, f.updated_at;
-- Recreate indexes for the restored view
CREATE UNIQUE INDEX idx_farm_analytics_view_farm_id ON public.farm_analytics_view(farm_id);
CREATE INDEX idx_farm_analytics_view_owner_id ON public.farm_analytics_view(owner_id);
-- The refresh function and triggers from 00005 are assumed to still exist
-- and will target this restored view definition.

View File

@ -0,0 +1,16 @@
-- +goose Up
-- Add a column to store geographical features (marker or polygon) for a cropland.
-- Example JSON structure:
-- {"type": "marker", "position": {"lat": 13.84, "lng": 100.48}}
-- or
-- {"type": "polygon", "path": [{"lat": 13.81, "lng": 100.40}, ...]}
ALTER TABLE croplands
ADD COLUMN geo_feature JSONB;
-- Consider adding a GIN index if querying within the JSON often
-- CREATE INDEX idx_croplands_geo_feature ON croplands USING GIN (geo_feature);
-- +goose Down
-- Remove the geo_feature column
ALTER TABLE croplands
DROP COLUMN IF EXISTS geo_feature;

View File

@ -0,0 +1,157 @@
-- +goose Up
-- Description: Updates the farm_analytics_view (Version 3) to remove financial data
-- and fetch the *latest* weather data instead of aggregating.
-- Drop the existing view (from migration 00009)
DROP MATERIALIZED VIEW IF EXISTS public.farm_analytics_view;
-- Recreate the materialized view with updated logic
CREATE MATERIALIZED VIEW public.farm_analytics_view AS
SELECT
f.uuid AS farm_id,
f.name AS farm_name,
f.owner_id,
f.farm_type,
f.total_size,
-- Determine last update time based on farm update or latest event
COALESCE(
(SELECT MAX(ae_max.created_at) FROM public.analytics_events ae_max WHERE ae_max.farm_id = f.uuid),
f.updated_at
) AS last_updated,
-- Weather data: Select the *latest* 'weather.updated' event data for the farm
(
SELECT jsonb_build_object(
'last_updated', latest_weather.created_at, -- Use the event timestamp
'temperature', (latest_weather.event_data->>'temperature')::float,
'humidity', (latest_weather.event_data->>'humidity')::float,
'rainfall', (latest_weather.event_data->>'rainfall')::float, -- Assuming 'rainfall' exists
'wind_speed', (latest_weather.event_data->>'wind_speed')::float,
'weather_status', latest_weather.event_data->>'weather_status', -- Assuming 'weather_status' exists
'alert_level', latest_weather.event_data->>'alert_level', -- Assuming 'alert_level' exists
'forecast_summary', latest_weather.event_data->>'forecast_summary' -- Assuming 'forecast_summary' exists
-- Add more fields here, ensuring they exist in your 'weather.updated' event_data JSON
)
FROM (
-- Find the most recent weather event for this farm
SELECT ae_w.event_data, ae_w.created_at
FROM public.analytics_events ae_w
WHERE ae_w.farm_id = f.uuid AND ae_w.event_type = 'weather.updated' -- Make sure event_type is correct
ORDER BY ae_w.created_at DESC
LIMIT 1
) AS latest_weather
) AS weather_data, -- This will be NULL if no 'weather.updated' event exists for the farm
-- Inventory data aggregation (Keep logic from V2 or refine)
(
SELECT jsonb_build_object(
'items', COALESCE(jsonb_agg(ae_i.event_data->'items' ORDER BY (ae_i.event_data->>'timestamp') DESC) FILTER (WHERE ae_i.event_data ? 'items'), '[]'::jsonb),
'last_updated', MAX(ae_i.created_at)
)
FROM analytics_events ae_i
WHERE ae_i.farm_id = f.uuid AND ae_i.event_type = 'inventory.updated' -- Ensure event type is correct
) AS inventory_data,
-- Plant health data aggregation (Keep logic from V2 or refine)
(
SELECT jsonb_build_object(
'status', MAX(ae_p.event_data->>'status'),
'issues', COALESCE(jsonb_agg(ae_p.event_data->'issues') FILTER (WHERE ae_p.event_data ? 'issues'), '[]'::jsonb),
'last_updated', MAX(ae_p.created_at)
)
FROM analytics_events ae_p
WHERE ae_p.farm_id = f.uuid AND ae_p.event_type = 'plant_health.updated' -- Ensure event type is correct
) AS plant_health_data,
-- Financial data aggregation -- REMOVED --
-- Production data aggregation (Keep logic from V2 or refine)
(
SELECT jsonb_build_object(
'yield_total', SUM((ae_pr.event_data->>'yield')::float) FILTER (WHERE ae_pr.event_data ? 'yield'),
'forecast_latest', MAX(ae_pr.event_data->>'forecast') FILTER (WHERE ae_pr.event_data ? 'forecast'),
'last_updated', MAX(ae_pr.created_at)
)
FROM analytics_events ae_pr
WHERE ae_pr.farm_id = f.uuid AND ae_pr.event_type = 'production.updated' -- Ensure event type is correct
) AS production_data
FROM
public.farms f;
-- Recreate indexes for faster queries on the new view structure
CREATE UNIQUE INDEX idx_farm_analytics_view_farm_id ON public.farm_analytics_view(farm_id);
CREATE INDEX idx_farm_analytics_view_owner_id ON public.farm_analytics_view(owner_id);
-- The refresh function and triggers from migration 00005 should still work.
-- +goose Down
-- Revert to the previous version (from migration 00009)
-- Drop the modified view
DROP MATERIALIZED VIEW IF EXISTS public.farm_analytics_view;
-- Recreate the view from migration 00009 (including financial data and aggregated weather)
CREATE MATERIALIZED VIEW public.farm_analytics_view AS
SELECT
f.uuid AS farm_id,
f.name AS farm_name,
f.owner_id,
f.farm_type,
f.total_size,
COALESCE(
(SELECT MAX(ae_max.created_at) FROM public.analytics_events ae_max WHERE ae_max.farm_id = f.uuid),
f.updated_at
) AS last_updated,
(
SELECT jsonb_build_object(
'temperature_avg', AVG((ae_w.event_data->>'temperature')::float) FILTER (WHERE ae_w.event_data ? 'temperature'),
'humidity_avg', AVG((ae_w.event_data->>'humidity')::float) FILTER (WHERE ae_w.event_data ? 'humidity'),
'forecasts', jsonb_agg(ae_w.event_data->'forecast') FILTER (WHERE ae_w.event_data ? 'forecast')
)
FROM analytics_events ae_w
WHERE ae_w.farm_id = f.uuid AND ae_w.event_type = 'weather.updated'
) AS weather_data,
(
SELECT jsonb_build_object(
'items', COALESCE(jsonb_agg(ae_i.event_data->'items' ORDER BY (ae_i.event_data->>'timestamp') DESC) FILTER (WHERE ae_i.event_data ? 'items'), '[]'::jsonb),
'last_updated', MAX(ae_i.created_at)
)
FROM analytics_events ae_i
WHERE ae_i.farm_id = f.uuid AND ae_i.event_type = 'inventory.updated'
) AS inventory_data,
(
SELECT jsonb_build_object(
'status', MAX(ae_p.event_data->>'status'),
'issues', COALESCE(jsonb_agg(ae_p.event_data->'issues') FILTER (WHERE ae_p.event_data ? 'issues'), '[]'::jsonb),
'last_updated', MAX(ae_p.created_at)
)
FROM analytics_events ae_p
WHERE ae_p.farm_id = f.uuid AND ae_p.event_type = 'plant_health.updated'
) AS plant_health_data,
(
SELECT jsonb_build_object(
'revenue', SUM((ae_f.event_data->>'revenue')::float) FILTER (WHERE ae_f.event_data ? 'revenue'),
'expenses', SUM((ae_f.event_data->>'expenses')::float) FILTER (WHERE ae_f.event_data ? 'expenses'),
'profit', SUM((ae_f.event_data->>'profit')::float) FILTER (WHERE ae_f.event_data ? 'profit'),
'last_updated', MAX(ae_f.created_at)
)
FROM analytics_events ae_f
WHERE ae_f.farm_id = f.uuid AND ae_f.event_type = 'financial.updated'
) AS financial_data,
(
SELECT jsonb_build_object(
'yield_total', SUM((ae_pr.event_data->>'yield')::float) FILTER (WHERE ae_pr.event_data ? 'yield'),
'forecast_latest', MAX(ae_pr.event_data->>'forecast') FILTER (WHERE ae_pr.event_data ? 'forecast'),
'last_updated', MAX(ae_pr.created_at)
)
FROM analytics_events ae_pr
WHERE ae_pr.farm_id = f.uuid AND ae_pr.event_type = 'production.updated'
) AS production_data
FROM
public.farms f;
-- Recreate indexes for the V2 view structure
CREATE UNIQUE INDEX idx_farm_analytics_view_farm_id ON public.farm_analytics_view(farm_id);
CREATE INDEX idx_farm_analytics_view_owner_id ON public.farm_analytics_view(owner_id);
-- The refresh function and triggers from 00005 are assumed to still exist.

View File

@ -0,0 +1,64 @@
-- +goose Up
-- Description: Creates a materialized view for crop-level analytics,
-- pulling data directly from croplands and plants tables.
CREATE MATERIALIZED VIEW public.crop_analytics_view AS
SELECT
c.uuid AS crop_id,
c.name AS crop_name,
c.farm_id,
p.name AS plant_name,
p.variety AS variety, -- Include variety from plants table
c.status AS current_status,
c.growth_stage,
c.land_size,
c.geo_feature, -- Include geo_feature added in 00010
c.updated_at AS last_updated -- Use cropland's updated_at as the primary refresh indicator
-- Add columns here if CropAnalytics struct includes more fields derived directly
-- from croplands or plants tables. Event-derived data would need different handling.
FROM
public.croplands c
JOIN
public.plants p ON c.plant_id = p.uuid;
-- Create indexes for efficient querying
CREATE UNIQUE INDEX idx_crop_analytics_view_crop_id ON public.crop_analytics_view(crop_id);
CREATE INDEX idx_crop_analytics_view_farm_id ON public.crop_analytics_view(farm_id);
CREATE INDEX idx_crop_analytics_view_plant_name ON public.crop_analytics_view(plant_name); -- Added index
-- Create a dedicated function to refresh this new view
-- +goose StatementBegin
CREATE OR REPLACE FUNCTION public.refresh_crop_analytics_view()
RETURNS TRIGGER AS $$
BEGIN
-- Use CONCURRENTLY to avoid locking the view during refresh
REFRESH MATERIALIZED VIEW CONCURRENTLY public.crop_analytics_view;
RETURN NULL; -- result is ignored since this is an AFTER trigger
END;
$$ LANGUAGE plpgsql;
-- +goose StatementEnd
-- Create triggers to refresh the view when underlying data changes
-- Trigger on Croplands table changes
CREATE TRIGGER refresh_crop_analytics_trigger_croplands
AFTER INSERT OR UPDATE OR DELETE ON public.croplands
FOR EACH STATEMENT -- Refresh once per statement that modifies the table
EXECUTE FUNCTION public.refresh_crop_analytics_view();
-- Trigger on Plants table changes (e.g., if plant name/variety is updated)
CREATE TRIGGER refresh_crop_analytics_trigger_plants
AFTER INSERT OR UPDATE OR DELETE ON public.plants
FOR EACH STATEMENT
EXECUTE FUNCTION public.refresh_crop_analytics_view();
-- +goose Down
-- Drop triggers first
DROP TRIGGER IF EXISTS refresh_crop_analytics_trigger_croplands ON public.croplands;
DROP TRIGGER IF EXISTS refresh_crop_analytics_trigger_plants ON public.plants;
-- Drop the refresh function
DROP FUNCTION IF EXISTS public.refresh_crop_analytics_view();
-- Drop the materialized view and its indexes
DROP MATERIALIZED VIEW IF EXISTS public.crop_analytics_view; -- Indexes are dropped automatically

View File

@ -0,0 +1,120 @@
-- +goose Up
-- Step 1: Create inventory_category table
CREATE TABLE inventory_category (
id SERIAL PRIMARY KEY,
name TEXT NOT NULL UNIQUE
);
-- Step 2: Insert sample categories (add more as needed)
INSERT INTO inventory_category (name)
VALUES
('Seeds'),
('Fertilizers'),
('Pesticides'),
('Herbicides'),
('Tools'),
('Equipment'),
('Fuel'),
('Harvested Goods'), -- If harvested items go into inventory
('Other');
-- Step 3: Add category_id column to inventory_items
ALTER TABLE inventory_items
ADD COLUMN category_id INT;
-- Step 4: Update category_id based on old 'category' text (best effort)
-- Map known old categories to new IDs. Set others to 'Other' or NULL.
UPDATE inventory_items inv SET category_id = (SELECT id FROM inventory_category cat WHERE cat.name = inv.category)
WHERE EXISTS (SELECT 1 FROM inventory_category cat WHERE cat.name = inv.category);
-- Example: Set remaining to 'Other'
-- UPDATE inventory_items SET category_id = (SELECT id FROM inventory_category WHERE name = 'Other') WHERE category_id IS NULL;
-- Step 5: Add foreign key constraint for category_id
ALTER TABLE inventory_items
ADD CONSTRAINT fk_inventory_category FOREIGN KEY (category_id) REFERENCES inventory_category(id) ON DELETE SET NULL; -- Or RESTRICT
-- Step 6: Add unit_id column to inventory_items (linking to harvest_units)
ALTER TABLE inventory_items
ADD COLUMN unit_id INT;
-- Step 7: Insert common inventory units into harvest_units table (if they don't exist)
-- harvest_units was created in 00002, potentially with crop-specific units. Add general ones here.
INSERT INTO harvest_units (name) VALUES
('Piece(s)'),
('Bag(s)'),
('Box(es)'),
('Liter(s)'),
('Gallon(s)'),
('kg'), -- Use consistent casing, e.g., lowercase
('tonne'),
('meter(s)'),
('hour(s)')
ON CONFLICT (name) DO NOTHING; -- Avoid errors if units already exist
-- Step 8: Update unit_id based on old 'unit' text (best effort)
UPDATE inventory_items inv SET unit_id = (SELECT id FROM harvest_units hu WHERE hu.name = inv.unit)
WHERE EXISTS (SELECT 1 FROM harvest_units hu WHERE hu.name = inv.unit);
-- Handle cases where the old unit might not be in the harvest_units table (optional)
-- UPDATE inventory_items SET unit_id = <default_unit_id> WHERE unit_id IS NULL;
-- Step 9: Add foreign key constraint for unit_id
ALTER TABLE inventory_items
ADD CONSTRAINT fk_inventory_unit FOREIGN KEY (unit_id) REFERENCES harvest_units(id) ON DELETE SET NULL; -- Or RESTRICT
-- Step 10: Remove old columns (type, category, unit) from inventory_items
ALTER TABLE inventory_items
DROP COLUMN type,
DROP COLUMN category,
DROP COLUMN unit;
-- Step 11: Add indexes for new foreign keys
CREATE INDEX idx_inventory_items_category_id ON inventory_items(category_id);
CREATE INDEX idx_inventory_items_unit_id ON inventory_items(unit_id);
-- +goose Down
-- Reverse Step 11: Drop indexes
DROP INDEX IF EXISTS idx_inventory_items_category_id;
DROP INDEX IF EXISTS idx_inventory_items_unit_id;
-- Reverse Step 10: Add back type, category, and unit columns
-- Mark as NOT NULL if they were originally required
ALTER TABLE inventory_items
ADD COLUMN type TEXT,
ADD COLUMN category TEXT,
ADD COLUMN unit TEXT;
-- Attempt to restore data (best effort, potential data loss)
UPDATE inventory_items inv SET category = (SELECT name FROM inventory_category cat WHERE cat.id = inv.category_id)
WHERE inv.category_id IS NOT NULL;
UPDATE inventory_items inv SET unit = (SELECT name FROM harvest_units hu WHERE hu.id = inv.unit_id)
WHERE inv.unit_id IS NOT NULL;
-- Cannot restore 'type' as it was dropped without replacement.
-- Reverse Step 9: Remove the foreign key constraint for unit
ALTER TABLE inventory_items
DROP CONSTRAINT IF EXISTS fk_inventory_unit;
-- Reverse Step 8: (Data restoration attempted above)
-- Reverse Step 7: (Cannot easily remove only units added here without knowing originals)
-- DELETE FROM harvest_units WHERE name IN ('Piece(s)', 'Bag(s)', ...); -- Risky if names overlapped
-- Reverse Step 6: Remove unit_id column from inventory_items
ALTER TABLE inventory_items
DROP COLUMN unit_id;
-- Reverse Step 5: Remove foreign key constraint for category
ALTER TABLE inventory_items
DROP CONSTRAINT IF EXISTS fk_inventory_category;
-- Reverse Step 4: (Data restoration attempted above)
-- Reverse Step 3: Remove category_id column from inventory_items
ALTER TABLE inventory_items
DROP COLUMN category_id;
-- Reverse Step 2: (Data in inventory_category table is kept unless explicitly dropped)
-- Reverse Step 1: Drop inventory_category table
DROP TABLE IF EXISTS inventory_category;