church-api/validate_timezone_migration.sql
Benjamin Slingo 0c06e159bb Initial commit: Church API Rust implementation
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.
2025-08-19 20:56:41 -04:00

422 lines
13 KiB
SQL

-- Timezone Migration Validation Script
-- File: validate_timezone_migration.sql
--
-- This script validates that the timezone conversion migration was successful.
-- It compares the migrated UTC times with the original EST times from backup tables.
--
-- Run this script after the migration to verify correctness.
-- ================================
-- VALIDATION OVERVIEW
-- ================================
DO $$
BEGIN
RAISE NOTICE '========================================';
RAISE NOTICE 'TIMEZONE MIGRATION VALIDATION REPORT';
RAISE NOTICE 'Generated at: %', NOW();
RAISE NOTICE '========================================';
END $$;
-- ================================
-- 1. BACKUP TABLE VERIFICATION
-- ================================
DO $$
DECLARE
table_info RECORD;
backup_count INTEGER := 0;
BEGIN
RAISE NOTICE '';
RAISE NOTICE '1. BACKUP TABLE VERIFICATION';
RAISE NOTICE '----------------------------';
FOR table_info IN
SELECT
schemaname,
tablename,
n_tup_ins as row_count
FROM pg_stat_user_tables
WHERE tablename LIKE '%_timezone_backup'
ORDER BY tablename
LOOP
RAISE NOTICE 'Backup table: % (% rows)', table_info.tablename, table_info.row_count;
backup_count := backup_count + 1;
END LOOP;
RAISE NOTICE 'Total backup tables found: %', backup_count;
IF backup_count < 8 THEN
RAISE WARNING 'Expected 8 backup tables, found %. Some backups may be missing.', backup_count;
END IF;
END $$;
-- ================================
-- 2. TIMEZONE OFFSET VALIDATION
-- ================================
-- Check that the migration applied correct timezone offsets
WITH timezone_validation AS (
SELECT
e.id,
e.title,
e.start_time as current_utc,
eb.original_start_time as original_est,
EXTRACT(EPOCH FROM (e.start_time - eb.original_start_time))/3600 as hour_offset,
CASE
WHEN EXTRACT(EPOCH FROM (e.start_time - eb.original_start_time))/3600 BETWEEN 4 AND 5 THEN 'CORRECT'
ELSE 'INCORRECT'
END as validation_status
FROM events e
JOIN events_timezone_backup eb ON e.id = eb.id
WHERE e.start_time IS NOT NULL
AND eb.original_start_time IS NOT NULL
LIMIT 10
)
SELECT
'2. TIMEZONE OFFSET VALIDATION' as section,
'' as spacer
UNION ALL
SELECT
'----------------------------' as section,
'' as spacer
UNION ALL
SELECT
'Sample Event: ' || title as section,
'Offset: ' || ROUND(hour_offset::numeric, 2) || ' hours (' || validation_status || ')' as spacer
FROM timezone_validation;
-- ================================
-- 3. DISPLAY TIME VALIDATION
-- ================================
-- Verify that UTC times display correctly in NY timezone
DO $$
DECLARE
event_record RECORD;
sample_count INTEGER := 0;
BEGIN
RAISE NOTICE '';
RAISE NOTICE '3. DISPLAY TIME VALIDATION';
RAISE NOTICE '---------------------------';
RAISE NOTICE 'Verifying UTC times display correctly in America/New_York timezone:';
RAISE NOTICE '';
FOR event_record IN
SELECT
title,
start_time as utc_time,
start_time AT TIME ZONE 'America/New_York' as ny_display_time
FROM events
WHERE start_time IS NOT NULL
ORDER BY start_time
LIMIT 5
LOOP
sample_count := sample_count + 1;
RAISE NOTICE 'Event: %', event_record.title;
RAISE NOTICE ' UTC Time: %', event_record.utc_time;
RAISE NOTICE ' NY Display: %', event_record.ny_display_time;
RAISE NOTICE '';
END LOOP;
IF sample_count = 0 THEN
RAISE WARNING 'No events found for display time validation.';
END IF;
END $$;
-- ================================
-- 4. MIGRATION STATISTICS
-- ================================
DO $$
DECLARE
events_migrated INTEGER;
pending_migrated INTEGER;
bulletins_migrated INTEGER;
users_migrated INTEGER;
total_records INTEGER;
BEGIN
RAISE NOTICE '4. MIGRATION STATISTICS';
RAISE NOTICE '-----------------------';
-- Count migrated records
SELECT COUNT(*) INTO events_migrated
FROM events
WHERE start_time IS NOT NULL OR end_time IS NOT NULL;
SELECT COUNT(*) INTO pending_migrated
FROM pending_events
WHERE start_time IS NOT NULL OR end_time IS NOT NULL OR submitted_at IS NOT NULL;
SELECT COUNT(*) INTO bulletins_migrated
FROM bulletins
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
SELECT COUNT(*) INTO users_migrated
FROM users
WHERE created_at IS NOT NULL OR updated_at IS NOT NULL;
total_records := events_migrated + pending_migrated + bulletins_migrated + users_migrated;
RAISE NOTICE 'Events with timestamps: %', events_migrated;
RAISE NOTICE 'Pending events with timestamps: %', pending_migrated;
RAISE NOTICE 'Bulletins with timestamps: %', bulletins_migrated;
RAISE NOTICE 'Users with timestamps: %', users_migrated;
RAISE NOTICE 'TOTAL RECORDS MIGRATED: %', total_records;
END $$;
-- ================================
-- 5. CONSISTENCY CHECKS
-- ================================
DO $$
DECLARE
inconsistent_count INTEGER;
null_timestamp_count INTEGER;
BEGIN
RAISE NOTICE '';
RAISE NOTICE '5. CONSISTENCY CHECKS';
RAISE NOTICE '---------------------';
-- Check for events where start_time > end_time (potential migration issue)
SELECT COUNT(*) INTO inconsistent_count
FROM events
WHERE start_time IS NOT NULL
AND end_time IS NOT NULL
AND start_time > end_time;
RAISE NOTICE 'Events with start_time > end_time: %', inconsistent_count;
IF inconsistent_count > 0 THEN
RAISE WARNING 'Found % events with inconsistent start/end times!', inconsistent_count;
END IF;
-- Check for NULL timestamps where they shouldn't be
SELECT COUNT(*) INTO null_timestamp_count
FROM events
WHERE (start_time IS NULL OR end_time IS NULL);
RAISE NOTICE 'Events with NULL start/end times: %', null_timestamp_count;
IF null_timestamp_count > 0 THEN
RAISE WARNING 'Found % events with NULL timestamps!', null_timestamp_count;
END IF;
END $$;
-- ================================
-- 6. FUTURE EVENT VALIDATION
-- ================================
-- Check upcoming events to ensure they display correctly
DO $$
DECLARE
future_event RECORD;
future_count INTEGER := 0;
BEGIN
RAISE NOTICE '';
RAISE NOTICE '6. FUTURE EVENT VALIDATION';
RAISE NOTICE '--------------------------';
RAISE NOTICE 'Upcoming events (next 30 days):';
RAISE NOTICE '';
FOR future_event IN
SELECT
title,
start_time AT TIME ZONE 'America/New_York' as ny_time,
EXTRACT(DOW FROM (start_time AT TIME ZONE 'America/New_York')) as day_of_week
FROM events
WHERE start_time > NOW()
AND start_time < (NOW() + INTERVAL '30 days')
ORDER BY start_time
LIMIT 5
LOOP
future_count := future_count + 1;
RAISE NOTICE 'Event: %', future_event.title;
RAISE NOTICE ' NY Time: %', future_event.ny_time;
RAISE NOTICE ' Day of Week: %',
CASE future_event.day_of_week::INTEGER
WHEN 0 THEN 'Sunday'
WHEN 1 THEN 'Monday'
WHEN 2 THEN 'Tuesday'
WHEN 3 THEN 'Wednesday'
WHEN 4 THEN 'Thursday'
WHEN 5 THEN 'Friday'
WHEN 6 THEN 'Saturday'
END;
RAISE NOTICE '';
END LOOP;
IF future_count = 0 THEN
RAISE NOTICE 'No upcoming events found in the next 30 days.';
END IF;
END $$;
-- ================================
-- 7. DAYLIGHT SAVING TIME VALIDATION
-- ================================
-- Check that DST transitions are handled correctly
DO $$
DECLARE
dst_record RECORD;
dst_sample_count INTEGER := 0;
BEGIN
RAISE NOTICE '';
RAISE NOTICE '7. DAYLIGHT SAVING TIME VALIDATION';
RAISE NOTICE '-----------------------------------';
RAISE NOTICE 'Checking DST handling for different times of year:';
RAISE NOTICE '';
-- Sample events from different months to check DST handling
FOR dst_record IN
SELECT
title,
start_time,
start_time AT TIME ZONE 'America/New_York' as ny_time,
EXTRACT(MONTH FROM start_time) as month,
CASE
WHEN EXTRACT(MONTH FROM start_time) IN (11, 12, 1, 2, 3) THEN 'EST (UTC-5)'
ELSE 'EDT (UTC-4)'
END as expected_timezone
FROM events
WHERE start_time IS NOT NULL
ORDER BY EXTRACT(MONTH FROM start_time), start_time
LIMIT 6
LOOP
dst_sample_count := dst_sample_count + 1;
RAISE NOTICE 'Month %: % (Expected: %)',
dst_record.month,
dst_record.title,
dst_record.expected_timezone;
RAISE NOTICE ' UTC: %', dst_record.start_time;
RAISE NOTICE ' NY Time: %', dst_record.ny_time;
RAISE NOTICE '';
END LOOP;
IF dst_sample_count = 0 THEN
RAISE NOTICE 'No events found for DST validation.';
END IF;
END $$;
-- ================================
-- 8. MIGRATION LOG VERIFICATION
-- ================================
DO $$
DECLARE
log_record RECORD;
migration_found BOOLEAN := FALSE;
BEGIN
RAISE NOTICE '';
RAISE NOTICE '8. MIGRATION LOG VERIFICATION';
RAISE NOTICE '-----------------------------';
FOR log_record IN
SELECT
migration_name,
executed_at,
description,
success
FROM migration_log
WHERE migration_name LIKE '%timezone%'
ORDER BY executed_at DESC
LOOP
migration_found := TRUE;
RAISE NOTICE 'Migration: %', log_record.migration_name;
RAISE NOTICE 'Executed: %', log_record.executed_at;
RAISE NOTICE 'Success: %', log_record.success;
RAISE NOTICE 'Description: %', log_record.description;
RAISE NOTICE '';
END LOOP;
IF NOT migration_found THEN
RAISE WARNING 'No timezone migration entries found in migration_log table.';
END IF;
END $$;
-- ================================
-- VALIDATION SUMMARY
-- ================================
DO $$
DECLARE
total_events INTEGER;
total_pending INTEGER;
backup_tables INTEGER;
BEGIN
RAISE NOTICE '========================================';
RAISE NOTICE 'VALIDATION SUMMARY';
RAISE NOTICE '========================================';
SELECT COUNT(*) INTO total_events FROM events WHERE start_time IS NOT NULL;
SELECT COUNT(*) INTO total_pending FROM pending_events WHERE start_time IS NOT NULL;
SELECT COUNT(*) INTO backup_tables FROM information_schema.tables WHERE table_name LIKE '%_timezone_backup';
RAISE NOTICE 'Events validated: %', total_events;
RAISE NOTICE 'Pending events validated: %', total_pending;
RAISE NOTICE 'Backup tables available: %', backup_tables;
RAISE NOTICE '';
RAISE NOTICE 'VALIDATION COMPLETED at %', NOW();
RAISE NOTICE '========================================';
IF backup_tables >= 8 AND total_events > 0 THEN
RAISE NOTICE 'STATUS: Migration validation PASSED';
ELSE
RAISE WARNING 'STATUS: Migration validation issues detected - review above';
END IF;
RAISE NOTICE '========================================';
END $$;
-- ================================
-- RECOMMENDED MANUAL CHECKS
-- ================================
-- These queries should be run manually to spot-check results
SELECT
'-- MANUAL CHECK QUERIES' as info,
'-- Run these queries to manually verify migration results:' as instructions
UNION ALL
SELECT
'-- 1. Compare before/after for specific events:' as info,
$manual1$
SELECT
e.title,
eb.original_start_time as "Before (EST-as-UTC)",
e.start_time as "After (True UTC)",
e.start_time AT TIME ZONE 'America/New_York' as "Display (NY Time)",
EXTRACT(EPOCH FROM (e.start_time - eb.original_start_time))/3600 as "Hour Offset"
FROM events e
JOIN events_timezone_backup eb ON e.id = eb.id
WHERE e.start_time IS NOT NULL
ORDER BY e.start_time
LIMIT 10;
$manual1$ as instructions
UNION ALL
SELECT
'-- 2. Check upcoming events display correctly:' as info,
$manual2$
SELECT
title,
start_time as utc_time,
start_time AT TIME ZONE 'America/New_York' as ny_display_time,
end_time AT TIME ZONE 'America/New_York' as ny_end_time
FROM events
WHERE start_time > NOW()
ORDER BY start_time
LIMIT 10;
$manual2$ as instructions
UNION ALL
SELECT
'-- 3. Verify pending events submission times:' as info,
$manual3$
SELECT
title,
submitted_at as utc_submitted,
submitted_at AT TIME ZONE 'America/New_York' as ny_submitted,
start_time AT TIME ZONE 'America/New_York' as ny_event_time
FROM pending_events
WHERE submitted_at IS NOT NULL
ORDER BY submitted_at DESC
LIMIT 5;
$manual3$ as instructions;