-- Migration 089: Immutable Schedules with Per-State Product Discovery -- -- Key changes: -- 1. Add is_immutable column - schedules can be edited but not deleted -- 2. Add method column - all tasks use 'http' (Puppeteer transport) -- 3. Store discovery weekly (168h) -- 4. Per-state product_discovery schedules (4h default) -- 5. Remove old payload_fetch schedules -- ===================================================== -- 1) Add new columns to task_schedules -- ===================================================== ALTER TABLE task_schedules ADD COLUMN IF NOT EXISTS is_immutable BOOLEAN DEFAULT FALSE; ALTER TABLE task_schedules ADD COLUMN IF NOT EXISTS method VARCHAR(10) DEFAULT 'http'; -- ===================================================== -- 2) Update store_discovery to weekly and immutable -- ===================================================== UPDATE task_schedules SET interval_hours = 168, -- 7 days is_immutable = TRUE, method = 'http', description = 'Discover new Dutchie stores weekly (HTTP transport)' WHERE name IN ('store_discovery_dutchie', 'Store Discovery'); -- Insert if doesn't exist INSERT INTO task_schedules (name, role, interval_hours, priority, description, is_immutable, method, platform, next_run_at) VALUES ('Store Discovery', 'store_discovery', 168, 5, 'Discover new Dutchie stores weekly (HTTP transport)', TRUE, 'http', 'dutchie', NOW()) ON CONFLICT (name) DO UPDATE SET interval_hours = 168, is_immutable = TRUE, method = 'http', description = 'Discover new Dutchie stores weekly (HTTP transport)'; -- ===================================================== -- 3) Remove old payload_fetch and product_refresh_all schedules -- ===================================================== DELETE FROM task_schedules WHERE name IN ('payload_fetch_all', 'product_refresh_all'); -- ===================================================== -- 4) Create per-state product_discovery schedules -- ===================================================== -- One schedule per state that has dispensaries with active cannabis programs INSERT INTO task_schedules (name, role, state_code, interval_hours, priority, description, is_immutable, method, enabled, next_run_at) SELECT 'product_discovery_' || lower(s.code) AS name, 'product_discovery' AS role, s.code AS state_code, 4 AS interval_hours, -- 4 hours default, editable 10 AS priority, 'Product discovery for ' || s.name || ' dispensaries (HTTP transport)' AS description, TRUE AS is_immutable, -- Can edit but not delete 'http' AS method, CASE WHEN s.is_active THEN TRUE ELSE FALSE END AS enabled, -- Stagger start times: each state starts 5 minutes after the previous NOW() + (ROW_NUMBER() OVER (ORDER BY s.code) * INTERVAL '5 minutes') AS next_run_at FROM states s WHERE EXISTS ( SELECT 1 FROM dispensaries d WHERE d.state_id = s.id AND d.crawl_enabled = true ) ON CONFLICT (name) DO UPDATE SET is_immutable = TRUE, method = 'http', description = EXCLUDED.description; -- Also create schedules for states that might have stores discovered later INSERT INTO task_schedules (name, role, state_code, interval_hours, priority, description, is_immutable, method, enabled, next_run_at) SELECT 'product_discovery_' || lower(s.code) AS name, 'product_discovery' AS role, s.code AS state_code, 4 AS interval_hours, 10 AS priority, 'Product discovery for ' || s.name || ' dispensaries (HTTP transport)' AS description, TRUE AS is_immutable, 'http' AS method, FALSE AS enabled, -- Disabled until stores exist NOW() + INTERVAL '1 hour' FROM states s WHERE NOT EXISTS ( SELECT 1 FROM task_schedules ts WHERE ts.name = 'product_discovery_' || lower(s.code) ) ON CONFLICT (name) DO NOTHING; -- ===================================================== -- 5) Make analytics_refresh immutable -- ===================================================== UPDATE task_schedules SET is_immutable = TRUE, method = 'http' WHERE name = 'analytics_refresh'; -- ===================================================== -- 6) Add index for schedule lookups -- ===================================================== CREATE INDEX IF NOT EXISTS idx_task_schedules_state_code ON task_schedules(state_code) WHERE state_code IS NOT NULL; -- Comments COMMENT ON COLUMN task_schedules.is_immutable IS 'If TRUE, schedule cannot be deleted (only edited)'; COMMENT ON COLUMN task_schedules.method IS 'Transport method: http (Puppeteer/browser) or curl (axios)';