From 216b85b053d091306e3311a21f5b050f70a75130 Mon Sep 17 00:00:00 2001 From: Eugen Rochko Date: Mon, 14 Dec 2020 09:06:34 +0100 Subject: Fix performance on instances list in admin UI (#15282) - Reduce duplicate queries - Remove n+1 queries - Add accounts count to detailed view - Add separate action log entry for updating existing domain blocks --- db/migrate/20201206004238_create_instances.rb | 9 +++++++++ db/schema.rb | 27 ++++++++++++++++++++++++++- db/views/instances_v01.sql | 17 +++++++++++++++++ 3 files changed, 52 insertions(+), 1 deletion(-) create mode 100644 db/migrate/20201206004238_create_instances.rb create mode 100644 db/views/instances_v01.sql (limited to 'db') diff --git a/db/migrate/20201206004238_create_instances.rb b/db/migrate/20201206004238_create_instances.rb new file mode 100644 index 000000000..a4b866894 --- /dev/null +++ b/db/migrate/20201206004238_create_instances.rb @@ -0,0 +1,9 @@ +class CreateInstances < ActiveRecord::Migration[5.2] + def change + create_view :instances, materialized: true + + # To be able to refresh the view concurrently, + # at least one unique index is required + safety_assured { add_index :instances, :domain, unique: true } + end +end diff --git a/db/schema.rb b/db/schema.rb index 873c37f67..2f9d369be 100644 --- a/db/schema.rb +++ b/db/schema.rb @@ -10,7 +10,7 @@ # # It's strongly recommended that you check this file into your version control system. -ActiveRecord::Schema.define(version: 2020_10_17_234926) do +ActiveRecord::Schema.define(version: 2020_12_06_004238) do # These are extensions that must be enabled in order to support this database enable_extension "plpgsql" @@ -1045,4 +1045,29 @@ ActiveRecord::Schema.define(version: 2020_10_17_234926) do add_foreign_key "web_push_subscriptions", "users", on_delete: :cascade add_foreign_key "web_settings", "users", name: "fk_11910667b2", on_delete: :cascade add_foreign_key "webauthn_credentials", "users" + + create_view "instances", materialized: true, sql_definition: <<-SQL + WITH domain_counts(domain, accounts_count) AS ( + SELECT accounts.domain, + count(*) AS accounts_count + FROM accounts + WHERE (accounts.domain IS NOT NULL) + GROUP BY accounts.domain + ) + SELECT domain_counts.domain, + domain_counts.accounts_count + FROM domain_counts + UNION + SELECT domain_blocks.domain, + COALESCE(domain_counts.accounts_count, (0)::bigint) AS accounts_count + FROM (domain_blocks + LEFT JOIN domain_counts ON (((domain_counts.domain)::text = (domain_blocks.domain)::text))) + UNION + SELECT domain_allows.domain, + COALESCE(domain_counts.accounts_count, (0)::bigint) AS accounts_count + FROM (domain_allows + LEFT JOIN domain_counts ON (((domain_counts.domain)::text = (domain_allows.domain)::text))); + SQL + add_index "instances", ["domain"], name: "index_instances_on_domain", unique: true + end diff --git a/db/views/instances_v01.sql b/db/views/instances_v01.sql new file mode 100644 index 000000000..94acd61a1 --- /dev/null +++ b/db/views/instances_v01.sql @@ -0,0 +1,17 @@ +WITH domain_counts(domain, accounts_count) +AS ( + SELECT domain, COUNT(*) as accounts_count + FROM accounts + WHERE domain IS NOT NULL + GROUP BY domain +) +SELECT domain, accounts_count +FROM domain_counts +UNION +SELECT domain_blocks.domain, COALESCE(domain_counts.accounts_count, 0) +FROM domain_blocks +LEFT OUTER JOIN domain_counts ON domain_counts.domain = domain_blocks.domain +UNION +SELECT domain_allows.domain, COALESCE(domain_counts.accounts_count, 0) +FROM domain_allows +LEFT OUTER JOIN domain_counts ON domain_counts.domain = domain_allows.domain -- cgit