Files
SkyArtShop/backend/migrations/006_database_fixes.sql

381 lines
12 KiB
MySQL
Raw Normal View History

2026-01-04 17:52:37 -06:00
-- =====================================================
-- DATABASE FIXES FOR SKYARTSHOP
-- Date: January 4, 2026
-- Purpose: Add missing indexes, foreign keys, and constraints
-- =====================================================
-- =====================================================
-- PART 1: ADD MISSING FOREIGN KEYS
-- =====================================================
-- Add foreign key constraint for product_images -> products
-- This ensures referential integrity and enables CASCADE deletes
2026-01-04 18:09:47 -06:00
DO $$
2026-01-04 17:52:37 -06:00
BEGIN
IF NOT EXISTS (
SELECT 1 FROM information_schema.table_constraints
WHERE constraint_name = 'fk_product_images_product'
AND table_name = 'product_images'
) THEN
ALTER TABLE product_images
ADD CONSTRAINT fk_product_images_product
FOREIGN KEY (product_id) REFERENCES products(id)
ON DELETE CASCADE;
RAISE NOTICE 'Added foreign key: product_images -> products';
ELSE
RAISE NOTICE 'Foreign key product_images -> products already exists';
END IF;
END $$;
-- Add foreign key constraint for uploads -> media_folders
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM information_schema.table_constraints
WHERE constraint_name = 'fk_uploads_folder'
AND table_name = 'uploads'
) THEN
-- First ensure all uploads have valid folder_id or NULL
UPDATE uploads
SET folder_id = NULL
WHERE folder_id NOT IN (SELECT id FROM media_folders);
ALTER TABLE uploads
ADD CONSTRAINT fk_uploads_folder
FOREIGN KEY (folder_id) REFERENCES media_folders(id)
ON DELETE SET NULL;
RAISE NOTICE 'Added foreign key: uploads -> media_folders';
ELSE
RAISE NOTICE 'Foreign key uploads -> media_folders already exists';
END IF;
END $$;
-- =====================================================
-- PART 2: ADD MISSING INDEXES FOR PERFORMANCE
-- =====================================================
-- Products table indexes
CREATE INDEX IF NOT EXISTS idx_products_isactive
ON products(isactive) WHERE isactive = true;
CREATE INDEX IF NOT EXISTS idx_products_isfeatured
ON products(isfeatured, createdat DESC)
WHERE isfeatured = true AND isactive = true;
CREATE INDEX IF NOT EXISTS idx_products_isbestseller
ON products(isbestseller, createdat DESC)
WHERE isbestseller = true AND isactive = true;
CREATE INDEX IF NOT EXISTS idx_products_category
ON products(category, createdat DESC)
WHERE isactive = true AND category IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_products_createdat
ON products(createdat DESC) WHERE isactive = true;
CREATE INDEX IF NOT EXISTS idx_products_price
ON products(price) WHERE isactive = true;
-- Portfolio projects indexes
CREATE INDEX IF NOT EXISTS idx_portfolio_isactive
ON portfolioprojects(isactive) WHERE isactive = true;
CREATE INDEX IF NOT EXISTS idx_portfolio_category
ON portfolioprojects(category) WHERE isactive = true;
CREATE INDEX IF NOT EXISTS idx_portfolio_displayorder
ON portfolioprojects(displayorder ASC, createdat DESC)
WHERE isactive = true;
CREATE INDEX IF NOT EXISTS idx_portfolio_createdat
ON portfolioprojects(createdat DESC) WHERE isactive = true;
-- Pages indexes
CREATE INDEX IF NOT EXISTS idx_pages_slug
ON pages(slug) WHERE isactive = true;
CREATE INDEX IF NOT EXISTS idx_pages_isactive
ON pages(isactive) WHERE isactive = true;
CREATE INDEX IF NOT EXISTS idx_pages_createdat
ON pages(createdat DESC) WHERE isactive = true;
-- Product images indexes (already exist, but verify)
CREATE INDEX IF NOT EXISTS idx_product_images_product_id
ON product_images(product_id);
CREATE INDEX IF NOT EXISTS idx_product_images_is_primary
ON product_images(product_id, is_primary) WHERE is_primary = true;
CREATE INDEX IF NOT EXISTS idx_product_images_display_order
ON product_images(product_id, display_order, created_at);
CREATE INDEX IF NOT EXISTS idx_product_images_color_variant
ON product_images(color_variant) WHERE color_variant IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_product_images_color_code
ON product_images(color_code) WHERE color_code IS NOT NULL;
-- Homepage sections indexes
CREATE INDEX IF NOT EXISTS idx_homepagesections_displayorder
ON homepagesections(displayorder ASC);
-- Team members indexes
CREATE INDEX IF NOT EXISTS idx_team_members_displayorder
ON team_members(display_order ASC, created_at DESC);
-- Uploads indexes (verify existing)
CREATE INDEX IF NOT EXISTS idx_uploads_filename
ON uploads(filename);
CREATE INDEX IF NOT EXISTS idx_uploads_folder_id
ON uploads(folder_id);
CREATE INDEX IF NOT EXISTS idx_uploads_created_at
ON uploads(created_at DESC);
CREATE INDEX IF NOT EXISTS idx_uploads_usage
ON uploads(used_in_type, used_in_id)
WHERE used_in_type IS NOT NULL;
-- Media folders indexes
CREATE INDEX IF NOT EXISTS idx_media_folders_parent_id
ON media_folders(parent_id);
CREATE INDEX IF NOT EXISTS idx_media_folders_path
ON media_folders(path);
-- Session table optimization (for express-session)
CREATE INDEX IF NOT EXISTS idx_session_expire
ON session(expire);
CREATE INDEX IF NOT EXISTS idx_session_sid
ON session(sid);
-- =====================================================
-- PART 3: ADD UNIQUE CONSTRAINTS
-- =====================================================
-- Ensure unique slugs (blogposts already has this)
DO $$
BEGIN
-- Products slug unique constraint
IF NOT EXISTS (
SELECT 1 FROM pg_constraint
WHERE conname = 'unique_products_slug'
) THEN
-- First, fix any duplicate slugs
WITH duplicates AS (
SELECT slug, COUNT(*) as cnt, array_agg(id) as ids
FROM products
WHERE slug IS NOT NULL
GROUP BY slug
HAVING COUNT(*) > 1
)
UPDATE products p
SET slug = p.slug || '-' || substring(p.id, 1, 8)
WHERE p.id IN (
SELECT unnest(ids[2:]) FROM duplicates
);
ALTER TABLE products
ADD CONSTRAINT unique_products_slug UNIQUE(slug);
RAISE NOTICE 'Added unique constraint on products.slug';
END IF;
-- Pages slug unique constraint
IF NOT EXISTS (
SELECT 1 FROM pg_constraint
WHERE conname = 'unique_pages_slug'
) THEN
-- Fix any duplicate slugs
WITH duplicates AS (
SELECT slug, COUNT(*) as cnt, array_agg(id) as ids
FROM pages
WHERE slug IS NOT NULL
GROUP BY slug
HAVING COUNT(*) > 1
)
UPDATE pages p
SET slug = p.slug || '-' || p.id::text
WHERE p.id IN (
SELECT unnest(ids[2:]) FROM duplicates
);
ALTER TABLE pages
ADD CONSTRAINT unique_pages_slug UNIQUE(slug);
RAISE NOTICE 'Added unique constraint on pages.slug';
END IF;
END $$;
-- =====================================================
-- PART 4: ADD CHECK CONSTRAINTS FOR DATA INTEGRITY
-- =====================================================
-- Products price and stock constraints
ALTER TABLE products DROP CONSTRAINT IF EXISTS check_products_price_positive;
ALTER TABLE products
ADD CONSTRAINT check_products_price_positive
CHECK (price >= 0);
ALTER TABLE products DROP CONSTRAINT IF EXISTS check_products_stock_nonnegative;
ALTER TABLE products
ADD CONSTRAINT check_products_stock_nonnegative
CHECK (stockquantity >= 0);
-- Product images variant constraints
ALTER TABLE product_images DROP CONSTRAINT IF EXISTS check_variant_price_positive;
ALTER TABLE product_images
ADD CONSTRAINT check_variant_price_positive
CHECK (variant_price IS NULL OR variant_price >= 0);
ALTER TABLE product_images DROP CONSTRAINT IF EXISTS check_variant_stock_nonnegative;
ALTER TABLE product_images
ADD CONSTRAINT check_variant_stock_nonnegative
CHECK (variant_stock >= 0);
-- Ensure display_order is non-negative
ALTER TABLE product_images DROP CONSTRAINT IF EXISTS check_display_order_nonnegative;
ALTER TABLE product_images
ADD CONSTRAINT check_display_order_nonnegative
CHECK (display_order >= 0);
ALTER TABLE portfolioprojects DROP CONSTRAINT IF EXISTS check_displayorder_nonnegative;
ALTER TABLE portfolioprojects
ADD CONSTRAINT check_displayorder_nonnegative
CHECK (displayorder >= 0);
ALTER TABLE homepagesections DROP CONSTRAINT IF EXISTS check_displayorder_nonnegative;
ALTER TABLE homepagesections
ADD CONSTRAINT check_displayorder_nonnegative
CHECK (displayorder >= 0);
ALTER TABLE team_members DROP CONSTRAINT IF EXISTS check_display_order_nonnegative;
ALTER TABLE team_members
ADD CONSTRAINT check_display_order_nonnegative
CHECK (display_order >= 0);
-- =====================================================
-- PART 5: ADD MISSING COLUMNS (IF ANY)
-- =====================================================
-- Ensure all tables have proper timestamp columns
ALTER TABLE products
ADD COLUMN IF NOT EXISTS createdat TIMESTAMP DEFAULT NOW(),
ADD COLUMN IF NOT EXISTS updatedat TIMESTAMP DEFAULT NOW();
ALTER TABLE portfolioprojects
ADD COLUMN IF NOT EXISTS createdat TIMESTAMP DEFAULT NOW(),
ADD COLUMN IF NOT EXISTS updatedat TIMESTAMP DEFAULT NOW();
ALTER TABLE blogposts
ADD COLUMN IF NOT EXISTS createdat TIMESTAMP DEFAULT NOW(),
ADD COLUMN IF NOT EXISTS updatedat TIMESTAMP DEFAULT NOW();
ALTER TABLE pages
ADD COLUMN IF NOT EXISTS createdat TIMESTAMP DEFAULT NOW(),
ADD COLUMN IF NOT EXISTS updatedat TIMESTAMP DEFAULT NOW();
-- Ensure portfolio has imageurl column
ALTER TABLE portfolioprojects
ADD COLUMN IF NOT EXISTS imageurl VARCHAR(500);
-- Ensure pages has pagecontent column
ALTER TABLE pages
ADD COLUMN IF NOT EXISTS pagecontent TEXT;
-- Ensure pages has ispublished column
ALTER TABLE pages
ADD COLUMN IF NOT EXISTS ispublished BOOLEAN DEFAULT true;
-- Ensure blogposts has ispublished column
ALTER TABLE blogposts
ADD COLUMN IF NOT EXISTS ispublished BOOLEAN DEFAULT true;
-- =====================================================
-- PART 6: DATA INTEGRITY FIXES
-- =====================================================
-- Generate missing slugs for products
UPDATE products
SET slug = LOWER(REGEXP_REPLACE(REGEXP_REPLACE(name, '[^a-zA-Z0-9\s-]', '', 'g'), '\s+', '-', 'g'))
WHERE (slug IS NULL OR slug = '') AND name IS NOT NULL;
-- Set ispublished from isactive for pages if NULL
UPDATE pages
SET ispublished = isactive
WHERE ispublished IS NULL;
-- Set ispublished from isactive for blog if NULL
UPDATE blogposts
SET ispublished = isactive
WHERE ispublished IS NULL;
-- Migrate portfolio featured image to imageurl if needed
UPDATE portfolioprojects
SET imageurl = featuredimage
WHERE imageurl IS NULL AND featuredimage IS NOT NULL;
-- =====================================================
-- PART 7: ANALYZE TABLES FOR QUERY OPTIMIZATION
-- =====================================================
ANALYZE products;
ANALYZE product_images;
ANALYZE portfolioprojects;
ANALYZE blogposts;
ANALYZE pages;
ANALYZE homepagesections;
ANALYZE uploads;
ANALYZE media_folders;
ANALYZE team_members;
ANALYZE site_settings;
-- =====================================================
-- PART 8: VERIFICATION QUERIES
-- =====================================================
-- Show foreign keys
SELECT
tc.table_name,
kcu.column_name,
ccu.table_name AS foreign_table,
rc.delete_rule
FROM information_schema.table_constraints AS tc
JOIN information_schema.key_column_usage AS kcu
ON tc.constraint_name = kcu.constraint_name
JOIN information_schema.constraint_column_usage AS ccu
ON ccu.constraint_name = tc.constraint_name
JOIN information_schema.referential_constraints AS rc
ON tc.constraint_name = rc.constraint_name
WHERE tc.constraint_type = 'FOREIGN KEY'
AND tc.table_schema = 'public'
ORDER BY tc.table_name;
-- Show unique constraints
SELECT
tc.table_name,
kcu.column_name,
tc.constraint_name
FROM information_schema.table_constraints tc
JOIN information_schema.key_column_usage kcu
ON tc.constraint_name = kcu.constraint_name
WHERE tc.constraint_type = 'UNIQUE'
AND tc.table_schema = 'public'
AND tc.table_name IN ('products', 'blogposts', 'pages')
ORDER BY tc.table_name;
-- Show index counts
SELECT
tablename,
COUNT(*) as index_count
FROM pg_indexes
WHERE schemaname = 'public'
AND tablename IN ('products', 'product_images', 'portfolioprojects', 'blogposts', 'pages')
GROUP BY tablename
ORDER BY tablename;
-- =====================================================
-- END OF DATABASE FIXES
-- =====================================================