-- ============================================================================ -- Migration 052: Add Cannabis Legalization Flags to States -- ============================================================================ -- -- Purpose: Add recreational/medical cannabis legalization status and years -- to the existing states table, then seed all 50 states + DC. -- -- SAFETY RULES: -- - Uses ADD COLUMN IF NOT EXISTS (idempotent) -- - Uses INSERT ... ON CONFLICT (code) DO UPDATE (idempotent) -- - NO DROP, DELETE, TRUNCATE, or destructive operations -- - Safe to run multiple times -- -- Run with: -- psql "$DATABASE_URL" -f migrations/052_add_state_cannabis_flags.sql -- -- ============================================================================ -- ============================================================================ -- SECTION 1: Add cannabis legalization columns -- ============================================================================ ALTER TABLE states ADD COLUMN IF NOT EXISTS recreational_legal BOOLEAN; ALTER TABLE states ADD COLUMN IF NOT EXISTS rec_year INTEGER; ALTER TABLE states ADD COLUMN IF NOT EXISTS medical_legal BOOLEAN; ALTER TABLE states ADD COLUMN IF NOT EXISTS med_year INTEGER; COMMENT ON COLUMN states.recreational_legal IS 'Whether recreational cannabis is legal in this state'; COMMENT ON COLUMN states.rec_year IS 'Year recreational cannabis was legalized (NULL if not legal)'; COMMENT ON COLUMN states.medical_legal IS 'Whether medical cannabis is legal in this state'; COMMENT ON COLUMN states.med_year IS 'Year medical cannabis was legalized (NULL if not legal)'; -- ============================================================================ -- SECTION 2: Seed all 50 states + DC with cannabis legalization data -- ============================================================================ -- Data sourced from state legalization records as of 2024 -- States ordered by medical legalization year, then alphabetically INSERT INTO states (code, name, timezone, recreational_legal, rec_year, medical_legal, med_year) VALUES -- Recreational + Medical States (ordered by rec year) ('WA', 'Washington', 'America/Los_Angeles', TRUE, 2012, TRUE, 1998), ('CO', 'Colorado', 'America/Denver', TRUE, 2012, TRUE, 2000), ('AK', 'Alaska', 'America/Anchorage', TRUE, 2014, TRUE, 1998), ('OR', 'Oregon', 'America/Los_Angeles', TRUE, 2014, TRUE, 1998), ('DC', 'District of Columbia', 'America/New_York', TRUE, 2015, TRUE, 2011), ('CA', 'California', 'America/Los_Angeles', TRUE, 2016, TRUE, 1996), ('NV', 'Nevada', 'America/Los_Angeles', TRUE, 2016, TRUE, 1998), ('ME', 'Maine', 'America/New_York', TRUE, 2016, TRUE, 1999), ('MA', 'Massachusetts', 'America/New_York', TRUE, 2016, TRUE, 2012), ('MI', 'Michigan', 'America/Detroit', TRUE, 2018, TRUE, 2008), ('IL', 'Illinois', 'America/Chicago', TRUE, 2019, TRUE, 2013), ('AZ', 'Arizona', 'America/Phoenix', TRUE, 2020, TRUE, 2010), ('MT', 'Montana', 'America/Denver', TRUE, 2020, TRUE, 2004), ('NJ', 'New Jersey', 'America/New_York', TRUE, 2020, TRUE, 2010), ('VT', 'Vermont', 'America/New_York', TRUE, 2020, TRUE, 2004), ('CT', 'Connecticut', 'America/New_York', TRUE, 2021, TRUE, 2012), ('NM', 'New Mexico', 'America/Denver', TRUE, 2021, TRUE, 2007), ('NY', 'New York', 'America/New_York', TRUE, 2021, TRUE, 2014), ('VA', 'Virginia', 'America/New_York', TRUE, 2021, TRUE, 2020), ('MD', 'Maryland', 'America/New_York', TRUE, 2022, TRUE, 2013), ('MO', 'Missouri', 'America/Chicago', TRUE, 2022, TRUE, 2018), ('RI', 'Rhode Island', 'America/New_York', TRUE, 2022, TRUE, 2006), ('DE', 'Delaware', 'America/New_York', TRUE, 2023, TRUE, 2011), ('MN', 'Minnesota', 'America/Chicago', TRUE, 2023, TRUE, 2014), ('OH', 'Ohio', 'America/New_York', TRUE, 2023, TRUE, 2016), -- Medical Only States (no recreational) ('HI', 'Hawaii', 'Pacific/Honolulu', FALSE, NULL, TRUE, 2000), ('NH', 'New Hampshire', 'America/New_York', FALSE, NULL, TRUE, 2013), ('GA', 'Georgia', 'America/New_York', FALSE, NULL, TRUE, 2015), ('LA', 'Louisiana', 'America/Chicago', FALSE, NULL, TRUE, 2015), ('TX', 'Texas', 'America/Chicago', FALSE, NULL, TRUE, 2015), ('AR', 'Arkansas', 'America/Chicago', FALSE, NULL, TRUE, 2016), ('FL', 'Florida', 'America/New_York', FALSE, NULL, TRUE, 2016), ('ND', 'North Dakota', 'America/Chicago', FALSE, NULL, TRUE, 2016), ('PA', 'Pennsylvania', 'America/New_York', FALSE, NULL, TRUE, 2016), ('IA', 'Iowa', 'America/Chicago', FALSE, NULL, TRUE, 2017), ('WV', 'West Virginia', 'America/New_York', FALSE, NULL, TRUE, 2017), ('OK', 'Oklahoma', 'America/Chicago', FALSE, NULL, TRUE, 2018), ('UT', 'Utah', 'America/Denver', FALSE, NULL, TRUE, 2018), ('SD', 'South Dakota', 'America/Chicago', FALSE, NULL, TRUE, 2020), ('AL', 'Alabama', 'America/Chicago', FALSE, NULL, TRUE, 2021), ('MS', 'Mississippi', 'America/Chicago', FALSE, NULL, TRUE, 2022), ('KY', 'Kentucky', 'America/New_York', FALSE, NULL, TRUE, 2023), ('NE', 'Nebraska', 'America/Chicago', FALSE, NULL, TRUE, 2024), -- No Cannabis Programs (neither rec nor medical) ('ID', 'Idaho', 'America/Boise', FALSE, NULL, FALSE, NULL), ('IN', 'Indiana', 'America/Indiana/Indianapolis', FALSE, NULL, FALSE, NULL), ('KS', 'Kansas', 'America/Chicago', FALSE, NULL, FALSE, NULL), ('NC', 'North Carolina', 'America/New_York', FALSE, NULL, FALSE, NULL), ('SC', 'South Carolina', 'America/New_York', FALSE, NULL, FALSE, NULL), ('TN', 'Tennessee', 'America/Chicago', FALSE, NULL, FALSE, NULL), ('WI', 'Wisconsin', 'America/Chicago', FALSE, NULL, FALSE, NULL), ('WY', 'Wyoming', 'America/Denver', FALSE, NULL, FALSE, NULL) ON CONFLICT (code) DO UPDATE SET name = EXCLUDED.name, timezone = COALESCE(states.timezone, EXCLUDED.timezone), recreational_legal = EXCLUDED.recreational_legal, rec_year = EXCLUDED.rec_year, medical_legal = EXCLUDED.medical_legal, med_year = EXCLUDED.med_year, updated_at = NOW(); -- ============================================================================ -- SECTION 3: Add indexes for common queries -- ============================================================================ CREATE INDEX IF NOT EXISTS idx_states_recreational ON states(recreational_legal) WHERE recreational_legal = TRUE; CREATE INDEX IF NOT EXISTS idx_states_medical ON states(medical_legal) WHERE medical_legal = TRUE; -- ============================================================================ -- SECTION 4: Verification query (informational only) -- ============================================================================ SELECT 'Migration 052 completed successfully.' AS status, (SELECT COUNT(*) FROM states WHERE recreational_legal = TRUE) AS rec_states, (SELECT COUNT(*) FROM states WHERE medical_legal = TRUE AND recreational_legal = FALSE) AS med_only_states, (SELECT COUNT(*) FROM states WHERE medical_legal = FALSE OR medical_legal IS NULL) AS no_program_states, (SELECT COUNT(*) FROM states) AS total_states;