118 lines
4.1 KiB
SQL
118 lines
4.1 KiB
SQL
-- =============================================================
|
|
-- SEO SLUG MIGRATION SCRIPT
|
|
-- Run this directly in your PostgreSQL database
|
|
-- =============================================================
|
|
|
|
-- First, let's see how many listings need slugs
|
|
SELECT 'Businesses without slugs: ' || COUNT(*) FROM businesses_json
|
|
WHERE data->>'slug' IS NULL OR data->>'slug' = '';
|
|
|
|
SELECT 'Commercial properties without slugs: ' || COUNT(*) FROM commercials_json
|
|
WHERE data->>'slug' IS NULL OR data->>'slug' = '';
|
|
|
|
-- =============================================================
|
|
-- UPDATE BUSINESS LISTINGS WITH SEO SLUGS
|
|
-- Format: title-city-state-shortid (e.g., restaurant-austin-tx-a3f7b2c1)
|
|
-- =============================================================
|
|
|
|
UPDATE businesses_json
|
|
SET data = jsonb_set(
|
|
data::jsonb,
|
|
'{slug}',
|
|
to_jsonb(
|
|
LOWER(
|
|
REGEXP_REPLACE(
|
|
REGEXP_REPLACE(
|
|
CONCAT(
|
|
-- Title (first 50 chars, cleaned)
|
|
SUBSTRING(
|
|
REGEXP_REPLACE(
|
|
LOWER(COALESCE(data->>'title', '')),
|
|
'[^a-z0-9\s-]', '', 'g'
|
|
), 1, 50
|
|
),
|
|
'-',
|
|
-- City or County
|
|
REGEXP_REPLACE(
|
|
LOWER(COALESCE(data->'location'->>'name', data->'location'->>'county', '')),
|
|
'[^a-z0-9\s-]', '', 'g'
|
|
),
|
|
'-',
|
|
-- State
|
|
LOWER(COALESCE(data->'location'->>'state', '')),
|
|
'-',
|
|
-- First 8 chars of UUID
|
|
SUBSTRING(id::text, 1, 8)
|
|
),
|
|
'\s+', '-', 'g' -- Replace spaces with hyphens
|
|
),
|
|
'-+', '-', 'g' -- Replace multiple hyphens with single
|
|
)
|
|
)
|
|
)
|
|
)
|
|
WHERE data->>'slug' IS NULL OR data->>'slug' = '';
|
|
|
|
-- =============================================================
|
|
-- UPDATE COMMERCIAL PROPERTIES WITH SEO SLUGS
|
|
-- =============================================================
|
|
|
|
UPDATE commercials_json
|
|
SET data = jsonb_set(
|
|
data::jsonb,
|
|
'{slug}',
|
|
to_jsonb(
|
|
LOWER(
|
|
REGEXP_REPLACE(
|
|
REGEXP_REPLACE(
|
|
CONCAT(
|
|
-- Title (first 50 chars, cleaned)
|
|
SUBSTRING(
|
|
REGEXP_REPLACE(
|
|
LOWER(COALESCE(data->>'title', '')),
|
|
'[^a-z0-9\s-]', '', 'g'
|
|
), 1, 50
|
|
),
|
|
'-',
|
|
-- City or County
|
|
REGEXP_REPLACE(
|
|
LOWER(COALESCE(data->'location'->>'name', data->'location'->>'county', '')),
|
|
'[^a-z0-9\s-]', '', 'g'
|
|
),
|
|
'-',
|
|
-- State
|
|
LOWER(COALESCE(data->'location'->>'state', '')),
|
|
'-',
|
|
-- First 8 chars of UUID
|
|
SUBSTRING(id::text, 1, 8)
|
|
),
|
|
'\s+', '-', 'g' -- Replace spaces with hyphens
|
|
),
|
|
'-+', '-', 'g' -- Replace multiple hyphens with single
|
|
)
|
|
)
|
|
)
|
|
)
|
|
WHERE data->>'slug' IS NULL OR data->>'slug' = '';
|
|
|
|
-- =============================================================
|
|
-- VERIFY THE RESULTS
|
|
-- =============================================================
|
|
|
|
SELECT 'Migration complete! Checking results...' AS status;
|
|
|
|
-- Show sample of updated slugs
|
|
SELECT
|
|
id,
|
|
data->>'title' AS title,
|
|
data->>'slug' AS slug
|
|
FROM businesses_json
|
|
LIMIT 5;
|
|
|
|
SELECT
|
|
id,
|
|
data->>'title' AS title,
|
|
data->>'slug' AS slug
|
|
FROM commercials_json
|
|
LIMIT 5;
|