forked from andika/membership-be
118 lines
4.9 KiB
SQL
118 lines
4.9 KiB
SQL
-- Sprint 1, 2, 3 Database Migration
|
|
-- This script adds all new columns and tables for Members Only features
|
|
|
|
-- ==============================================
|
|
-- Step 1: Add new columns to users table
|
|
-- ==============================================
|
|
|
|
-- Add profile photo and social media columns (Sprint 1)
|
|
ALTER TABLE users ADD COLUMN IF NOT EXISTS profile_photo_url VARCHAR;
|
|
ALTER TABLE users ADD COLUMN IF NOT EXISTS social_media_facebook VARCHAR;
|
|
ALTER TABLE users ADD COLUMN IF NOT EXISTS social_media_instagram VARCHAR;
|
|
ALTER TABLE users ADD COLUMN IF NOT EXISTS social_media_twitter VARCHAR;
|
|
ALTER TABLE users ADD COLUMN IF NOT EXISTS social_media_linkedin VARCHAR;
|
|
|
|
-- ==============================================
|
|
-- Step 2: Add new columns to events table
|
|
-- ==============================================
|
|
|
|
-- Add Microsoft Calendar integration columns (Sprint 2)
|
|
ALTER TABLE events ADD COLUMN IF NOT EXISTS microsoft_calendar_id VARCHAR;
|
|
ALTER TABLE events ADD COLUMN IF NOT EXISTS microsoft_calendar_sync_enabled BOOLEAN DEFAULT FALSE;
|
|
|
|
-- ==============================================
|
|
-- Step 3: Create new tables
|
|
-- ==============================================
|
|
|
|
-- EventGallery table (Sprint 3)
|
|
CREATE TABLE IF NOT EXISTS event_galleries (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
event_id UUID NOT NULL REFERENCES events(id) ON DELETE CASCADE,
|
|
image_url VARCHAR NOT NULL,
|
|
image_key VARCHAR NOT NULL,
|
|
caption TEXT,
|
|
uploaded_by UUID NOT NULL REFERENCES users(id),
|
|
file_size_bytes INTEGER NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create index for faster queries
|
|
CREATE INDEX IF NOT EXISTS idx_event_galleries_event_id ON event_galleries(event_id);
|
|
CREATE INDEX IF NOT EXISTS idx_event_galleries_uploaded_by ON event_galleries(uploaded_by);
|
|
|
|
-- NewsletterArchive table (Sprint 4 - preparing ahead)
|
|
CREATE TABLE IF NOT EXISTS newsletter_archives (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
title VARCHAR NOT NULL,
|
|
description TEXT,
|
|
published_date TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
document_url VARCHAR NOT NULL,
|
|
document_type VARCHAR DEFAULT 'google_docs',
|
|
file_size_bytes INTEGER,
|
|
created_by UUID NOT NULL REFERENCES users(id),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_newsletter_archives_published_date ON newsletter_archives(published_date DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_newsletter_archives_created_by ON newsletter_archives(created_by);
|
|
|
|
-- FinancialReport table (Sprint 4 - preparing ahead)
|
|
CREATE TABLE IF NOT EXISTS financial_reports (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
year INTEGER NOT NULL,
|
|
title VARCHAR NOT NULL,
|
|
document_url VARCHAR NOT NULL,
|
|
document_type VARCHAR DEFAULT 'google_drive',
|
|
file_size_bytes INTEGER,
|
|
created_by UUID NOT NULL REFERENCES users(id),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_financial_reports_year ON financial_reports(year DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_financial_reports_created_by ON financial_reports(created_by);
|
|
|
|
-- BylawsDocument table (Sprint 4 - preparing ahead)
|
|
CREATE TABLE IF NOT EXISTS bylaws_documents (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
title VARCHAR NOT NULL,
|
|
version VARCHAR NOT NULL,
|
|
effective_date TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
document_url VARCHAR NOT NULL,
|
|
document_type VARCHAR DEFAULT 'google_drive',
|
|
file_size_bytes INTEGER,
|
|
is_current BOOLEAN DEFAULT TRUE,
|
|
created_by UUID NOT NULL REFERENCES users(id),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_bylaws_documents_is_current ON bylaws_documents(is_current);
|
|
CREATE INDEX IF NOT EXISTS idx_bylaws_documents_created_by ON bylaws_documents(created_by);
|
|
|
|
-- StorageUsage table (Sprint 1)
|
|
CREATE TABLE IF NOT EXISTS storage_usage (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
total_bytes_used BIGINT DEFAULT 0,
|
|
max_bytes_allowed BIGINT NOT NULL,
|
|
last_updated TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Insert initial storage usage record
|
|
INSERT INTO storage_usage (total_bytes_used, max_bytes_allowed)
|
|
SELECT 0, 10737418240
|
|
WHERE NOT EXISTS (SELECT 1 FROM storage_usage);
|
|
|
|
-- ==============================================
|
|
-- Migration Complete
|
|
-- ==============================================
|
|
|
|
-- Verify migrations
|
|
DO $$
|
|
BEGIN
|
|
RAISE NOTICE 'Migration completed successfully!';
|
|
RAISE NOTICE 'New columns added to users table: profile_photo_url, social_media_*';
|
|
RAISE NOTICE 'New columns added to events table: microsoft_calendar_*';
|
|
RAISE NOTICE 'New tables created: event_galleries, newsletter_archives, financial_reports, bylaws_documents, storage_usage';
|
|
END $$;
|