Skip to content

Commit

Permalink
Migrate all datetime columns to timestampz
Browse files Browse the repository at this point in the history
rails/rails#41084 introduces support for timestamp with time zone

Currently, all our timestamp and datetime fields are without time zone (the previous default of datetime)

This has resulted in some inconsistencies when trying to query for a time object not explicitly passed as UTC
  • Loading branch information
oliverguenther committed Aug 31, 2022
1 parent 504a2e1 commit 72f56bf
Show file tree
Hide file tree
Showing 2 changed files with 53 additions and 0 deletions.
4 changes: 4 additions & 0 deletions config/initializers/postgresql_timestamp.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
Rails.application.config.after_initialize do
# Use timestampz to create new timestamp columns, so that we get WITH TIME ZONE support
ActiveRecord::ConnectionAdapters::PostgreSQLAdapter.datetime_type = :timestamptz
end
49 changes: 49 additions & 0 deletions db/migrate/20220831081937_migrate_timestamps_to_with_timezone.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,49 @@
class MigrateTimestampsToWithTimezone < ActiveRecord::Migration[7.0]
def up
migrate_to_timestampz
end

def down
migrate_to_timestamp
end

private

def migrate_to_timestampz
execute <<~SQL.squish
DO $$
DECLARE
t record;
BEGIN
FOR t IN
SELECT column_name, table_name, data_type
FROM information_schema.columns
WHERE
table_schema = ANY (SELECT unnest(string_to_array(replace(setting, '"$user"', CURRENT_USER), ', ')) FROM pg_settings WHERE name = 'search_path')
AND data_type = 'timestamp without time zone'
LOOP
EXECUTE 'ALTER TABLE ' || t.table_name || ' ALTER COLUMN ' || t.column_name || ' TYPE timestamp with time zone USING ' || t.column_name || ' AT TIME ZONE ''UTC''';
END LOOP;
END$$;
SQL
end

def migrate_to_timestamp
execute <<~SQL.squish
DO $$
DECLARE
t record;
BEGIN
FOR t IN
SELECT column_name, table_name, data_type
FROM information_schema.columns
WHERE
table_schema = ANY (SELECT unnest(string_to_array(replace(setting, '"$user"', CURRENT_USER), ', ')) FROM pg_settings WHERE name = 'search_path')
AND data_type = 'timestamp with time zone'
LOOP
EXECUTE 'ALTER TABLE ' || t.table_name || ' ALTER COLUMN ' || t.column_name || ' TYPE timestamp without time zone USING ' || t.column_name || ' AT TIME ZONE ''UTC''';
END LOOP;
END$$;
SQL
end
end

0 comments on commit 72f56bf

Please sign in to comment.