Updatweb
This commit is contained in:
264
config/database-fixes.sql
Normal file
264
config/database-fixes.sql
Normal file
@@ -0,0 +1,264 @@
|
||||
-- SkyArtShop Database Schema Fixes
|
||||
-- Date: December 18, 2025
|
||||
-- Purpose: Fix missing columns, add constraints, optimize queries
|
||||
|
||||
-- =====================================================
|
||||
-- PHASE 1: Fix Missing Columns
|
||||
-- =====================================================
|
||||
|
||||
-- Fix pages table - add ispublished column
|
||||
ALTER TABLE pages
|
||||
ADD COLUMN IF NOT EXISTS ispublished BOOLEAN DEFAULT true;
|
||||
|
||||
-- Standardize pages table columns
|
||||
UPDATE pages SET ispublished = isactive WHERE ispublished IS NULL;
|
||||
|
||||
-- Fix portfolioprojects table - add imageurl column
|
||||
ALTER TABLE portfolioprojects
|
||||
ADD COLUMN IF NOT EXISTS imageurl VARCHAR(500);
|
||||
|
||||
-- Migrate featuredimage to imageurl for consistency
|
||||
UPDATE portfolioprojects
|
||||
SET imageurl = featuredimage
|
||||
WHERE imageurl IS NULL AND featuredimage IS NOT NULL;
|
||||
|
||||
-- =====================================================
|
||||
-- PHASE 2: Add Missing Indexes for Performance
|
||||
-- =====================================================
|
||||
|
||||
-- Products table indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_products_isactive ON products(isactive);
|
||||
CREATE INDEX IF NOT EXISTS idx_products_category ON products(category);
|
||||
CREATE INDEX IF NOT EXISTS idx_products_isfeatured ON products(isfeatured) WHERE isfeatured = true;
|
||||
CREATE INDEX IF NOT EXISTS idx_products_createdat ON products(createdat DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_products_slug ON products(slug);
|
||||
|
||||
-- Blog posts indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_blogposts_ispublished ON blogposts(ispublished);
|
||||
CREATE INDEX IF NOT EXISTS idx_blogposts_slug ON blogposts(slug);
|
||||
CREATE INDEX IF NOT EXISTS idx_blogposts_createdat ON blogposts(createdat DESC);
|
||||
|
||||
-- Portfolio projects indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_portfolioprojects_isactive ON portfolioprojects(isactive);
|
||||
CREATE INDEX IF NOT EXISTS idx_portfolioprojects_categoryid ON portfolioprojects(categoryid);
|
||||
CREATE INDEX IF NOT EXISTS idx_portfolioprojects_displayorder ON portfolioprojects(displayorder);
|
||||
|
||||
-- Pages indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_pages_isactive ON pages(isactive);
|
||||
CREATE INDEX IF NOT EXISTS idx_pages_slug ON pages(slug);
|
||||
|
||||
-- Admin users indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_adminusers_email ON adminusers(email);
|
||||
CREATE INDEX IF NOT EXISTS idx_adminusers_isactive ON adminusers(isactive);
|
||||
CREATE INDEX IF NOT EXISTS idx_adminusers_role_id ON adminusers(role_id);
|
||||
|
||||
-- Session index (for cleanup)
|
||||
CREATE INDEX IF NOT EXISTS idx_session_expire ON session(expire);
|
||||
|
||||
-- =====================================================
|
||||
-- PHASE 3: Add Constraints and Validations
|
||||
-- =====================================================
|
||||
|
||||
-- Ensure NOT NULL constraints where appropriate
|
||||
ALTER TABLE products
|
||||
ALTER COLUMN isactive SET DEFAULT true,
|
||||
ALTER COLUMN isfeatured SET DEFAULT false,
|
||||
ALTER COLUMN isbestseller SET DEFAULT false,
|
||||
ALTER COLUMN stockquantity SET DEFAULT 0;
|
||||
|
||||
ALTER TABLE blogposts
|
||||
ALTER COLUMN ispublished SET DEFAULT false,
|
||||
ALTER COLUMN views SET DEFAULT 0;
|
||||
|
||||
ALTER TABLE portfolioprojects
|
||||
ALTER COLUMN isactive SET DEFAULT true,
|
||||
ALTER COLUMN displayorder SET DEFAULT 0;
|
||||
|
||||
ALTER TABLE pages
|
||||
ALTER COLUMN isactive SET DEFAULT true;
|
||||
|
||||
-- Add unique constraints
|
||||
ALTER TABLE products DROP CONSTRAINT IF EXISTS unique_products_slug;
|
||||
ALTER TABLE products ADD CONSTRAINT unique_products_slug UNIQUE(slug);
|
||||
|
||||
ALTER TABLE blogposts DROP CONSTRAINT IF EXISTS unique_blogposts_slug;
|
||||
ALTER TABLE blogposts ADD CONSTRAINT unique_blogposts_slug UNIQUE(slug);
|
||||
|
||||
ALTER TABLE pages DROP CONSTRAINT IF EXISTS unique_pages_slug;
|
||||
ALTER TABLE pages ADD CONSTRAINT unique_pages_slug UNIQUE(slug);
|
||||
|
||||
ALTER TABLE adminusers DROP CONSTRAINT IF EXISTS unique_adminusers_email;
|
||||
ALTER TABLE adminusers ADD CONSTRAINT unique_adminusers_email UNIQUE(email);
|
||||
|
||||
-- Add check 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);
|
||||
|
||||
-- =====================================================
|
||||
-- PHASE 4: Add Foreign Key Constraints
|
||||
-- =====================================================
|
||||
|
||||
-- Portfolio projects to categories (if portfoliocategories table exists)
|
||||
DO $$
|
||||
BEGIN
|
||||
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'portfoliocategories') THEN
|
||||
ALTER TABLE portfolioprojects DROP CONSTRAINT IF EXISTS fk_portfolioprojects_category;
|
||||
ALTER TABLE portfolioprojects
|
||||
ADD CONSTRAINT fk_portfolioprojects_category
|
||||
FOREIGN KEY (categoryid) REFERENCES portfoliocategories(id)
|
||||
ON DELETE SET NULL;
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- =====================================================
|
||||
-- PHASE 5: Optimize Existing Data
|
||||
-- =====================================================
|
||||
|
||||
-- Ensure all timestamps are set
|
||||
UPDATE products SET updatedat = createdat WHERE updatedat IS NULL;
|
||||
UPDATE blogposts SET updatedat = createdat WHERE updatedat IS NULL;
|
||||
UPDATE portfolioprojects SET updatedat = createdat WHERE updatedat IS NULL;
|
||||
UPDATE pages SET updatedat = createdat WHERE updatedat IS NULL;
|
||||
|
||||
-- Set default values for nullable booleans
|
||||
UPDATE products SET isactive = true WHERE isactive IS NULL;
|
||||
UPDATE products SET isfeatured = false WHERE isfeatured IS NULL;
|
||||
UPDATE products SET isbestseller = false WHERE isbestseller IS NULL;
|
||||
|
||||
UPDATE blogposts SET ispublished = false WHERE ispublished IS NULL;
|
||||
UPDATE portfolioprojects SET isactive = true WHERE isactive IS NULL;
|
||||
UPDATE pages SET isactive = true WHERE isactive IS NULL;
|
||||
UPDATE pages SET ispublished = true WHERE ispublished IS NULL;
|
||||
|
||||
-- =====================================================
|
||||
-- PHASE 6: Create Useful Views for Reporting
|
||||
-- =====================================================
|
||||
|
||||
-- View for active products with sales data
|
||||
CREATE OR REPLACE VIEW v_active_products AS
|
||||
SELECT
|
||||
id, name, slug, price, stockquantity, category,
|
||||
imageurl, isfeatured, isbestseller,
|
||||
unitssold, totalrevenue, averagerating, totalreviews,
|
||||
createdat
|
||||
FROM products
|
||||
WHERE isactive = true
|
||||
ORDER BY createdat DESC;
|
||||
|
||||
-- View for published blog posts
|
||||
CREATE OR REPLACE VIEW v_published_blogposts AS
|
||||
SELECT
|
||||
id, title, slug, excerpt, imageurl,
|
||||
authorname, publisheddate, views, tags,
|
||||
createdat
|
||||
FROM blogposts
|
||||
WHERE ispublished = true
|
||||
ORDER BY publisheddate DESC NULLS LAST, createdat DESC;
|
||||
|
||||
-- View for active portfolio projects
|
||||
CREATE OR REPLACE VIEW v_active_portfolio AS
|
||||
SELECT
|
||||
id, title, description, imageurl, featuredimage,
|
||||
category, categoryid, displayorder,
|
||||
createdat
|
||||
FROM portfolioprojects
|
||||
WHERE isactive = true
|
||||
ORDER BY displayorder ASC, createdat DESC;
|
||||
|
||||
-- =====================================================
|
||||
-- PHASE 7: Add Triggers for Automatic Timestamps
|
||||
-- =====================================================
|
||||
|
||||
-- Function to update timestamp
|
||||
CREATE OR REPLACE FUNCTION update_timestamp()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updatedat = CURRENT_TIMESTAMP;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Add triggers for products
|
||||
DROP TRIGGER IF EXISTS trg_products_update ON products;
|
||||
CREATE TRIGGER trg_products_update
|
||||
BEFORE UPDATE ON products
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_timestamp();
|
||||
|
||||
-- Add triggers for blogposts
|
||||
DROP TRIGGER IF EXISTS trg_blogposts_update ON blogposts;
|
||||
CREATE TRIGGER trg_blogposts_update
|
||||
BEFORE UPDATE ON blogposts
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_timestamp();
|
||||
|
||||
-- Add triggers for portfolioprojects
|
||||
DROP TRIGGER IF EXISTS trg_portfolioprojects_update ON portfolioprojects;
|
||||
CREATE TRIGGER trg_portfolioprojects_update
|
||||
BEFORE UPDATE ON portfolioprojects
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_timestamp();
|
||||
|
||||
-- Add triggers for pages
|
||||
DROP TRIGGER IF EXISTS trg_pages_update ON pages;
|
||||
CREATE TRIGGER trg_pages_update
|
||||
BEFORE UPDATE ON pages
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_timestamp();
|
||||
|
||||
-- Add triggers for adminusers
|
||||
DROP TRIGGER IF EXISTS trg_adminusers_update ON adminusers;
|
||||
CREATE TRIGGER trg_adminusers_update
|
||||
BEFORE UPDATE ON adminusers
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_timestamp();
|
||||
|
||||
-- =====================================================
|
||||
-- PHASE 8: Clean Up Expired Sessions
|
||||
-- =====================================================
|
||||
|
||||
-- Delete expired sessions (run periodically)
|
||||
DELETE FROM session WHERE expire < NOW();
|
||||
|
||||
-- =====================================================
|
||||
-- VERIFICATION QUERIES
|
||||
-- =====================================================
|
||||
|
||||
-- Verify all critical columns exist
|
||||
SELECT
|
||||
'products' as table_name,
|
||||
EXISTS(SELECT 1 FROM information_schema.columns WHERE table_name='products' AND column_name='isactive') as has_isactive,
|
||||
EXISTS(SELECT 1 FROM information_schema.columns WHERE table_name='products' AND column_name='isfeatured') as has_isfeatured;
|
||||
|
||||
SELECT
|
||||
'pages' as table_name,
|
||||
EXISTS(SELECT 1 FROM information_schema.columns WHERE table_name='pages' AND column_name='ispublished') as has_ispublished,
|
||||
EXISTS(SELECT 1 FROM information_schema.columns WHERE table_name='pages' AND column_name='isactive') as has_isactive;
|
||||
|
||||
SELECT
|
||||
'portfolioprojects' as table_name,
|
||||
EXISTS(SELECT 1 FROM information_schema.columns WHERE table_name='portfolioprojects' AND column_name='imageurl') as has_imageurl,
|
||||
EXISTS(SELECT 1 FROM information_schema.columns WHERE table_name='portfolioprojects' AND column_name='isactive') as has_isactive;
|
||||
|
||||
-- Count indexes
|
||||
SELECT
|
||||
schemaname,
|
||||
tablename,
|
||||
COUNT(*) as index_count
|
||||
FROM pg_indexes
|
||||
WHERE schemaname = 'public'
|
||||
GROUP BY schemaname, tablename
|
||||
ORDER BY tablename;
|
||||
|
||||
-- Verify constraints
|
||||
SELECT
|
||||
tc.table_name,
|
||||
tc.constraint_type,
|
||||
COUNT(*) as constraint_count
|
||||
FROM information_schema.table_constraints tc
|
||||
WHERE tc.table_schema = 'public'
|
||||
GROUP BY tc.table_name, tc.constraint_type
|
||||
ORDER BY tc.table_name;
|
||||
Reference in New Issue
Block a user