
Complete church management system with bulletin management, media processing, live streaming integration, and web interface. Includes authentication, email notifications, database migrations, and comprehensive test suite.
245 lines
8 KiB
PL/PgSQL
245 lines
8 KiB
PL/PgSQL
-- Timezone Migration: Convert EST-masquerading-as-UTC to proper UTC
|
|
-- Migration: 20250729000001_timezone_conversion_est_to_utc_fixed.sql
|
|
--
|
|
-- PROBLEM: Database currently stores EST times labeled as UTC timestamps
|
|
-- SOLUTION: Convert all EST times to proper UTC by applying the correct offset
|
|
|
|
-- Enable required extensions
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
|
|
-- Start transaction for atomic migration
|
|
BEGIN;
|
|
|
|
-- ================================
|
|
-- CREATE BACKUP TABLES
|
|
-- ================================
|
|
|
|
-- Backup events table
|
|
CREATE TABLE events_timezone_backup AS SELECT * FROM events;
|
|
|
|
-- Backup pending_events table
|
|
CREATE TABLE pending_events_timezone_backup AS SELECT * FROM pending_events;
|
|
|
|
-- Backup bulletins table
|
|
CREATE TABLE bulletins_timezone_backup AS SELECT * FROM bulletins;
|
|
|
|
-- Backup users table
|
|
CREATE TABLE users_timezone_backup AS SELECT * FROM users;
|
|
|
|
-- Backup church_config table
|
|
CREATE TABLE church_config_timezone_backup AS SELECT * FROM church_config;
|
|
|
|
-- Backup schedules table
|
|
CREATE TABLE schedules_timezone_backup AS SELECT * FROM schedules;
|
|
|
|
-- Backup bible_verses table
|
|
CREATE TABLE bible_verses_timezone_backup AS SELECT * FROM bible_verses;
|
|
|
|
-- Backup app_versions table (if exists)
|
|
DO $$
|
|
BEGIN
|
|
IF EXISTS (SELECT FROM information_schema.tables WHERE table_name = 'app_versions') THEN
|
|
EXECUTE 'CREATE TABLE app_versions_timezone_backup AS SELECT * FROM app_versions';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- ================================
|
|
-- HIGH PRIORITY: EVENT TIMES
|
|
-- These are user-facing times that affect scheduling
|
|
-- ================================
|
|
|
|
-- Convert events.start_time and events.end_time (EST -> UTC)
|
|
UPDATE events
|
|
SET
|
|
start_time = (start_time AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC',
|
|
end_time = (end_time AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
WHERE start_time IS NOT NULL AND end_time IS NOT NULL;
|
|
|
|
-- Convert pending_events times (EST -> UTC)
|
|
UPDATE pending_events
|
|
SET
|
|
start_time = (start_time AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC',
|
|
end_time = (end_time AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC',
|
|
submitted_at = CASE
|
|
WHEN submitted_at IS NOT NULL
|
|
THEN (submitted_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END
|
|
WHERE start_time IS NOT NULL AND end_time IS NOT NULL;
|
|
|
|
-- ================================
|
|
-- MEDIUM PRIORITY: AUDIT TIMESTAMPS
|
|
-- These are for internal tracking
|
|
-- ================================
|
|
|
|
-- Convert events audit timestamps
|
|
UPDATE events
|
|
SET
|
|
created_at = CASE
|
|
WHEN created_at IS NOT NULL
|
|
THEN (created_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END,
|
|
updated_at = CASE
|
|
WHEN updated_at IS NOT NULL
|
|
THEN (updated_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
-- Convert pending_events audit timestamps
|
|
UPDATE pending_events
|
|
SET
|
|
created_at = CASE
|
|
WHEN created_at IS NOT NULL
|
|
THEN (created_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END,
|
|
updated_at = CASE
|
|
WHEN updated_at IS NOT NULL
|
|
THEN (updated_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
-- Convert bulletins audit timestamps
|
|
UPDATE bulletins
|
|
SET
|
|
created_at = CASE
|
|
WHEN created_at IS NOT NULL
|
|
THEN (created_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END,
|
|
updated_at = CASE
|
|
WHEN updated_at IS NOT NULL
|
|
THEN (updated_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
-- Convert users audit timestamps
|
|
UPDATE users
|
|
SET
|
|
created_at = CASE
|
|
WHEN created_at IS NOT NULL
|
|
THEN (created_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END,
|
|
updated_at = CASE
|
|
WHEN updated_at IS NOT NULL
|
|
THEN (updated_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
-- Convert church_config audit timestamps
|
|
UPDATE church_config
|
|
SET
|
|
created_at = CASE
|
|
WHEN created_at IS NOT NULL
|
|
THEN (created_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END,
|
|
updated_at = CASE
|
|
WHEN updated_at IS NOT NULL
|
|
THEN (updated_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
-- Convert schedules audit timestamps (if table exists)
|
|
DO $$
|
|
BEGIN
|
|
IF EXISTS (SELECT FROM information_schema.tables WHERE table_name = 'schedules') THEN
|
|
UPDATE schedules
|
|
SET
|
|
created_at = CASE
|
|
WHEN created_at IS NOT NULL
|
|
THEN (created_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END,
|
|
updated_at = CASE
|
|
WHEN updated_at IS NOT NULL
|
|
THEN (updated_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
END IF;
|
|
END $$;
|
|
|
|
-- Convert bible_verses audit timestamps (if table exists)
|
|
DO $$
|
|
BEGIN
|
|
IF EXISTS (SELECT FROM information_schema.tables WHERE table_name = 'bible_verses') THEN
|
|
UPDATE bible_verses
|
|
SET
|
|
created_at = CASE
|
|
WHEN created_at IS NOT NULL
|
|
THEN (created_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END,
|
|
updated_at = CASE
|
|
WHEN updated_at IS NOT NULL
|
|
THEN (updated_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
END IF;
|
|
END $$;
|
|
|
|
-- Convert app_versions audit timestamps (if table exists)
|
|
DO $$
|
|
BEGIN
|
|
IF EXISTS (SELECT FROM information_schema.tables WHERE table_name = 'app_versions') THEN
|
|
UPDATE app_versions
|
|
SET
|
|
created_at = CASE
|
|
WHEN created_at IS NOT NULL
|
|
THEN (created_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END,
|
|
updated_at = CASE
|
|
WHEN updated_at IS NOT NULL
|
|
THEN (updated_at AT TIME ZONE 'America/New_York') AT TIME ZONE 'UTC'
|
|
ELSE NULL
|
|
END
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
END IF;
|
|
END $$;
|
|
|
|
-- ================================
|
|
-- FINAL VALIDATION
|
|
-- ================================
|
|
|
|
-- Get counts of migrated records
|
|
DO $$
|
|
DECLARE
|
|
events_count INTEGER;
|
|
pending_events_count INTEGER;
|
|
bulletins_count INTEGER;
|
|
BEGIN
|
|
SELECT COUNT(*) INTO events_count FROM events;
|
|
SELECT COUNT(*) INTO pending_events_count FROM pending_events;
|
|
SELECT COUNT(*) INTO bulletins_count FROM bulletins;
|
|
|
|
RAISE NOTICE '========================================';
|
|
RAISE NOTICE 'TIMEZONE MIGRATION COMPLETED SUCCESSFULLY';
|
|
RAISE NOTICE 'Records processed:';
|
|
RAISE NOTICE '- Events: %', events_count;
|
|
RAISE NOTICE '- Pending Events: %', pending_events_count;
|
|
RAISE NOTICE '- Bulletins: %', bulletins_count;
|
|
RAISE NOTICE '========================================';
|
|
RAISE NOTICE 'BACKUP TABLES CREATED FOR ROLLBACK:';
|
|
RAISE NOTICE '- events_timezone_backup';
|
|
RAISE NOTICE '- pending_events_timezone_backup';
|
|
RAISE NOTICE '- bulletins_timezone_backup';
|
|
RAISE NOTICE '- users_timezone_backup';
|
|
RAISE NOTICE '- church_config_timezone_backup';
|
|
RAISE NOTICE '- schedules_timezone_backup';
|
|
RAISE NOTICE '- bible_verses_timezone_backup';
|
|
RAISE NOTICE '- app_versions_timezone_backup (if exists)';
|
|
RAISE NOTICE '========================================';
|
|
END $$;
|
|
|
|
-- Commit the transaction
|
|
COMMIT; |