
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.
448 lines
14 KiB
PL/PgSQL
448 lines
14 KiB
PL/PgSQL
-- Timezone Migration: Convert EST-masquerading-as-UTC to proper UTC
|
|
-- Migration: 20250729000001_timezone_conversion_est_to_utc.sql
|
|
--
|
|
-- PROBLEM: Database currently stores EST times labeled as UTC timestamps
|
|
-- SOLUTION: Convert all EST times to proper UTC by applying the correct offset
|
|
--
|
|
-- New York timezone offsets:
|
|
-- - EST (Standard Time): UTC-5 (November - March)
|
|
-- - EDT (Daylight Time): UTC-4 (March - November)
|
|
--
|
|
-- Since current times are EST labeled as UTC, we need to ADD the offset to get true UTC:
|
|
-- - EST time + 5 hours = UTC
|
|
-- - EDT time + 4 hours = UTC
|
|
|
|
-- Enable required extensions
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
|
|
-- Start transaction for atomic migration
|
|
BEGIN;
|
|
|
|
-- ================================
|
|
-- VALIDATION QUERIES (BEFORE)
|
|
-- ================================
|
|
|
|
-- Create temporary table to store validation samples before migration
|
|
CREATE TEMP TABLE pre_migration_samples AS
|
|
SELECT
|
|
'events' as table_name,
|
|
id::text as record_id,
|
|
'start_time' as field_name,
|
|
start_time as original_value,
|
|
start_time AT TIME ZONE 'America/New_York' as interpreted_as_ny_time,
|
|
(start_time AT TIME ZONE 'UTC') AT TIME ZONE 'America/New_York' as current_display_time
|
|
FROM events
|
|
WHERE start_time IS NOT NULL
|
|
LIMIT 5
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
'events' as table_name,
|
|
id::text as record_id,
|
|
'end_time' as field_name,
|
|
end_time as original_value,
|
|
end_time AT TIME ZONE 'America/New_York' as interpreted_as_ny_time,
|
|
(end_time AT TIME ZONE 'UTC') AT TIME ZONE 'America/New_York' as current_display_time
|
|
FROM events
|
|
WHERE end_time IS NOT NULL
|
|
LIMIT 5
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
'pending_events' as table_name,
|
|
id::text as record_id,
|
|
'start_time' as field_name,
|
|
start_time as original_value,
|
|
start_time AT TIME ZONE 'America/New_York' as interpreted_as_ny_time,
|
|
(start_time AT TIME ZONE 'UTC') AT TIME ZONE 'America/New_York' as current_display_time
|
|
FROM pending_events
|
|
WHERE start_time IS NOT NULL
|
|
LIMIT 3;
|
|
|
|
-- Display pre-migration samples
|
|
DO $$
|
|
DECLARE
|
|
sample_record RECORD;
|
|
BEGIN
|
|
RAISE NOTICE '========================================';
|
|
RAISE NOTICE 'PRE-MIGRATION VALIDATION SAMPLES';
|
|
RAISE NOTICE '========================================';
|
|
|
|
FOR sample_record IN SELECT * FROM pre_migration_samples ORDER BY table_name, record_id LOOP
|
|
RAISE NOTICE 'Table: %, ID: %, Field: %', sample_record.table_name, sample_record.record_id, sample_record.field_name;
|
|
RAISE NOTICE ' Original Value: %', sample_record.original_value;
|
|
RAISE NOTICE ' Interpreted as NY: %', sample_record.interpreted_as_ny_time;
|
|
RAISE NOTICE ' Current Display: %', sample_record.current_display_time;
|
|
RAISE NOTICE '----------------------------------------';
|
|
END LOOP;
|
|
END $$;
|
|
|
|
-- ================================
|
|
-- MIGRATION FUNCTIONS
|
|
-- ================================
|
|
|
|
-- Function to convert EST-masquerading-as-UTC to proper UTC
|
|
-- This function treats the input timestamp as if it's in America/New_York timezone
|
|
-- and converts it to proper UTC
|
|
CREATE OR REPLACE FUNCTION convert_est_to_utc(est_timestamp TIMESTAMP WITH TIME ZONE)
|
|
RETURNS TIMESTAMP WITH TIME ZONE AS $$
|
|
BEGIN
|
|
-- If timestamp is NULL, return NULL
|
|
IF est_timestamp IS NULL THEN
|
|
RETURN NULL;
|
|
END IF;
|
|
|
|
-- Convert the timestamp by treating it as America/New_York time and converting to UTC
|
|
-- This handles both EST (UTC-5) and EDT (UTC-4) automatically
|
|
RETURN (est_timestamp AT TIME ZONE 'UTC') AT TIME ZONE 'America/New_York';
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- ================================
|
|
-- BACKUP TABLES (for rollback)
|
|
-- ================================
|
|
|
|
-- Create backup tables with original data
|
|
CREATE TABLE IF NOT EXISTS events_timezone_backup AS
|
|
SELECT
|
|
id,
|
|
start_time as original_start_time,
|
|
end_time as original_end_time,
|
|
created_at as original_created_at,
|
|
updated_at as original_updated_at,
|
|
now() as backup_created_at
|
|
FROM events;
|
|
|
|
CREATE TABLE IF NOT EXISTS pending_events_timezone_backup AS
|
|
SELECT
|
|
id,
|
|
start_time as original_start_time,
|
|
end_time as original_end_time,
|
|
submitted_at as original_submitted_at,
|
|
created_at as original_created_at,
|
|
updated_at as original_updated_at,
|
|
now() as backup_created_at
|
|
FROM pending_events;
|
|
|
|
CREATE TABLE IF NOT EXISTS bulletins_timezone_backup AS
|
|
SELECT
|
|
id,
|
|
created_at as original_created_at,
|
|
updated_at as original_updated_at,
|
|
now() as backup_created_at
|
|
FROM bulletins;
|
|
|
|
CREATE TABLE IF NOT EXISTS users_timezone_backup AS
|
|
SELECT
|
|
id,
|
|
created_at as original_created_at,
|
|
updated_at as original_updated_at,
|
|
now() as backup_created_at
|
|
FROM users
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
CREATE TABLE IF NOT EXISTS church_config_timezone_backup AS
|
|
SELECT
|
|
id,
|
|
created_at as original_created_at,
|
|
updated_at as original_updated_at,
|
|
now() as backup_created_at
|
|
FROM church_config;
|
|
|
|
CREATE TABLE IF NOT EXISTS schedules_timezone_backup AS
|
|
SELECT
|
|
id,
|
|
created_at as original_created_at,
|
|
updated_at as original_updated_at,
|
|
now() as backup_created_at
|
|
FROM schedules;
|
|
|
|
CREATE TABLE IF NOT EXISTS bible_verses_timezone_backup AS
|
|
SELECT
|
|
id,
|
|
created_at as original_created_at,
|
|
updated_at as original_updated_at,
|
|
now() as backup_created_at
|
|
FROM bible_verses;
|
|
|
|
CREATE TABLE IF NOT EXISTS app_versions_timezone_backup AS
|
|
SELECT
|
|
id,
|
|
created_at as original_created_at,
|
|
updated_at as original_updated_at,
|
|
now() as backup_created_at
|
|
FROM app_versions;
|
|
|
|
-- ================================
|
|
-- HIGH PRIORITY MIGRATIONS (Event Times)
|
|
-- ================================
|
|
|
|
RAISE NOTICE 'Starting HIGH PRIORITY timezone migrations...';
|
|
|
|
-- Update events table - event times
|
|
UPDATE events
|
|
SET
|
|
start_time = convert_est_to_utc(start_time),
|
|
end_time = convert_est_to_utc(end_time),
|
|
updated_at = NOW()
|
|
WHERE start_time IS NOT NULL OR end_time IS NOT NULL;
|
|
|
|
-- Update pending_events table - event times and submission time
|
|
UPDATE pending_events
|
|
SET
|
|
start_time = convert_est_to_utc(start_time),
|
|
end_time = convert_est_to_utc(end_time),
|
|
submitted_at = convert_est_to_utc(submitted_at),
|
|
updated_at = NOW()
|
|
WHERE start_time IS NOT NULL OR end_time IS NOT NULL OR submitted_at IS NOT NULL;
|
|
|
|
RAISE NOTICE 'HIGH PRIORITY timezone migrations completed.';
|
|
|
|
-- ================================
|
|
-- MEDIUM PRIORITY MIGRATIONS (Audit Timestamps)
|
|
-- ================================
|
|
|
|
RAISE NOTICE 'Starting MEDIUM PRIORITY timezone migrations...';
|
|
|
|
-- Update events table - audit timestamps (only if not already updated above)
|
|
UPDATE events
|
|
SET
|
|
created_at = convert_est_to_utc(created_at)
|
|
WHERE created_at IS NOT NULL
|
|
AND created_at != updated_at; -- Skip if we just updated it above
|
|
|
|
-- Update pending_events table - audit timestamps (only if not already updated above)
|
|
UPDATE pending_events
|
|
SET
|
|
created_at = convert_est_to_utc(created_at)
|
|
WHERE created_at IS NOT NULL
|
|
AND created_at != updated_at; -- Skip if we just updated it above
|
|
|
|
-- Update bulletins table
|
|
UPDATE bulletins
|
|
SET
|
|
created_at = convert_est_to_utc(created_at),
|
|
updated_at = convert_est_to_utc(updated_at)
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
-- Update users table
|
|
UPDATE users
|
|
SET
|
|
created_at = convert_est_to_utc(created_at),
|
|
updated_at = convert_est_to_utc(updated_at)
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
-- Update church_config table
|
|
UPDATE church_config
|
|
SET
|
|
created_at = convert_est_to_utc(created_at),
|
|
updated_at = convert_est_to_utc(updated_at)
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
-- Update schedules table
|
|
UPDATE schedules
|
|
SET
|
|
created_at = convert_est_to_utc(created_at),
|
|
updated_at = convert_est_to_utc(updated_at)
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
-- Update bible_verses table
|
|
UPDATE bible_verses
|
|
SET
|
|
created_at = convert_est_to_utc(created_at),
|
|
updated_at = convert_est_to_utc(updated_at)
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
-- Update app_versions table
|
|
UPDATE app_versions
|
|
SET
|
|
created_at = convert_est_to_utc(created_at),
|
|
updated_at = convert_est_to_utc(updated_at)
|
|
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
RAISE NOTICE 'MEDIUM PRIORITY timezone migrations completed.';
|
|
|
|
-- ================================
|
|
-- POST-MIGRATION VALIDATION
|
|
-- ================================
|
|
|
|
-- Create post-migration samples
|
|
CREATE TEMP TABLE post_migration_samples AS
|
|
SELECT
|
|
'events' as table_name,
|
|
id::text as record_id,
|
|
'start_time' as field_name,
|
|
start_time as new_value,
|
|
start_time AT TIME ZONE 'America/New_York' as new_display_time
|
|
FROM events
|
|
WHERE start_time IS NOT NULL
|
|
LIMIT 5
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
'events' as table_name,
|
|
id::text as record_id,
|
|
'end_time' as field_name,
|
|
end_time as new_value,
|
|
end_time AT TIME ZONE 'America/New_York' as new_display_time
|
|
FROM events
|
|
WHERE end_time IS NOT NULL
|
|
LIMIT 5
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
'pending_events' as table_name,
|
|
id::text as record_id,
|
|
'start_time' as field_name,
|
|
start_time as new_value,
|
|
start_time AT TIME ZONE 'America/New_York' as new_display_time
|
|
FROM pending_events
|
|
WHERE start_time IS NOT NULL
|
|
LIMIT 3;
|
|
|
|
-- Display post-migration samples and comparison
|
|
DO $$
|
|
DECLARE
|
|
pre_record RECORD;
|
|
post_record RECORD;
|
|
total_events INTEGER;
|
|
total_pending_events INTEGER;
|
|
total_bulletins INTEGER;
|
|
BEGIN
|
|
RAISE NOTICE '========================================';
|
|
RAISE NOTICE 'POST-MIGRATION VALIDATION SAMPLES';
|
|
RAISE NOTICE '========================================';
|
|
|
|
-- Show post-migration samples
|
|
FOR post_record IN SELECT * FROM post_migration_samples ORDER BY table_name, record_id LOOP
|
|
RAISE NOTICE 'Table: %, ID: %, Field: %', post_record.table_name, post_record.record_id, post_record.field_name;
|
|
RAISE NOTICE ' New UTC Value: %', post_record.new_value;
|
|
RAISE NOTICE ' New Display Time (NY): %', post_record.new_display_time;
|
|
RAISE NOTICE '----------------------------------------';
|
|
END LOOP;
|
|
|
|
-- Show migration statistics
|
|
SELECT COUNT(*) INTO total_events FROM events WHERE start_time IS NOT NULL OR end_time IS NOT NULL;
|
|
SELECT COUNT(*) INTO total_pending_events FROM pending_events WHERE start_time IS NOT NULL OR end_time IS NOT NULL;
|
|
SELECT COUNT(*) INTO total_bulletins FROM bulletins WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
|
|
|
|
RAISE NOTICE '========================================';
|
|
RAISE NOTICE 'MIGRATION STATISTICS';
|
|
RAISE NOTICE '========================================';
|
|
RAISE NOTICE 'Events migrated: %', total_events;
|
|
RAISE NOTICE 'Pending events migrated: %', total_pending_events;
|
|
RAISE NOTICE 'Bulletins migrated: %', total_bulletins;
|
|
RAISE NOTICE '========================================';
|
|
END $$;
|
|
|
|
-- ================================
|
|
-- VALIDATION QUERIES
|
|
-- ================================
|
|
|
|
-- These queries can be run after migration to verify correctness
|
|
CREATE TEMP TABLE validation_queries AS
|
|
SELECT 1 as query_num,
|
|
'Check upcoming events display correctly in NY timezone' as description,
|
|
$validation1$
|
|
SELECT
|
|
title,
|
|
start_time as utc_time,
|
|
start_time AT TIME ZONE 'America/New_York' as ny_display_time
|
|
FROM events
|
|
WHERE start_time > NOW()
|
|
ORDER BY start_time
|
|
LIMIT 10;
|
|
$validation1$ as query_sql
|
|
|
|
UNION ALL
|
|
|
|
SELECT 2 as query_num,
|
|
'Verify event times are now proper UTC (should be 4-5 hours ahead of original EST)' as description,
|
|
$validation2$
|
|
SELECT
|
|
e.title,
|
|
e.start_time as new_utc_time,
|
|
eb.original_start_time as old_est_time,
|
|
EXTRACT(HOUR FROM (e.start_time - eb.original_start_time)) as hour_difference
|
|
FROM events e
|
|
JOIN events_timezone_backup eb ON e.id = eb.id
|
|
WHERE e.start_time IS NOT NULL
|
|
LIMIT 10;
|
|
$validation2$ as query_sql
|
|
|
|
UNION ALL
|
|
|
|
SELECT 3 as query_num,
|
|
'Check that EST event times now show correctly when converted to NY timezone' as description,
|
|
$validation3$
|
|
SELECT
|
|
title,
|
|
start_time AT TIME ZONE 'America/New_York' as ny_time,
|
|
end_time AT TIME ZONE 'America/New_York' as ny_end_time
|
|
FROM events
|
|
WHERE start_time IS NOT NULL
|
|
ORDER BY start_time
|
|
LIMIT 5;
|
|
$validation3$ as query_sql;
|
|
|
|
-- Display validation queries for manual execution
|
|
DO $$
|
|
DECLARE
|
|
val_record RECORD;
|
|
BEGIN
|
|
RAISE NOTICE '========================================';
|
|
RAISE NOTICE 'POST-MIGRATION VALIDATION QUERIES';
|
|
RAISE NOTICE 'Run these queries to verify migration:';
|
|
RAISE NOTICE '========================================';
|
|
|
|
FOR val_record IN SELECT * FROM validation_queries ORDER BY query_num LOOP
|
|
RAISE NOTICE 'Query %: %', val_record.query_num, val_record.description;
|
|
RAISE NOTICE '%', val_record.query_sql;
|
|
RAISE NOTICE '----------------------------------------';
|
|
END LOOP;
|
|
END $$;
|
|
|
|
-- Drop temporary function
|
|
DROP FUNCTION convert_est_to_utc(TIMESTAMP WITH TIME ZONE);
|
|
|
|
-- ================================
|
|
-- MIGRATION COMPLETE LOG
|
|
-- ================================
|
|
|
|
-- Create migration log entry
|
|
CREATE TABLE IF NOT EXISTS migration_log (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
migration_name VARCHAR(255) NOT NULL,
|
|
executed_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
description TEXT,
|
|
success BOOLEAN DEFAULT true
|
|
);
|
|
|
|
INSERT INTO migration_log (migration_name, description)
|
|
VALUES (
|
|
'20250729000001_timezone_conversion_est_to_utc',
|
|
'Converted EST-masquerading-as-UTC timestamps to proper UTC timestamps. Migrated event times (high priority) and audit timestamps (medium priority) across all tables. Created backup tables for rollback capability.'
|
|
);
|
|
|
|
RAISE NOTICE '========================================';
|
|
RAISE NOTICE 'TIMEZONE MIGRATION COMPLETED SUCCESSFULLY';
|
|
RAISE NOTICE 'Migration: 20250729000001_timezone_conversion_est_to_utc';
|
|
RAISE NOTICE 'Executed at: %', NOW();
|
|
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';
|
|
RAISE NOTICE '========================================';
|
|
|
|
-- Commit the transaction
|
|
COMMIT; |