- 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>
102 lines
2.6 KiB
SQL
102 lines
2.6 KiB
SQL
-- Populate dispensaries table from azdhs_list
|
|
-- This migrates all 182 AZDHS records with their enriched Google Maps data
|
|
-- For multi-location dispensaries with duplicate slugs, append city name to make unique
|
|
-- IDEMPOTENT: Uses ON CONFLICT DO NOTHING to skip already-imported records
|
|
|
|
WITH ranked_dispensaries AS (
|
|
SELECT
|
|
id,
|
|
name,
|
|
company_name,
|
|
address,
|
|
city,
|
|
state,
|
|
zip,
|
|
status_line,
|
|
azdhs_url,
|
|
latitude,
|
|
longitude,
|
|
dba_name,
|
|
phone,
|
|
email,
|
|
website,
|
|
google_rating,
|
|
google_review_count,
|
|
slug,
|
|
created_at,
|
|
updated_at,
|
|
ROW_NUMBER() OVER (PARTITION BY slug, city ORDER BY id) as city_row_num,
|
|
COUNT(*) OVER (PARTITION BY slug, city) as city_count,
|
|
ROW_NUMBER() OVER (PARTITION BY slug ORDER BY id) as global_row_num
|
|
FROM azdhs_list
|
|
)
|
|
INSERT INTO dispensaries (
|
|
azdhs_id,
|
|
name,
|
|
company_name,
|
|
address,
|
|
city,
|
|
state,
|
|
zip,
|
|
status_line,
|
|
azdhs_url,
|
|
latitude,
|
|
longitude,
|
|
dba_name,
|
|
phone,
|
|
email,
|
|
website,
|
|
google_rating,
|
|
google_review_count,
|
|
slug,
|
|
created_at,
|
|
updated_at
|
|
)
|
|
SELECT
|
|
id, -- azdhs_id (FK to source table)
|
|
name,
|
|
company_name,
|
|
address,
|
|
city,
|
|
state,
|
|
zip,
|
|
status_line,
|
|
azdhs_url,
|
|
latitude,
|
|
longitude,
|
|
dba_name, -- From Google Maps enrichment
|
|
phone, -- From Google Maps enrichment
|
|
email, -- From Google Maps enrichment (rare)
|
|
website, -- From Google Maps enrichment
|
|
google_rating,
|
|
google_review_count,
|
|
-- Make slug unique by appending city and/or number for multi-location dispensaries
|
|
CASE
|
|
WHEN global_row_num = 1 THEN slug -- First location keeps original slug
|
|
WHEN city_count = 1 THEN slug || '-' || LOWER(REGEXP_REPLACE(city, '[^a-zA-Z0-9]+', '-', 'g')) -- Single location in city, append city
|
|
ELSE slug || '-' || LOWER(REGEXP_REPLACE(city, '[^a-zA-Z0-9]+', '-', 'g')) || '-' || city_row_num::text -- Multiple in city, append city and number
|
|
END as slug,
|
|
created_at,
|
|
updated_at
|
|
FROM ranked_dispensaries
|
|
ORDER BY id
|
|
ON CONFLICT (azdhs_id) DO NOTHING;
|
|
|
|
-- Verify the migration (idempotent - just logs, doesn't fail)
|
|
DO $$
|
|
DECLARE
|
|
source_count INTEGER;
|
|
dest_count INTEGER;
|
|
BEGIN
|
|
SELECT COUNT(*) INTO source_count FROM azdhs_list;
|
|
SELECT COUNT(*) INTO dest_count FROM dispensaries;
|
|
|
|
RAISE NOTICE 'Migration status: % records in azdhs_list, % records in dispensaries', source_count, dest_count;
|
|
|
|
IF dest_count >= source_count THEN
|
|
RAISE NOTICE 'OK: dispensaries table has expected records';
|
|
ELSE
|
|
RAISE WARNING 'dispensaries has fewer records than azdhs_list (% vs %)', dest_count, source_count;
|
|
END IF;
|
|
END $$;
|