Files
cannaiq/backend/migrations/012_create_dispensary_changes_table.sql
Kelly bf4ceaf09e fix: Make all migrations idempotent
- 008: Add IF NOT EXISTS to ALTER TABLE ADD COLUMN
- 011: Add IF NOT EXISTS to CREATE TABLE and INDEX
- 012: Add IF NOT EXISTS, DROP TRIGGER IF EXISTS
- 013: Add ON CONFLICT (azdhs_id) DO NOTHING
- 014: Add IF NOT EXISTS to ALTER TABLE ADD COLUMN

All migrations can now be safely re-run without errors.

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2025-12-07 23:48:35 -07:00

51 lines
2.2 KiB
PL/PgSQL

-- Create dispensary_changes table for change approval workflow
-- This protects against accidental data destruction by requiring manual review
CREATE TABLE IF NOT EXISTS dispensary_changes (
id SERIAL PRIMARY KEY,
dispensary_id INTEGER NOT NULL REFERENCES dispensaries(id) ON DELETE CASCADE,
-- What changed
field_name VARCHAR(100) NOT NULL, -- 'dba_name', 'website', 'phone', 'menu_url', etc.
old_value TEXT, -- Previous value (null if new field)
new_value TEXT, -- Proposed new value
-- Where it came from
source VARCHAR(50) NOT NULL, -- 'google_maps', 'manual_edit', 'azdhs_update', 'dutchie_scraper'
confidence_score VARCHAR(20), -- 'high', 'medium', 'low' (for automated changes)
change_notes TEXT, -- Optional explanation
-- Approval workflow
status VARCHAR(20) DEFAULT 'pending' NOT NULL CHECK (status IN ('pending', 'approved', 'rejected')),
requires_recrawl BOOLEAN DEFAULT FALSE, -- TRUE for website/menu_url changes
-- Audit trail
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
reviewed_at TIMESTAMP,
reviewed_by INTEGER REFERENCES users(id),
rejection_reason TEXT
);
-- Create indexes for common queries
CREATE INDEX IF NOT EXISTS idx_dispensary_changes_status ON dispensary_changes(status);
CREATE INDEX IF NOT EXISTS idx_dispensary_changes_dispensary_status ON dispensary_changes(dispensary_id, status);
CREATE INDEX IF NOT EXISTS idx_dispensary_changes_created_at ON dispensary_changes(created_at DESC);
CREATE INDEX IF NOT EXISTS idx_dispensary_changes_requires_recrawl ON dispensary_changes(requires_recrawl) WHERE requires_recrawl = TRUE;
-- Create function to automatically set requires_recrawl for website/menu_url changes
CREATE OR REPLACE FUNCTION set_requires_recrawl()
RETURNS TRIGGER AS $$
BEGIN
IF NEW.field_name IN ('website', 'menu_url') THEN
NEW.requires_recrawl := TRUE;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Create trigger to call the function (drop first to make idempotent)
DROP TRIGGER IF EXISTS trigger_set_requires_recrawl ON dispensary_changes;
CREATE TRIGGER trigger_set_requires_recrawl
BEFORE INSERT ON dispensary_changes
FOR EACH ROW
EXECUTE FUNCTION set_requires_recrawl();