From f2a2bd0d049224e075969352e4370ceb0317ea84 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Nicol=C3=A1s=20De=20los=20Santos?= Date: Sun, 28 Sep 2025 16:37:32 +0200 Subject: [PATCH] perf: optimize tables query tables info can be queried faster by calling pg_total_relation_size only once per row --- ...af5875a1842ca09da63a7fe68996409e21e7f779.json} | 4 ++-- crates/pgt_schema_cache/src/queries/tables.sql | 15 +++------------ 2 files changed, 5 insertions(+), 14 deletions(-) rename .sqlx/{query-aced4382cedbfc359bb1c1ab71cf2472fa8afc0b24bf02ee1bfdfdbf111acfc8.json => query-2b27b190ecaed2d961577fcaaf5875a1842ca09da63a7fe68996409e21e7f779.json} (65%) diff --git a/.sqlx/query-aced4382cedbfc359bb1c1ab71cf2472fa8afc0b24bf02ee1bfdfdbf111acfc8.json b/.sqlx/query-2b27b190ecaed2d961577fcaaf5875a1842ca09da63a7fe68996409e21e7f779.json similarity index 65% rename from .sqlx/query-aced4382cedbfc359bb1c1ab71cf2472fa8afc0b24bf02ee1bfdfdbf111acfc8.json rename to .sqlx/query-2b27b190ecaed2d961577fcaaf5875a1842ca09da63a7fe68996409e21e7f779.json index 398f0ee20..9f1393a3f 100644 --- a/.sqlx/query-aced4382cedbfc359bb1c1ab71cf2472fa8afc0b24bf02ee1bfdfdbf111acfc8.json +++ b/.sqlx/query-2b27b190ecaed2d961577fcaaf5875a1842ca09da63a7fe68996409e21e7f779.json @@ -1,6 +1,6 @@ { "db_name": "PostgreSQL", - "query": "select\n c.oid :: int8 as \"id!\",\n nc.nspname as schema,\n c.relname as name,\n c.relkind as table_kind,\n c.relrowsecurity as rls_enabled,\n c.relforcerowsecurity as rls_forced,\n case\n when c.relreplident = 'd' then 'DEFAULT'\n when c.relreplident = 'i' then 'INDEX'\n when c.relreplident = 'f' then 'FULL'\n else 'NOTHING'\n end as \"replica_identity!\",\n pg_total_relation_size(format('%I.%I', nc.nspname, c.relname)) :: int8 as \"bytes!\",\n pg_size_pretty(\n pg_total_relation_size(format('%I.%I', nc.nspname, c.relname))\n ) as \"size!\",\n pg_stat_get_live_tuples(c.oid) as \"live_rows_estimate!\",\n pg_stat_get_dead_tuples(c.oid) as \"dead_rows_estimate!\",\n obj_description(c.oid) as comment\nfrom\n pg_namespace nc\n join pg_class c on nc.oid = c.relnamespace\nwhere\n c.relkind in ('r', 'p', 'v', 'm')\n and not pg_is_other_temp_schema(nc.oid)\n and (\n pg_has_role(c.relowner, 'USAGE')\n or has_table_privilege(\n c.oid,\n 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER'\n )\n or has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES')\n )\ngroup by\n c.oid,\n c.relname,\n c.relkind,\n c.relrowsecurity,\n c.relforcerowsecurity,\n c.relreplident,\n nc.nspname;\n", + "query": "select\n c.oid :: int8 as \"id!\",\n nc.nspname as schema,\n c.relname as name,\n c.relkind as table_kind,\n c.relrowsecurity as rls_enabled,\n c.relforcerowsecurity as rls_forced,\n case\n when c.relreplident = 'd' then 'DEFAULT'\n when c.relreplident = 'i' then 'INDEX'\n when c.relreplident = 'f' then 'FULL'\n else 'NOTHING'\n end as \"replica_identity!\",\n relation_size:: int8 as \"bytes!\",\n pg_size_pretty(relation_size) as \"size!\",\n pg_stat_get_live_tuples(c.oid) as \"live_rows_estimate!\",\n pg_stat_get_dead_tuples(c.oid) as \"dead_rows_estimate!\",\n obj_description(c.oid) as comment\nfrom\n pg_namespace nc\n join pg_class c on nc.oid = c.relnamespace\n cross join lateral pg_total_relation_size(c.oid) relation_size\nwhere\n c.relkind in ('r', 'p', 'v', 'm')\n and not pg_is_other_temp_schema(nc.oid)\n and (\n pg_has_role(c.relowner, 'USAGE')\n or has_table_privilege(\n c.oid,\n 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER'\n )\n or has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES')\n )\n", "describe": { "columns": [ { @@ -82,5 +82,5 @@ null ] }, - "hash": "aced4382cedbfc359bb1c1ab71cf2472fa8afc0b24bf02ee1bfdfdbf111acfc8" + "hash": "2b27b190ecaed2d961577fcaaf5875a1842ca09da63a7fe68996409e21e7f779" } diff --git a/crates/pgt_schema_cache/src/queries/tables.sql b/crates/pgt_schema_cache/src/queries/tables.sql index 6ff89da45..624d1bbc6 100644 --- a/crates/pgt_schema_cache/src/queries/tables.sql +++ b/crates/pgt_schema_cache/src/queries/tables.sql @@ -11,16 +11,15 @@ select when c.relreplident = 'f' then 'FULL' else 'NOTHING' end as "replica_identity!", - pg_total_relation_size(format('%I.%I', nc.nspname, c.relname)) :: int8 as "bytes!", - pg_size_pretty( - pg_total_relation_size(format('%I.%I', nc.nspname, c.relname)) - ) as "size!", + relation_size:: int8 as "bytes!", + pg_size_pretty(relation_size) as "size!", pg_stat_get_live_tuples(c.oid) as "live_rows_estimate!", pg_stat_get_dead_tuples(c.oid) as "dead_rows_estimate!", obj_description(c.oid) as comment from pg_namespace nc join pg_class c on nc.oid = c.relnamespace + cross join lateral pg_total_relation_size(c.oid) relation_size where c.relkind in ('r', 'p', 'v', 'm') and not pg_is_other_temp_schema(nc.oid) @@ -32,11 +31,3 @@ where ) or has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES') ) -group by - c.oid, - c.relname, - c.relkind, - c.relrowsecurity, - c.relforcerowsecurity, - c.relreplident, - nc.nspname;