356 lines
14 KiB
SQL
356 lines
14 KiB
SQL
-- =====================================================
|
|
-- DATABASE ANALYSIS & FIXES FOR SKYARTSHOP
|
|
-- Date: January 3, 2026
|
|
-- Purpose: Comprehensive database schema validation and fixes
|
|
-- =====================================================
|
|
|
|
-- =====================================================
|
|
-- PART 1: VERIFY CORE TABLES EXIST
|
|
-- =====================================================
|
|
|
|
-- Ensure all required tables exist
|
|
DO $$
|
|
BEGIN
|
|
-- Check if tables exist and create if missing
|
|
IF NOT EXISTS (SELECT FROM pg_tables WHERE schemaname = 'public' AND tablename = 'products') THEN
|
|
RAISE EXCEPTION 'CRITICAL: products table is missing!';
|
|
END IF;
|
|
|
|
IF NOT EXISTS (SELECT FROM pg_tables WHERE schemaname = 'public' AND tablename = 'product_images') THEN
|
|
RAISE NOTICE 'product_images table is missing - will be created';
|
|
END IF;
|
|
|
|
IF NOT EXISTS (SELECT FROM pg_tables WHERE schemaname = 'public' AND tablename = 'adminusers') THEN
|
|
RAISE EXCEPTION 'CRITICAL: adminusers table is missing!';
|
|
END IF;
|
|
|
|
IF NOT EXISTS (SELECT FROM pg_tables WHERE schemaname = 'public' AND tablename = 'uploads') THEN
|
|
RAISE NOTICE 'uploads table is missing - will be created';
|
|
END IF;
|
|
|
|
IF NOT EXISTS (SELECT FROM pg_tables WHERE schemaname = 'public' AND tablename = 'media_folders') THEN
|
|
RAISE NOTICE 'media_folders table is missing - will be created';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- =====================================================
|
|
-- PART 2: VERIFY AND ADD MISSING COLUMNS
|
|
-- =====================================================
|
|
|
|
-- Products table columns
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS id TEXT PRIMARY KEY DEFAULT replace(gen_random_uuid()::text, '-', '');
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS name VARCHAR(255) NOT NULL DEFAULT '';
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS slug VARCHAR(255);
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS shortdescription TEXT;
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS description TEXT;
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS price DECIMAL(10,2) NOT NULL DEFAULT 0.00;
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS stockquantity INTEGER DEFAULT 0;
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS category VARCHAR(100);
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS sku VARCHAR(100);
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS weight DECIMAL(10,2);
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS dimensions VARCHAR(100);
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS material VARCHAR(255);
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS isactive BOOLEAN DEFAULT true;
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS isfeatured BOOLEAN DEFAULT false;
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS isbestseller BOOLEAN DEFAULT false;
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS createdat TIMESTAMP DEFAULT NOW();
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS updatedat TIMESTAMP DEFAULT NOW();
|
|
ALTER TABLE products ADD COLUMN IF NOT EXISTS metakeywords TEXT;
|
|
|
|
-- Portfolio projects columns
|
|
ALTER TABLE portfolioprojects ADD COLUMN IF NOT EXISTS imageurl VARCHAR(500);
|
|
ALTER TABLE portfolioprojects ADD COLUMN IF NOT EXISTS featuredimage VARCHAR(500);
|
|
ALTER TABLE portfolioprojects ADD COLUMN IF NOT EXISTS images JSONB;
|
|
ALTER TABLE portfolioprojects ADD COLUMN IF NOT EXISTS displayorder INTEGER DEFAULT 0;
|
|
|
|
-- Pages table columns
|
|
ALTER TABLE pages ADD COLUMN IF NOT EXISTS ispublished BOOLEAN DEFAULT true;
|
|
ALTER TABLE pages ADD COLUMN IF NOT EXISTS pagecontent TEXT;
|
|
|
|
-- Blog posts columns
|
|
ALTER TABLE blogposts ADD COLUMN IF NOT EXISTS excerpt TEXT;
|
|
ALTER TABLE blogposts ADD COLUMN IF NOT EXISTS imageurl VARCHAR(500);
|
|
|
|
-- =====================================================
|
|
-- PART 3: CREATE PRODUCT_IMAGES TABLE (IF MISSING)
|
|
-- =====================================================
|
|
|
|
CREATE TABLE IF NOT EXISTS product_images (
|
|
id TEXT PRIMARY KEY DEFAULT replace(gen_random_uuid()::text, '-', ''),
|
|
product_id TEXT NOT NULL,
|
|
image_url VARCHAR(500) NOT NULL,
|
|
color_variant VARCHAR(100),
|
|
color_code VARCHAR(7),
|
|
alt_text VARCHAR(255),
|
|
display_order INTEGER DEFAULT 0,
|
|
is_primary BOOLEAN DEFAULT FALSE,
|
|
variant_price DECIMAL(10,2),
|
|
variant_stock INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP DEFAULT NOW(),
|
|
CONSTRAINT fk_product_images_product FOREIGN KEY (product_id)
|
|
REFERENCES products(id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- =====================================================
|
|
-- PART 4: CREATE UPLOADS & MEDIA_FOLDERS TABLES
|
|
-- =====================================================
|
|
|
|
CREATE TABLE IF NOT EXISTS media_folders (
|
|
id SERIAL PRIMARY KEY,
|
|
name VARCHAR(255) NOT NULL,
|
|
parent_id INTEGER REFERENCES media_folders(id) ON DELETE CASCADE,
|
|
path VARCHAR(1000) NOT NULL,
|
|
created_by TEXT,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE(parent_id, name)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS uploads (
|
|
id SERIAL PRIMARY KEY,
|
|
filename VARCHAR(255) NOT NULL UNIQUE,
|
|
original_name VARCHAR(255) NOT NULL,
|
|
file_path VARCHAR(500) NOT NULL,
|
|
file_size INTEGER NOT NULL,
|
|
mime_type VARCHAR(100) NOT NULL,
|
|
uploaded_by TEXT,
|
|
folder_id INTEGER REFERENCES media_folders(id) ON DELETE SET NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
used_in_type VARCHAR(50),
|
|
used_in_id TEXT
|
|
);
|
|
|
|
-- =====================================================
|
|
-- PART 5: CREATE SITE_SETTINGS TABLE
|
|
-- =====================================================
|
|
|
|
CREATE TABLE IF NOT EXISTS site_settings (
|
|
id SERIAL PRIMARY KEY,
|
|
key VARCHAR(100) UNIQUE NOT NULL,
|
|
settings JSONB NOT NULL DEFAULT '{}'::jsonb,
|
|
created_at TIMESTAMP DEFAULT NOW(),
|
|
updated_at TIMESTAMP DEFAULT NOW()
|
|
);
|
|
|
|
-- Insert default settings if not exists
|
|
INSERT INTO site_settings (key, settings) VALUES
|
|
('menu', '{"items": []}'::jsonb),
|
|
('homepage', '{"hero": {}, "sections": []}'::jsonb)
|
|
ON CONFLICT (key) DO NOTHING;
|
|
|
|
-- =====================================================
|
|
-- PART 6: CREATE TEAM_MEMBERS TABLE
|
|
-- =====================================================
|
|
|
|
CREATE TABLE IF NOT EXISTS team_members (
|
|
id SERIAL PRIMARY KEY,
|
|
name VARCHAR(255) NOT NULL,
|
|
position VARCHAR(255) NOT NULL,
|
|
bio TEXT,
|
|
image_url VARCHAR(500),
|
|
display_order INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- =====================================================
|
|
-- PART 7: ADD ALL CRITICAL INDEXES
|
|
-- =====================================================
|
|
|
|
-- Products 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) WHERE isfeatured = true AND isactive = true;
|
|
CREATE INDEX IF NOT EXISTS idx_products_slug ON products(slug) WHERE isactive = true;
|
|
CREATE INDEX IF NOT EXISTS idx_products_category ON products(category) WHERE isactive = true;
|
|
CREATE INDEX IF NOT EXISTS idx_products_createdat ON products(createdat DESC) WHERE isactive = true;
|
|
CREATE INDEX IF NOT EXISTS idx_products_composite ON products(isactive, isfeatured, createdat DESC);
|
|
|
|
-- Product images indexes
|
|
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 ON product_images(color_variant);
|
|
|
|
-- Blog posts indexes
|
|
CREATE INDEX IF NOT EXISTS idx_blogposts_ispublished ON blogposts(ispublished) WHERE ispublished = true;
|
|
CREATE INDEX IF NOT EXISTS idx_blogposts_slug ON blogposts(slug) WHERE ispublished = true;
|
|
CREATE INDEX IF NOT EXISTS idx_blogposts_createdat ON blogposts(createdat DESC) WHERE ispublished = 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_display ON portfolioprojects(displayorder ASC, 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;
|
|
|
|
-- Homepage sections indexes
|
|
CREATE INDEX IF NOT EXISTS idx_homepagesections_display ON homepagesections(displayorder ASC);
|
|
|
|
-- Team members indexes
|
|
CREATE INDEX IF NOT EXISTS idx_team_members_display ON team_members(display_order ASC, created_at DESC);
|
|
|
|
-- Uploads indexes
|
|
CREATE INDEX IF NOT EXISTS idx_uploads_filename ON uploads(filename);
|
|
CREATE INDEX IF NOT EXISTS idx_uploads_created_at ON uploads(created_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_uploads_folder_id ON uploads(folder_id);
|
|
CREATE INDEX IF NOT EXISTS idx_uploads_usage ON uploads(used_in_type, used_in_id);
|
|
|
|
-- 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
|
|
CREATE INDEX IF NOT EXISTS idx_session_expire ON session(expire);
|
|
|
|
-- =====================================================
|
|
-- PART 8: ADD UNIQUE CONSTRAINTS
|
|
-- =====================================================
|
|
|
|
-- Ensure unique slugs
|
|
DO $$
|
|
BEGIN
|
|
-- Products slug constraint
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM pg_constraint
|
|
WHERE conname = 'unique_products_slug'
|
|
) THEN
|
|
ALTER TABLE products ADD CONSTRAINT unique_products_slug
|
|
UNIQUE(slug);
|
|
END IF;
|
|
|
|
-- Blog posts slug constraint
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM pg_constraint
|
|
WHERE conname = 'unique_blogposts_slug'
|
|
) THEN
|
|
ALTER TABLE blogposts ADD CONSTRAINT unique_blogposts_slug
|
|
UNIQUE(slug);
|
|
END IF;
|
|
|
|
-- Pages slug constraint
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM pg_constraint
|
|
WHERE conname = 'unique_pages_slug'
|
|
) THEN
|
|
ALTER TABLE pages ADD CONSTRAINT unique_pages_slug
|
|
UNIQUE(slug);
|
|
END IF;
|
|
END $$;
|
|
|
|
-- =====================================================
|
|
-- PART 9: ADD CHECK CONSTRAINTS FOR DATA INTEGRITY
|
|
-- =====================================================
|
|
|
|
-- Products 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 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);
|
|
|
|
-- =====================================================
|
|
-- PART 10: DATA MIGRATION & CLEANUP
|
|
-- =====================================================
|
|
|
|
-- Generate slugs for products missing them
|
|
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 for pages from isactive
|
|
UPDATE pages
|
|
SET ispublished = isactive
|
|
WHERE ispublished IS NULL;
|
|
|
|
-- Migrate portfolio featured image if needed
|
|
UPDATE portfolioprojects
|
|
SET imageurl = featuredimage
|
|
WHERE imageurl IS NULL AND featuredimage IS NOT NULL;
|
|
|
|
-- =====================================================
|
|
-- PART 11: ANALYZE TABLES FOR QUERY OPTIMIZATION
|
|
-- =====================================================
|
|
|
|
ANALYZE products;
|
|
ANALYZE product_images;
|
|
ANALYZE blogposts;
|
|
ANALYZE portfolioprojects;
|
|
ANALYZE pages;
|
|
ANALYZE homepagesections;
|
|
ANALYZE uploads;
|
|
ANALYZE media_folders;
|
|
ANALYZE team_members;
|
|
ANALYZE site_settings;
|
|
|
|
-- =====================================================
|
|
-- PART 12: VERIFICATION QUERIES
|
|
-- =====================================================
|
|
|
|
-- Show table row counts
|
|
SELECT 'products' as table_name, COUNT(*) as row_count FROM products
|
|
UNION ALL
|
|
SELECT 'product_images', COUNT(*) FROM product_images
|
|
UNION ALL
|
|
SELECT 'blogposts', COUNT(*) FROM blogposts
|
|
UNION ALL
|
|
SELECT 'portfolioprojects', COUNT(*) FROM portfolioprojects
|
|
UNION ALL
|
|
SELECT 'pages', COUNT(*) FROM pages
|
|
UNION ALL
|
|
SELECT 'uploads', COUNT(*) FROM uploads
|
|
UNION ALL
|
|
SELECT 'media_folders', COUNT(*) FROM media_folders
|
|
UNION ALL
|
|
SELECT 'team_members', COUNT(*) FROM team_members
|
|
UNION ALL
|
|
SELECT 'adminusers', COUNT(*) FROM adminusers
|
|
ORDER BY table_name;
|
|
|
|
-- Show index usage
|
|
SELECT
|
|
schemaname,
|
|
tablename,
|
|
indexname,
|
|
idx_scan as times_used,
|
|
idx_tup_read as rows_read,
|
|
idx_tup_fetch as rows_fetched
|
|
FROM pg_stat_user_indexes
|
|
WHERE schemaname = 'public'
|
|
ORDER BY tablename, indexname;
|
|
|
|
-- Show foreign key constraints
|
|
SELECT
|
|
tc.table_name,
|
|
kcu.column_name,
|
|
ccu.table_name AS foreign_table_name,
|
|
ccu.column_name AS foreign_column_name,
|
|
rc.update_rule,
|
|
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, kcu.column_name;
|
|
|
|
-- =====================================================
|
|
-- END OF DATABASE ANALYSIS & FIXES
|
|
-- =====================================================
|