# Timezone Migration Scripts This directory contains comprehensive PostgreSQL migration scripts to convert EST-masquerading-as-UTC times to proper UTC times in the church API database. ## Problem Statement The database currently stores EST (Eastern Standard Time) timestamps that are incorrectly labeled as UTC. This causes confusion and requires workarounds in the frontend to display proper times. **Example of the problem:** - Database stores: `2025-07-29 14:30:00+00` (labeled as UTC) - Actual meaning: `2025-07-29 14:30:00` EST (which is really `19:30:00` UTC) - Should store: `2025-07-29 19:30:00+00` (true UTC) ## Files Included ### 1. `20250729000001_timezone_conversion_est_to_utc.sql` **Main migration script** that converts EST-masquerading-as-UTC times to proper UTC. **What it migrates:** - **High Priority (Event Times):** - `events.start_time` and `events.end_time` - `pending_events.start_time`, `pending_events.end_time`, and `pending_events.submitted_at` - **Medium Priority (Audit Timestamps):** - All `created_at` and `updated_at` fields across all tables: - `events`, `pending_events`, `bulletins`, `users` - `church_config`, `schedules`, `bible_verses`, `app_versions` **Features:** - ✅ Handles daylight saving time automatically (EST/EDT) - ✅ Creates backup tables for safe rollback - ✅ Transaction-wrapped for atomicity - ✅ Comprehensive validation and logging - ✅ Before/after samples for verification ### 2. `20250729000001_timezone_conversion_est_to_utc_rollback.sql` **Rollback script** to revert the migration if needed. **Features:** - ✅ Restores all original timestamps from backup tables - ✅ Validates backup table existence before proceeding - ✅ Shows before/after states for verification - ✅ Preserves backup tables (commented cleanup section) ### 3. `validate_timezone_migration.sql` **Validation script** to verify migration success. **Checks performed:** - ✅ Backup table verification - ✅ Timezone offset validation (should be 4-5 hours) - ✅ Display time validation in NY timezone - ✅ Migration statistics and consistency checks - ✅ Future event validation - ✅ Daylight saving time handling - ✅ Migration log verification ## Usage Instructions ### Pre-Migration Preparation 1. **Backup your database** (outside of the migration): ```bash pg_dump your_database > backup_before_timezone_migration.sql ``` 2. **Review current data** to understand the scope: ```sql -- Check sample event times SELECT title, start_time, start_time AT TIME ZONE 'America/New_York' FROM events WHERE start_time IS NOT NULL LIMIT 5; ``` ### Running the Migration 1. **Execute the main migration**: ```bash psql -d your_database -f migrations/20250729000001_timezone_conversion_est_to_utc.sql ``` 2. **Review the migration output** for any warnings or errors. 3. **Run validation** to verify success: ```bash psql -d your_database -f migrations/validate_timezone_migration.sql ``` ### Verification Steps After migration, verify the results: 1. **Check upcoming events display correctly**: ```sql 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; ``` 2. **Verify offset conversion worked**: ```sql SELECT e.title, eb.original_start_time as old_est_time, e.start_time as new_utc_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 5; ``` *Expected: `hour_difference` should be 4-5 hours (depending on DST)* 3. **Check that times still make sense**: ```sql -- Church events should typically be during reasonable hours in NY time SELECT title, start_time AT TIME ZONE 'America/New_York' as ny_time, EXTRACT(hour FROM (start_time AT TIME ZONE 'America/New_York')) as hour_of_day FROM events WHERE start_time IS NOT NULL ORDER BY start_time LIMIT 10; ``` ### Rolling Back (If Needed) If issues are discovered and rollback is necessary: 1. **Execute the rollback script**: ```bash psql -d your_database -f migrations/20250729000001_timezone_conversion_est_to_utc_rollback.sql ``` 2. **Verify rollback success**: ```sql -- Check that times are back to original EST-as-UTC format SELECT title, start_time FROM events WHERE start_time IS NOT NULL LIMIT 5; ``` ## Migration Details ### Timezone Conversion Logic The migration uses PostgreSQL's timezone conversion functions to properly handle the EST/EDT transition: ```sql -- Convert EST-masquerading-as-UTC to proper UTC (est_timestamp AT TIME ZONE 'UTC') AT TIME ZONE 'America/New_York' ``` This approach: - Treats the stored timestamp as if it's in `America/New_York` timezone - Converts it to proper UTC automatically handling DST - Results in +4 hours offset during EDT (summer) - Results in +5 hours offset during EST (winter) ### Backup Tables Created The migration creates these backup tables for rollback capability: - `events_timezone_backup` - `pending_events_timezone_backup` - `bulletins_timezone_backup` - `users_timezone_backup` - `church_config_timezone_backup` - `schedules_timezone_backup` - `bible_verses_timezone_backup` - `app_versions_timezone_backup` ### Safety Features 1. **Atomic Transactions**: All changes wrapped in BEGIN/COMMIT 2. **Backup Tables**: Original data preserved for rollback 3. **Validation**: Extensive before/after checking 4. **Logging**: Migration events recorded in `migration_log` table 5. **Error Handling**: Migration fails fast on any issues ## Expected Results After successful migration: 1. **Database timestamps are true UTC** 2. **Display times in NY timezone are correct** 3. **API responses will need updating** to handle the new UTC format 4. **Frontend clients** may need timezone conversion logic 5. **Backup tables available** for emergency rollback ## Integration with Application Code After the database migration, you'll need to update application code: ### V1 API Endpoints (Backward Compatibility) Add timezone conversion in handlers to return EST times: ```rust // Convert UTC from DB to EST for v1 endpoints let est_time = utc_time.with_timezone(&America_New_York); ``` ### V2 API Endpoints (Proper UTC) Ensure v2 endpoints return true UTC without conversion: ```rust // Return UTC directly for v2 endpoints response.start_time = event.start_time; // Already UTC from DB ``` ## Troubleshooting ### Common Issues 1. **Times appear 4-5 hours off**: This is expected! The database now stores true UTC. 2. **Backup tables missing**: Re-run migration - it will recreate backups. 3. **DST boundary issues**: The migration handles DST automatically via PostgreSQL. ### Verification Queries ```sql -- Check migration was applied SELECT COUNT(*) FROM events_timezone_backup; -- Verify UTC conversion SELECT title, start_time as utc, start_time AT TIME ZONE 'America/New_York' as local FROM events LIMIT 3; -- Check offset is correct SELECT EXTRACT(HOUR FROM ( e.start_time - eb.original_start_time )) as offset_hours FROM events e JOIN events_timezone_backup eb ON e.id = eb.id LIMIT 1; ``` ## Support If you encounter issues: 1. Check the validation script output for specific problems 2. Review the migration log in the `migration_log` table 3. Examine backup tables to compare before/after values 4. Use the rollback script if immediate reversion is needed The migration is designed to be safe and reversible while providing comprehensive logging and validation throughout the process.