From 5bb3fe9076f455a7857fdbb33efcf33b31fdc462 Mon Sep 17 00:00:00 2001 From: Johannes Haass Date: Tue, 14 Nov 2023 14:54:33 +0100 Subject: [PATCH] Add missing indexes for foreign keys on postgres Mysql automatically creates indexes for foreign keys. This makes the execution of joins, eager loading etc. faster. Conversely, in Postgres indexes for for foreign keys aren't automatically created. This change adds the missing indexes for Postgres. The migration has been created with the help of the following psql function which shows the foreign keys with missing indexes: ``` -- -- function: missing_fk_indexes2 -- purpose: List all foreing keys in the database without and index in the referencing table. -- The listing contains create index sentences -- author: Based on the work of Laurenz Albe -- see: https://www.cybertec-postgresql.com/en/index-your-foreign-key/ -- create or replace function missing_fk_indexes2 () returns setof varchar language sql as $$ select -- create index sentence 'create index on ' || tc.conrelid::regclass || '(' || string_agg(ta.attname, ', ' order by tx.n) || ')' as create_index from pg_catalog.pg_constraint tc -- enumerated key column numbers per foreign key cross join lateral unnest(tc.conkey) with ordinality as tx(attnum, n) -- name for each key column join pg_catalog.pg_attribute ta on ta.attnum = tx.attnum and ta.attrelid = tc.conrelid where not exists ( -- is there ta matching index for the constraint? select 1 from pg_catalog.pg_index i where i.indrelid = tc.conrelid and -- the first index columns must be the same as the key columns, but order doesn't matter (i.indkey::smallint[])[0:cardinality(tc.conkey)-1] @> tc.conkey) and tc.contype = 'f' group by tc.conrelid, tc.conname, tc.confrelid order by pg_catalog.pg_relation_size(tc.conrelid) desc $$; ``` Which can be executed like this: ``` select * from missing_fk_indexes2(); ``` Co-authored-by: Johannes Haass --- .../20231114130216_add_missing_fk_indexes.rb | 51 +++++++++++++++++++ spec/migrations/Readme.md | 2 + 2 files changed, 53 insertions(+) create mode 100644 db/migrations/20231114130216_add_missing_fk_indexes.rb diff --git a/db/migrations/20231114130216_add_missing_fk_indexes.rb b/db/migrations/20231114130216_add_missing_fk_indexes.rb new file mode 100644 index 00000000000..d0ec255a779 --- /dev/null +++ b/db/migrations/20231114130216_add_missing_fk_indexes.rb @@ -0,0 +1,51 @@ +def migration_name(table, columns) + "#{table}_#{columns.join('_')}_index" +end + +Sequel.migration do + foreign_key_indexes = [ + { table: :organizations, columns: %i[quota_definition_id] }, + { table: :organizations, columns: %i[guid default_isolation_segment_guid] }, + { table: :domains, columns: %i[owning_organization_id] }, + { table: :spaces, columns: %i[isolation_segment_guid] }, + { table: :routes, columns: %i[domain_id] }, + { table: :routes, columns: %i[space_id] }, + { table: :users, columns: %i[default_space_id] }, + { table: :organizations_users, columns: %i[user_id] }, + { table: :organizations_managers, columns: %i[user_id] }, + { table: :organizations_billing_managers, columns: %i[user_id] }, + { table: :organizations_auditors, columns: %i[user_id] }, + { table: :spaces_developers, columns: %i[user_id] }, + { table: :spaces_managers, columns: %i[user_id] }, + { table: :spaces_auditors, columns: %i[user_id] }, + { table: :organizations_private_domains, columns: %i[private_domain_id] }, + { table: :route_bindings, columns: %i[route_id] }, + { table: :route_bindings, columns: %i[service_instance_id] }, + { table: :organizations_isolation_segments, columns: %i[isolation_segment_guid] }, + { table: :staging_security_groups_spaces, columns: %i[staging_space_id] }, + { table: :service_instance_shares, columns: %i[target_space_guid] }, + { table: :job_warnings, columns: %i[fk_jobs_id] }, + { table: :service_broker_update_requests, columns: %i[fk_service_brokers_id] }, + { table: :kpack_lifecycle_data, columns: %i[app_guid] }, + { table: :spaces_supporters, columns: %i[user_id] }, + { table: :route_shares, columns: %i[target_space_guid] } + ] + + no_transaction # Disable automatic transactions + + up do + if database_type == :postgres + foreign_key_indexes.each do |index| + add_index index[:table], index[:columns], name: migration_name(index[:table], index[:columns]), concurrently: true, if_not_exists: true + end + end + end + + down do + if database_type == :postgres + foreign_key_indexes.each do |index| + drop_index index[:table], nil, name: migration_name(index[:table], index[:columns]), concurrently: true, if_exists: true + end + end + end +end diff --git a/spec/migrations/Readme.md b/spec/migrations/Readme.md index 3a53ee5f9f2..f6f789af8a5 100644 --- a/spec/migrations/Readme.md +++ b/spec/migrations/Readme.md @@ -17,6 +17,8 @@ At present, the Cloud Controller (CC) supports both Postgres and MySQL in variou 1. A size should always be specified for a string (and text should not be used). Postgres and MySQL have different size limits on String and TEXT fields. To ensure data can be migrated across the two databases (and others in future) without issues, a maximum size should always be specified. A rubocop linter has enforced this since 2017-07-30. 1. For MySQL, `String` is `varchar(255)`, `String, text: true` has a max size of 16_000 for UTF-8-encoded DBs. 1. For Postgres, both `String` and `String, text: true` are TEXT and have a max size of ~1GB. +1. In Postgres, default indexes are established for primary key and unique key columns. Conversely, an index for a foreign key column isn't automatically generated - it has to be manually added via a migration. In contrast to this, MySQL automatically creates these indexes. + ### Rules when writing migrations