diff --git a/backend/migrations/029_link_dutchie_stores_to_dispensaries.sql b/backend/migrations/029_link_dutchie_stores_to_dispensaries.sql new file mode 100644 index 00000000..27426846 --- /dev/null +++ b/backend/migrations/029_link_dutchie_stores_to_dispensaries.sql @@ -0,0 +1,56 @@ +-- ===================================================== +-- Link Dutchie Stores to Dispensaries +-- ===================================================== +-- Creates dispensary records for stores with dutchie_url that +-- don't yet have a dispensary_id, then links them. + +-- Create dispensaries for unlinked stores with dutchie_url +DO $$ +DECLARE + store_rec RECORD; + new_slug TEXT; + new_disp_id INTEGER; +BEGIN + FOR store_rec IN + SELECT id, name, dutchie_url + FROM stores + WHERE dutchie_url IS NOT NULL AND dispensary_id IS NULL + LOOP + -- Extract slug from dutchie_url + new_slug := regexp_replace( + regexp_replace(store_rec.dutchie_url, '^https://dutchie\.com/(embedded-menu|dispensary)/', ''), + '/.*$', '' + ); + + -- Insert or update dispensary + INSERT INTO dispensaries (name, slug, address, city, state, provider_type, menu_url, created_at, updated_at) + VALUES ( + store_rec.name, + new_slug, + 'TBD', -- Address to be filled in later + 'TBD', -- City to be filled in later + 'AZ', -- Default state + 'dutchie', + store_rec.dutchie_url, + NOW(), + NOW() + ) + ON CONFLICT (slug) DO UPDATE SET + provider_type = 'dutchie', + menu_url = EXCLUDED.menu_url, + updated_at = NOW() + RETURNING id INTO new_disp_id; + + -- Link store to dispensary + UPDATE stores SET dispensary_id = new_disp_id WHERE id = store_rec.id; + + RAISE NOTICE 'Linked store % (%) to dispensary %', store_rec.id, store_rec.name, new_disp_id; + END LOOP; +END $$; + +-- Report on linked stores +SELECT s.id as store_id, s.name as store_name, s.dispensary_id, d.slug as disp_slug +FROM stores s +JOIN dispensaries d ON d.id = s.dispensary_id +WHERE s.dutchie_url IS NOT NULL +ORDER BY s.id;