From ba690a4a5438494f84eea05ddc5eb35605b8f2ad Mon Sep 17 00:00:00 2001 From: Chris Gwilliams <517923+encima@users.noreply.github.com> Date: Tue, 9 Apr 2024 13:33:57 +0300 Subject: [PATCH 01/14] move queries to inspect module and exclude system schemas --- internal/inspect/bloat/bloat.go | 65 +--- internal/inspect/blocking/blocking.go | 22 +- internal/inspect/cache/cache.go | 17 +- internal/inspect/calls/calls.go | 15 +- internal/inspect/index_sizes/index_sizes.go | 14 +- internal/inspect/index_usage/index_usage.go | 22 +- internal/inspect/locks/locks.go | 18 +- .../long_running_queries.go | 17 +- internal/inspect/outliers/outliers.go | 15 +- internal/inspect/queries.go | 334 ++++++++++++++++++ .../replication_slots/replication_slots.go | 17 +- .../role_connections/role_connections.go | 21 +- internal/inspect/seq_scans/seq_scans.go | 10 +- .../table_index_sizes/table_index_sizes.go | 13 +- .../table_record_counts.go | 12 +- internal/inspect/table_sizes/table_sizes.go | 2 +- .../total_index_size/total_index_size.go | 12 +- .../total_table_sizes/total_table_sizes.go | 14 +- .../inspect/unused_indexes/unused_indexes.go | 15 +- internal/inspect/vacuum_stats/vacuum_stats.go | 49 +-- 20 files changed, 372 insertions(+), 332 deletions(-) create mode 100644 internal/inspect/queries.go diff --git a/internal/inspect/bloat/bloat.go b/internal/inspect/bloat/bloat.go index d80408630..4cd78d2fb 100644 --- a/internal/inspect/bloat/bloat.go +++ b/internal/inspect/bloat/bloat.go @@ -8,73 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -WITH constants AS ( - SELECT current_setting('block_size')::numeric AS bs, 23 AS hdr, 4 AS ma -), bloat_info AS ( - SELECT - ma,bs,schemaname,tablename, - (datawidth+(hdr+ma-(case when hdr%ma=0 THEN ma ELSE hdr%ma END)))::numeric AS datahdr, - (maxfracsum*(nullhdr+ma-(case when nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2 - FROM ( - SELECT - schemaname, tablename, hdr, ma, bs, - SUM((1-null_frac)*avg_width) AS datawidth, - MAX(null_frac) AS maxfracsum, - hdr+( - SELECT 1+count(*)/8 - FROM pg_stats s2 - WHERE null_frac<>0 AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename - ) AS nullhdr - FROM pg_stats s, constants - GROUP BY 1,2,3,4,5 - ) AS foo -), table_bloat AS ( - SELECT - schemaname, tablename, cc.relpages, bs, - CEIL((cc.reltuples*((datahdr+ma- - (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::float)) AS otta - FROM bloat_info - JOIN pg_class cc ON cc.relname = bloat_info.tablename - JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = bloat_info.schemaname AND nn.nspname <> 'information_schema' -), index_bloat AS ( - SELECT - schemaname, tablename, bs, - COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages, - COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::float)),0) AS iotta -- very rough approximation, assumes all cols - FROM bloat_info - JOIN pg_class cc ON cc.relname = bloat_info.tablename - JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = bloat_info.schemaname AND nn.nspname <> 'information_schema' - JOIN pg_index i ON indrelid = cc.oid - JOIN pg_class c2 ON c2.oid = i.indexrelid -) -SELECT - type, schemaname, object_name, bloat, pg_size_pretty(raw_waste) as waste -FROM -(SELECT - 'table' as type, - schemaname, - tablename as object_name, - ROUND(CASE WHEN otta=0 THEN 0.0 ELSE table_bloat.relpages/otta::numeric END,1) AS bloat, - CASE WHEN relpages < otta THEN '0' ELSE (bs*(table_bloat.relpages-otta)::bigint)::bigint END AS raw_waste -FROM - table_bloat - UNION -SELECT - 'index' as type, - schemaname, - tablename || '::' || iname as object_name, - ROUND(CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages/iotta::numeric END,1) AS bloat, - CASE WHEN ipages < iotta THEN '0' ELSE (bs*(ipages-iotta))::bigint END AS raw_waste -FROM - index_bloat) bloat_summary -ORDER BY raw_waste DESC, bloat DESC` - type Result struct { Type string Schemaname string @@ -88,7 +27,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.BloatQuery()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/blocking/blocking.go b/internal/inspect/blocking/blocking.go index 3d418bf68..717eec452 100644 --- a/internal/inspect/blocking/blocking.go +++ b/internal/inspect/blocking/blocking.go @@ -9,30 +9,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -// Ref: https://github.com/heroku/heroku-pg-extras/blob/main/commands/blocking.js#L7 -const QUERY = ` -SELECT - bl.pid AS blocked_pid, - ka.query AS blocking_statement, - now() - ka.query_start AS blocking_duration, - kl.pid AS blocking_pid, - a.query AS blocked_statement, - now() - a.query_start AS blocked_duration -FROM pg_catalog.pg_locks bl -JOIN pg_catalog.pg_stat_activity a - ON bl.pid = a.pid -JOIN pg_catalog.pg_locks kl -JOIN pg_catalog.pg_stat_activity ka - ON kl.pid = ka.pid - ON bl.transactionid = kl.transactionid AND bl.pid != kl.pid -WHERE NOT bl.granted -` - type Result struct { Blocked_pid string Blocking_statement string @@ -47,7 +29,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.BLOCKING_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/cache/cache.go b/internal/inspect/cache/cache.go index 88f3c65aa..10c552d18 100644 --- a/internal/inspect/cache/cache.go +++ b/internal/inspect/cache/cache.go @@ -8,24 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -// Ref: https://github.com/heroku/heroku-pg-extras/blob/main/commands/cache_hit.js#L7 -const QUERY = ` -SELECT - 'index hit rate' AS name, - (sum(idx_blks_hit)) / nullif(sum(idx_blks_hit + idx_blks_read),0) AS ratio -FROM pg_statio_user_indexes -UNION ALL -SELECT - 'table hit rate' AS name, - sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS ratio -FROM pg_statio_user_tables; -` - type Result struct { Name string Ratio float64 @@ -36,7 +24,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.CACHE_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } @@ -48,6 +36,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu table := "|Name|Ratio|\n|-|-|\n" for _, r := range result { table += fmt.Sprintf("|`%s`|`%.6f`|\n", r.Name, r.Ratio) + } return list.RenderTable(table) } diff --git a/internal/inspect/calls/calls.go b/internal/inspect/calls/calls.go index faf289ee3..02808cb07 100644 --- a/internal/inspect/calls/calls.go +++ b/internal/inspect/calls/calls.go @@ -9,23 +9,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT - query, - interval '1 millisecond' * total_exec_time AS total_exec_time, - to_char((total_exec_time/sum(total_exec_time) OVER()) * 100, 'FM90D0') || '%' AS prop_exec_time, - to_char(calls, 'FM999G999G990') AS ncalls, - interval '1 millisecond' * (blk_read_time + blk_write_time) AS sync_io_time -FROM pg_stat_statements -ORDER BY calls DESC -LIMIT 10 -` - type Result struct { Total_exec_time string Prop_exec_time string @@ -39,7 +28,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.CALLS_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/index_sizes/index_sizes.go b/internal/inspect/index_sizes/index_sizes.go index 2d5848bc0..57cca59f6 100644 --- a/internal/inspect/index_sizes/index_sizes.go +++ b/internal/inspect/index_sizes/index_sizes.go @@ -8,22 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT c.relname AS name, - pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size -FROM pg_class c -LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') -AND n.nspname !~ '^pg_toast' -AND c.relkind='i' -GROUP BY c.relname -ORDER BY sum(c.relpages) DESC;` - type Result struct { Name string Size string @@ -34,7 +24,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.IndexSizesQuery()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/index_usage/index_usage.go b/internal/inspect/index_usage/index_usage.go index cd304609a..25258e062 100644 --- a/internal/inspect/index_usage/index_usage.go +++ b/internal/inspect/index_usage/index_usage.go @@ -8,30 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT relname, - CASE - WHEN idx_scan IS NULL THEN 'Insufficient data' - WHEN idx_scan = 0 THEN 'Insufficient data' - ELSE (100 * idx_scan / (seq_scan + idx_scan))::text - END percent_of_times_index_used, - n_live_tup rows_in_table -FROM - pg_stat_user_tables -ORDER BY - CASE - WHEN idx_scan is null then 1 - WHEN idx_scan = 0 then 1 - ELSE 0 - END, - n_live_tup DESC; -` - type Result struct { Relname string Percent_of_times_index_used string @@ -43,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.INDEX_USAGE_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/locks/locks.go b/internal/inspect/locks/locks.go index 0d3eb5cdb..5ab2fa06d 100644 --- a/internal/inspect/locks/locks.go +++ b/internal/inspect/locks/locks.go @@ -9,26 +9,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT - pg_stat_activity.pid, - COALESCE(pg_class.relname, 'null') AS relname, - COALESCE(pg_locks.transactionid, 'null') AS transactionid, - pg_locks.granted, - pg_stat_activity.query, - age(now(),pg_stat_activity.query_start) AS age -FROM pg_stat_activity, pg_locks LEFT OUTER JOIN pg_class ON (pg_locks.relation = pg_class.oid) -WHERE pg_stat_activity.query <> '' -AND pg_locks.pid=pg_stat_activity.pid -AND pg_locks.mode = 'ExclusiveLock' -ORDER BY query_start; -` - type Result struct { Pid string Relname string @@ -43,7 +29,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.LOCKS_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/long_running_queries/long_running_queries.go b/internal/inspect/long_running_queries/long_running_queries.go index 9b18f527a..fc1a56f90 100644 --- a/internal/inspect/long_running_queries/long_running_queries.go +++ b/internal/inspect/long_running_queries/long_running_queries.go @@ -8,25 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT - pid, - now() - pg_stat_activity.query_start AS duration, - query AS query -FROM - pg_stat_activity -WHERE - pg_stat_activity.query <> ''::text - AND state <> 'idle' - AND now() - pg_stat_activity.query_start > interval '5 minutes' -ORDER BY - now() - pg_stat_activity.query_start DESC;` - type Result struct { Pid string Duration string @@ -38,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.LONG_RUNNING_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/outliers/outliers.go b/internal/inspect/outliers/outliers.go index 33307045f..d19a691e5 100644 --- a/internal/inspect/outliers/outliers.go +++ b/internal/inspect/outliers/outliers.go @@ -9,23 +9,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT - interval '1 millisecond' * total_exec_time AS total_exec_time, - to_char((total_exec_time/sum(total_exec_time) OVER()) * 100, 'FM90D0') || '%' AS prop_exec_time, - to_char(calls, 'FM999G999G999G990') AS ncalls, - interval '1 millisecond' * (blk_read_time + blk_write_time) AS sync_io_time, - query -FROM pg_stat_statements WHERE userid = (SELECT usesysid FROM pg_user WHERE usename = current_user LIMIT 1) -ORDER BY total_exec_time DESC -LIMIT 10 -` - type Result struct { Total_exec_time string Prop_exec_time string @@ -39,7 +28,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.OUTLIERS_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go new file mode 100644 index 000000000..88d566293 --- /dev/null +++ b/internal/inspect/queries.go @@ -0,0 +1,334 @@ +package inspect + +import ( + "fmt" + "strings" + + "github.com/supabase/cli/internal/utils" +) + +var excludedString string + +func init() { + var excluded = make([]string, len(utils.InternalSchemas)) + for i, schema := range utils.InternalSchemas { + excluded[i] = fmt.Sprintf("'%s'", schema) + } + excluded = append(excluded, "'pg_catalog'") + excludedString = strings.Join(excluded, ", ") +} + +func BloatQuery() string { + return fmt.Sprintf(`WITH constants AS ( + SELECT current_setting('block_size')::numeric AS bs, 23 AS hdr, 4 AS ma +), bloat_info AS ( + SELECT + ma,bs,schemaname,tablename, + (datawidth+(hdr+ma-(case when hdr%%ma=0 THEN ma ELSE hdr%%ma END)))::numeric AS datahdr, + (maxfracsum*(nullhdr+ma-(case when nullhdr%%ma=0 THEN ma ELSE nullhdr%%ma END))) AS nullhdr2 + FROM ( + SELECT + schemaname, tablename, hdr, ma, bs, + SUM((1-null_frac)*avg_width) AS datawidth, + MAX(null_frac) AS maxfracsum, + hdr+( + SELECT 1+count(*)/8 + FROM pg_stats s2 + WHERE null_frac<>0 AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename + ) AS nullhdr + FROM pg_stats s, constants + GROUP BY 1,2,3,4,5 + ) AS foo +), table_bloat AS ( + SELECT + schemaname, tablename, cc.relpages, bs, + CEIL((cc.reltuples*((datahdr+ma- + (CASE WHEN datahdr%%ma=0 THEN ma ELSE datahdr%%ma END))+nullhdr2+4))/(bs-20::float)) AS otta + FROM bloat_info + JOIN pg_class cc ON cc.relname = bloat_info.tablename + JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = bloat_info.schemaname AND nn.nspname <> 'information_schema' +), index_bloat AS ( + SELECT + schemaname, tablename, bs, + COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages, + COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::float)),0) AS iotta -- very rough approximation, assumes all cols + FROM bloat_info + JOIN pg_class cc ON cc.relname = bloat_info.tablename + JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = bloat_info.schemaname AND nn.nspname <> 'information_schema' + JOIN pg_index i ON indrelid = cc.oid + JOIN pg_class c2 ON c2.oid = i.indexrelid +) +SELECT + type, schemaname, object_name, bloat, pg_size_pretty(raw_waste) as waste +FROM +(SELECT + 'table' as type, + schemaname, + tablename as object_name, + ROUND(CASE WHEN otta=0 THEN 0.0 ELSE table_bloat.relpages/otta::numeric END,1) AS bloat, + CASE WHEN relpages < otta THEN '0' ELSE (bs*(table_bloat.relpages-otta)::bigint)::bigint END AS raw_waste +FROM + table_bloat + UNION +SELECT + 'index' as type, + schemaname, + tablename || '::' || iname as object_name, + ROUND(CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages/iotta::numeric END,1) AS bloat, + CASE WHEN ipages < iotta THEN '0' ELSE (bs*(ipages-iotta))::bigint END AS raw_waste +FROM + index_bloat) bloat_summary +WHERE + schemaname NOT IN (%s) +ORDER BY raw_waste DESC, bloat DESC`, excludedString) +} + +// Ref: https://github.com/heroku/heroku-pg-extras/blob/main/commands/blocking.js#L7 +const BLOCKING_QUERY = ` +SELECT + bl.pid AS blocked_pid, + ka.query AS blocking_statement, + now() - ka.query_start AS blocking_duration, + kl.pid AS blocking_pid, + a.query AS blocked_statement, + now() - a.query_start AS blocked_duration +FROM pg_catalog.pg_locks bl +JOIN pg_catalog.pg_stat_activity a + ON bl.pid = a.pid +JOIN pg_catalog.pg_locks kl +JOIN pg_catalog.pg_stat_activity ka + ON kl.pid = ka.pid + ON bl.transactionid = kl.transactionid AND bl.pid != kl.pid +WHERE NOT bl.granted` + +// Ref: https://github.com/heroku/heroku-pg-extras/blob/main/commands/cache_hit.js#L7 +const CACHE_QUERY = `SELECT +'index hit rate' AS name, +(sum(idx_blks_hit)) / nullif(sum(idx_blks_hit + idx_blks_read),0) AS ratio +FROM pg_statio_user_indexes +UNION ALL +SELECT +'table hit rate' AS name, +sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS ratio +FROM pg_statio_user_tables` + +const CALLS_QUERY = `SELECT +'index hit rate' AS name, +(sum(idx_blks_hit)) / nullif(sum(idx_blks_hit + idx_blks_read),0) AS ratio +FROM pg_statio_user_indexes +UNION ALL +SELECT +'table hit rate' AS name, +sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS ratio +FROM pg_statio_user_tables` + +func IndexSizesQuery() string { + return fmt.Sprintf(`SELECT c.relname AS name, +pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size +FROM pg_class c +LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) +WHERE n.nspname NOT IN (%s) +AND n.nspname !~ '^pg_toast' +AND c.relkind='i' +GROUP BY c.relname +ORDER BY sum(c.relpages) DESC`, excludedString) +} + +const INDEX_USAGE_QUERY = `SELECT relname, +CASE + WHEN idx_scan IS NULL THEN 'Insufficient data' + WHEN idx_scan = 0 THEN 'Insufficient data' + ELSE (100 * idx_scan / (seq_scan + idx_scan))::text +END percent_of_times_index_used, +n_live_tup rows_in_table +FROM +pg_stat_user_tables +ORDER BY +CASE + WHEN idx_scan is null then 1 + WHEN idx_scan = 0 then 1 + ELSE 0 +END, +n_live_tup DESC` + +const LOCKS_QUERY = `SELECT +pg_stat_activity.pid, +COALESCE(pg_class.relname, 'null') AS relname, +COALESCE(pg_locks.transactionid, 'null') AS transactionid, +pg_locks.granted, +pg_stat_activity.query, +age(now(),pg_stat_activity.query_start) AS age +FROM pg_stat_activity, pg_locks LEFT OUTER JOIN pg_class ON (pg_locks.relation = pg_class.oid) +WHERE pg_stat_activity.query <> '' +AND pg_locks.pid=pg_stat_activity.pid +AND pg_locks.mode = 'ExclusiveLock' +ORDER BY query_start` + +const LONG_RUNNING_QUERY = `SELECT +pid, +now() - pg_stat_activity.query_start AS duration, +query AS query +FROM +pg_stat_activity +WHERE +pg_stat_activity.query <> ''::text +AND state <> 'idle' +AND now() - pg_stat_activity.query_start > interval '5 minutes' +ORDER BY +now() - pg_stat_activity.query_start DESC` + +const OUTLIERS_QUERY = `SELECT +interval '1 millisecond' * total_exec_time AS total_exec_time, +to_char((total_exec_time/sum(total_exec_time) OVER()) * 100, 'FM90D0') || '%' AS prop_exec_time, +to_char(calls, 'FM999G999G999G990') AS ncalls, +interval '1 millisecond' * (blk_read_time + blk_write_time) AS sync_io_time, +query +FROM pg_stat_statements WHERE userid = (SELECT usesysid FROM pg_user WHERE usename = current_user LIMIT 1) +ORDER BY total_exec_time DESC +LIMIT 10` + +const REPLICATION_SLOTS_QUERY = `SELECT +s.slot_name, +s.active, +COALESCE(r.state, 'N/A') as state, +CASE WHEN r.client_addr IS NULL + THEN 'N/A' + ELSE r.client_addr::text +END replication_client_address, +GREATEST(0, ROUND((redo_lsn-restart_lsn)/1024/1024/1024, 2)) as replication_lag_gb +FROM pg_control_checkpoint(), pg_replication_slots s +LEFT JOIN pg_stat_replication r ON (r.pid = s.active_pid)` + +const ROLE_CONNECTIONS_QUERY = `SELECT +rolname, +( + SELECT + count(*) + FROM + pg_stat_activity + WHERE + pg_roles.rolname = pg_stat_activity.usename +) AS active_connections, +CASE WHEN rolconnlimit = -1 THEN current_setting('max_connections') :: int8 + ELSE rolconnlimit +END AS connection_limit +FROM +pg_roles +ORDER BY 2 DESC` + +const SEQ_SCANS_QUERY = `SELECT relname AS name, +seq_scan as count +FROM +pg_stat_user_tables +ORDER BY seq_scan DESC` + +func TableIndexSizesQuery() string { + return fmt.Sprintf(`SELECT c.relname AS table, +pg_size_pretty(pg_indexes_size(c.oid)) AS index_size +FROM pg_class c +LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) +WHERE n.nspname NOT IN (%s) +AND n.nspname !~ '^pg_toast' +AND c.relkind='r' +ORDER BY pg_indexes_size(c.oid) DESC`, excludedString) +} + +const TABLE_RECORD_COUNTS_QUERY = `SELECT +relname AS name, +n_live_tup AS estimated_count +FROM +pg_stat_user_tables +ORDER BY +n_live_tup DESC` + +func TableSizesQuery() string { + return fmt.Sprintf(`SELECT c.relname AS name, +pg_size_pretty(pg_table_size(c.oid)) AS size +FROM pg_class c +LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) +WHERE n.nspname NOT IN (%s) +AND n.nspname !~ '^pg_toast' +AND c.relkind='r' +ORDER BY pg_table_size(c.oid) DESC`, excludedString) +} + +func TotalIndexSizesQuery() string { + return fmt.Sprintf(`SELECT pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size +FROM pg_class c +LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) +WHERE n.nspname NOT IN (%s) +AND n.nspname !~ '^pg_toast' +AND c.relkind='i'`, excludedString) +} + +func TotalTableSizesQuery() string { + return fmt.Sprintf(`SELECT c.relname AS name, +pg_size_pretty(pg_total_relation_size(c.oid)) AS size +FROM pg_class c +LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) +WHERE n.nspname NOT IN (%s) +AND n.nspname !~ '^pg_toast' +AND c.relkind='r' +ORDER BY pg_total_relation_size(c.oid) DESC`, excludedString) +} + +func UnusedIndexesQuery() string { + return fmt.Sprintf(`SELECT +schemaname || '.' || relname AS table, +indexrelname AS index, +pg_size_pretty(pg_relation_size(i.indexrelid)) AS index_size, +idx_scan as index_scans +FROM pg_stat_user_indexes ui +JOIN pg_index i ON ui.indexrelid = i.indexrelid +WHERE NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 AND schemaname NOT IN (%s) +ORDER BY pg_relation_size(i.indexrelid) / nullif(idx_scan, 0) DESC NULLS FIRST, +pg_relation_size(i.indexrelid) DESC`, excludedString) +} + +func VacuumStatsQuery() string { + return fmt.Sprintf(`WITH table_opts AS ( + SELECT + pg_class.oid, relname, nspname, array_to_string(reloptions, '') AS relopts + FROM + pg_class INNER JOIN pg_namespace ns ON relnamespace = ns.oid +), vacuum_settings AS ( + SELECT + oid, relname, nspname, + CASE + WHEN relopts LIKE '%%autovacuum_vacuum_threshold%%' + THEN substring(relopts, '.*autovacuum_vacuum_threshold=([0-9.]+).*')::integer + ELSE current_setting('autovacuum_vacuum_threshold')::integer + END AS autovacuum_vacuum_threshold, + CASE + WHEN relopts LIKE '%%autovacuum_vacuum_scale_factor%%' + THEN substring(relopts, '.*autovacuum_vacuum_scale_factor=([0-9.]+).*')::real + ELSE current_setting('autovacuum_vacuum_scale_factor')::real + END AS autovacuum_vacuum_scale_factor + FROM + table_opts +) +SELECT + vacuum_settings.nspname AS schema, + vacuum_settings.relname AS table, + coalesce(to_char(psut.last_vacuum, 'YYYY-MM-DD HH24:MI'), '') AS last_vacuum, + coalesce(to_char(psut.last_autovacuum, 'YYYY-MM-DD HH24:MI'), '') AS last_autovacuum, + to_char(pg_class.reltuples, '9G999G999G999') AS rowcount, + to_char(psut.n_dead_tup, '9G999G999G999') AS dead_rowcount, + to_char(autovacuum_vacuum_threshold + + (autovacuum_vacuum_scale_factor::numeric * pg_class.reltuples), '9G999G999G999') AS autovacuum_threshold, + CASE + WHEN autovacuum_vacuum_threshold + (autovacuum_vacuum_scale_factor::numeric * pg_class.reltuples) < psut.n_dead_tup + THEN 'yes' + ELSE 'no' + END AS expect_autovacuum +FROM + pg_stat_user_tables psut INNER JOIN pg_class ON psut.relid = pg_class.oid +INNER JOIN vacuum_settings ON pg_class.oid = vacuum_settings.oid +WHERE schema NOT IN (%s) +ORDER BY + case + when pg_class.reltuples = -1 then 1 + else 0 + end, + 1`, excludedString) +} diff --git a/internal/inspect/replication_slots/replication_slots.go b/internal/inspect/replication_slots/replication_slots.go index 97408d6c7..d86b12194 100644 --- a/internal/inspect/replication_slots/replication_slots.go +++ b/internal/inspect/replication_slots/replication_slots.go @@ -8,25 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT - s.slot_name, - s.active, - COALESCE(r.state, 'N/A') as state, - CASE WHEN r.client_addr IS NULL - THEN 'N/A' - ELSE r.client_addr::text - END replication_client_address, - GREATEST(0, ROUND((redo_lsn-restart_lsn)/1024/1024/1024, 2)) as replication_lag_gb -FROM pg_control_checkpoint(), pg_replication_slots s -LEFT JOIN pg_stat_replication r ON (r.pid = s.active_pid); -` - type Result struct { Slot_name string Active string @@ -40,7 +27,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.REPLICATION_SLOTS_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/role_connections/role_connections.go b/internal/inspect/role_connections/role_connections.go index 0f5c92e8e..b0a2aa1fb 100644 --- a/internal/inspect/role_connections/role_connections.go +++ b/internal/inspect/role_connections/role_connections.go @@ -8,29 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -select - rolname, - ( - select - count(*) - from - pg_stat_activity - where - pg_roles.rolname = pg_stat_activity.usename - ) as active_connections, - case when rolconnlimit = -1 then current_setting('max_connections') :: int8 - else rolconnlimit - end as connection_limit -from - pg_roles -order by 2 desc` - type Result struct { Rolname string Active_connections int @@ -42,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.ROLE_CONNECTIONS_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/seq_scans/seq_scans.go b/internal/inspect/seq_scans/seq_scans.go index e02351187..8d29a67ba 100644 --- a/internal/inspect/seq_scans/seq_scans.go +++ b/internal/inspect/seq_scans/seq_scans.go @@ -8,18 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT relname AS name, - seq_scan as count -FROM - pg_stat_user_tables -ORDER BY seq_scan DESC;` - type Result struct { Name string Count string @@ -30,7 +24,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.SEQ_SCANS_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/table_index_sizes/table_index_sizes.go b/internal/inspect/table_index_sizes/table_index_sizes.go index 629058333..f4f8addb3 100644 --- a/internal/inspect/table_index_sizes/table_index_sizes.go +++ b/internal/inspect/table_index_sizes/table_index_sizes.go @@ -8,21 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT c.relname AS table, - pg_size_pretty(pg_indexes_size(c.oid)) AS index_size -FROM pg_class c -LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') -AND n.nspname !~ '^pg_toast' -AND c.relkind='r' -ORDER BY pg_indexes_size(c.oid) DESC;` - type Result struct { Table string Index_size string @@ -33,7 +24,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.TableIndexSizesQuery()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/table_record_counts/table_record_counts.go b/internal/inspect/table_record_counts/table_record_counts.go index ba204c84c..c4ab62a2f 100644 --- a/internal/inspect/table_record_counts/table_record_counts.go +++ b/internal/inspect/table_record_counts/table_record_counts.go @@ -8,20 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT - relname AS name, - n_live_tup AS estimated_count -FROM - pg_stat_user_tables -ORDER BY - n_live_tup DESC;` - type Result struct { Name string Estimated_count string @@ -32,7 +24,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.TABLE_RECORD_COUNTS_QUERY) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/table_sizes/table_sizes.go b/internal/inspect/table_sizes/table_sizes.go index 579ba1721..d807e315f 100644 --- a/internal/inspect/table_sizes/table_sizes.go +++ b/internal/inspect/table_sizes/table_sizes.go @@ -18,7 +18,7 @@ SELECT c.relname AS name, pg_size_pretty(pg_table_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') +WHERE n.nspname NOT IN ('pg_catalog', 'information_schema', 'auth', 'realtime', 'pgsodium', 'supabase_migrations', 'vault', 'storage') AND n.nspname !~ '^pg_toast' AND c.relkind='r' ORDER BY pg_table_size(c.oid) DESC;` diff --git a/internal/inspect/total_index_size/total_index_size.go b/internal/inspect/total_index_size/total_index_size.go index 389001778..b59e8590f 100644 --- a/internal/inspect/total_index_size/total_index_size.go +++ b/internal/inspect/total_index_size/total_index_size.go @@ -8,20 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size -FROM pg_class c -LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') -AND n.nspname !~ '^pg_toast' -AND c.relkind='i'; -` - type Result struct { Size string } @@ -31,7 +23,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.TotalIndexSizesQuery()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/total_table_sizes/total_table_sizes.go b/internal/inspect/total_table_sizes/total_table_sizes.go index e47f90b6f..2016af2e3 100644 --- a/internal/inspect/total_table_sizes/total_table_sizes.go +++ b/internal/inspect/total_table_sizes/total_table_sizes.go @@ -8,22 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT c.relname AS name, - pg_size_pretty(pg_total_relation_size(c.oid)) AS size -FROM pg_class c -LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') -AND n.nspname !~ '^pg_toast' -AND c.relkind='r' -ORDER BY pg_total_relation_size(c.oid) DESC; -` - type Result struct { Name string Size string @@ -34,7 +24,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.TotalTableSizesQuery()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/unused_indexes/unused_indexes.go b/internal/inspect/unused_indexes/unused_indexes.go index 18fc06dc0..58cd3ce92 100644 --- a/internal/inspect/unused_indexes/unused_indexes.go +++ b/internal/inspect/unused_indexes/unused_indexes.go @@ -8,23 +8,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT - schemaname || '.' || relname AS table, - indexrelname AS index, - pg_size_pretty(pg_relation_size(i.indexrelid)) AS index_size, - idx_scan as index_scans -FROM pg_stat_user_indexes ui -JOIN pg_index i ON ui.indexrelid = i.indexrelid -WHERE NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 -ORDER BY pg_relation_size(i.indexrelid) / nullif(idx_scan, 0) DESC NULLS FIRST, -pg_relation_size(i.indexrelid) DESC;` - type Result struct { Table string Index string @@ -37,7 +26,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.UnusedIndexesQuery()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/vacuum_stats/vacuum_stats.go b/internal/inspect/vacuum_stats/vacuum_stats.go index 220990ed4..332305d3b 100644 --- a/internal/inspect/vacuum_stats/vacuum_stats.go +++ b/internal/inspect/vacuum_stats/vacuum_stats.go @@ -9,57 +9,12 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -WITH table_opts AS ( - SELECT - pg_class.oid, relname, nspname, array_to_string(reloptions, '') AS relopts - FROM - pg_class INNER JOIN pg_namespace ns ON relnamespace = ns.oid -), vacuum_settings AS ( - SELECT - oid, relname, nspname, - CASE - WHEN relopts LIKE '%autovacuum_vacuum_threshold%' - THEN substring(relopts, '.*autovacuum_vacuum_threshold=([0-9.]+).*')::integer - ELSE current_setting('autovacuum_vacuum_threshold')::integer - END AS autovacuum_vacuum_threshold, - CASE - WHEN relopts LIKE '%autovacuum_vacuum_scale_factor%' - THEN substring(relopts, '.*autovacuum_vacuum_scale_factor=([0-9.]+).*')::real - ELSE current_setting('autovacuum_vacuum_scale_factor')::real - END AS autovacuum_vacuum_scale_factor - FROM - table_opts -) -SELECT - vacuum_settings.nspname AS schema, - vacuum_settings.relname AS table, - coalesce(to_char(psut.last_vacuum, 'YYYY-MM-DD HH24:MI'), '') AS last_vacuum, - coalesce(to_char(psut.last_autovacuum, 'YYYY-MM-DD HH24:MI'), '') AS last_autovacuum, - to_char(pg_class.reltuples, '9G999G999G999') AS rowcount, - to_char(psut.n_dead_tup, '9G999G999G999') AS dead_rowcount, - to_char(autovacuum_vacuum_threshold - + (autovacuum_vacuum_scale_factor::numeric * pg_class.reltuples), '9G999G999G999') AS autovacuum_threshold, - CASE - WHEN autovacuum_vacuum_threshold + (autovacuum_vacuum_scale_factor::numeric * pg_class.reltuples) < psut.n_dead_tup - THEN 'yes' - ELSE 'no' - END AS expect_autovacuum -FROM - pg_stat_user_tables psut INNER JOIN pg_class ON psut.relid = pg_class.oid -INNER JOIN vacuum_settings ON pg_class.oid = vacuum_settings.oid -ORDER BY - case - when pg_class.reltuples = -1 then 1 - else 0 - end, - 1` - type Result struct { Schema string Table string @@ -76,7 +31,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.VacuumStatsQuery()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } From c3c43129ad94c28a62d27336689c5db198a5dad4 Mon Sep 17 00:00:00 2001 From: Chris Gwilliams <517923+encima@users.noreply.github.com> Date: Wed, 10 Apr 2024 14:19:23 +0300 Subject: [PATCH 02/14] add explanation for cache hit and if action is needed --- internal/inspect/cache/cache.go | 15 ++++++++++++--- 1 file changed, 12 insertions(+), 3 deletions(-) diff --git a/internal/inspect/cache/cache.go b/internal/inspect/cache/cache.go index 10c552d18..eb16a7bb4 100644 --- a/internal/inspect/cache/cache.go +++ b/internal/inspect/cache/cache.go @@ -33,10 +33,19 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu return err } // TODO: implement a markdown table marshaller - table := "|Name|Ratio|\n|-|-|\n" + table := "|Name|Ratio|OK?|Explanation|\n|-|-|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%.6f`|\n", r.Name, r.Ratio) - + ok := "Yup!" + if r.Ratio < 0.94 { + ok = "Maybe not..." + } + var explanation string + if r.Name == "index hit rate" { + explanation = "This is the ratio of index hits to index scans. If this ratio is low, it means that the database is not using indexes effectively. Check the `index-usage` command for more info." + } else if r.Name == "table hit rate" { + explanation = "This is the ratio of table hits to table scans. If this ratio is low, it means that your queries are not finding the data effectively. Check your query performance and it might be worth increasing your compute." + } + table += fmt.Sprintf("|`%s`|`%.6f`|`%s`|`%s`|\n", r.Name, r.Ratio, ok, explanation) } return list.RenderTable(table) } From 78fd5a2dbde93d8f5951e422c00e357813320250 Mon Sep 17 00:00:00 2001 From: Chris Gwilliams <517923+encima@users.noreply.github.com> Date: Thu, 11 Apr 2024 09:03:42 +0300 Subject: [PATCH 03/14] modify queries to be parameterized instead of formatted strings --- internal/inspect/bloat/bloat.go | 2 +- internal/inspect/index_sizes/index_sizes.go | 2 +- internal/inspect/queries.go | 88 +++++++------------ .../table_index_sizes/table_index_sizes.go | 2 +- .../total_index_size/total_index_size.go | 2 +- .../total_table_sizes/total_table_sizes.go | 2 +- .../inspect/unused_indexes/unused_indexes.go | 2 +- internal/inspect/vacuum_stats/vacuum_stats.go | 2 +- 8 files changed, 38 insertions(+), 64 deletions(-) diff --git a/internal/inspect/bloat/bloat.go b/internal/inspect/bloat/bloat.go index 4cd78d2fb..b9f63707a 100644 --- a/internal/inspect/bloat/bloat.go +++ b/internal/inspect/bloat/bloat.go @@ -27,7 +27,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.BloatQuery()) + rows, err := conn.Query(ctx, inspect.BLOAT_QUERY, inspect.GetExcludedSchemas()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/index_sizes/index_sizes.go b/internal/inspect/index_sizes/index_sizes.go index 57cca59f6..d05e72c42 100644 --- a/internal/inspect/index_sizes/index_sizes.go +++ b/internal/inspect/index_sizes/index_sizes.go @@ -24,7 +24,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.IndexSizesQuery()) + rows, err := conn.Query(ctx, inspect.INDEX_SIZE_QUERY, inspect.GetExcludedSchemas()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index 88d566293..f097d41b4 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -1,31 +1,20 @@ package inspect import ( - "fmt" - "strings" - "github.com/supabase/cli/internal/utils" ) -var excludedString string - -func init() { - var excluded = make([]string, len(utils.InternalSchemas)) - for i, schema := range utils.InternalSchemas { - excluded[i] = fmt.Sprintf("'%s'", schema) - } - excluded = append(excluded, "'pg_catalog'") - excludedString = strings.Join(excluded, ", ") +func GetExcludedSchemas() []string { + return append(utils.InternalSchemas, "pg_catalog") } -func BloatQuery() string { - return fmt.Sprintf(`WITH constants AS ( +const BLOAT_QUERY = `WITH constants AS ( SELECT current_setting('block_size')::numeric AS bs, 23 AS hdr, 4 AS ma ), bloat_info AS ( SELECT ma,bs,schemaname,tablename, - (datawidth+(hdr+ma-(case when hdr%%ma=0 THEN ma ELSE hdr%%ma END)))::numeric AS datahdr, - (maxfracsum*(nullhdr+ma-(case when nullhdr%%ma=0 THEN ma ELSE nullhdr%%ma END))) AS nullhdr2 + (datawidth+(hdr+ma-(case when hdr%ma=0 THEN ma ELSE hdr%ma END)))::numeric AS datahdr, + (maxfracsum*(nullhdr+ma-(case when nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2 FROM ( SELECT schemaname, tablename, hdr, ma, bs, @@ -43,7 +32,7 @@ func BloatQuery() string { SELECT schemaname, tablename, cc.relpages, bs, CEIL((cc.reltuples*((datahdr+ma- - (CASE WHEN datahdr%%ma=0 THEN ma ELSE datahdr%%ma END))+nullhdr2+4))/(bs-20::float)) AS otta + (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::float)) AS otta FROM bloat_info JOIN pg_class cc ON cc.relname = bloat_info.tablename JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = bloat_info.schemaname AND nn.nspname <> 'information_schema' @@ -79,9 +68,8 @@ SELECT FROM index_bloat) bloat_summary WHERE - schemaname NOT IN (%s) -ORDER BY raw_waste DESC, bloat DESC`, excludedString) -} + schemaname NOT IN (SELECT unnest($1::text[])) +ORDER BY raw_waste DESC, bloat DESC` // Ref: https://github.com/heroku/heroku-pg-extras/blob/main/commands/blocking.js#L7 const BLOCKING_QUERY = ` @@ -122,17 +110,15 @@ SELECT sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS ratio FROM pg_statio_user_tables` -func IndexSizesQuery() string { - return fmt.Sprintf(`SELECT c.relname AS name, +const INDEX_SIZE_QUERY = `SELECT c.relname AS name, pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN (%s) +WHERE n.nspname NOT IN (%1) AND n.nspname !~ '^pg_toast' AND c.relkind='i' GROUP BY c.relname -ORDER BY sum(c.relpages) DESC`, excludedString) -} +ORDER BY sum(c.relpages) DESC` const INDEX_USAGE_QUERY = `SELECT relname, CASE @@ -222,16 +208,14 @@ FROM pg_stat_user_tables ORDER BY seq_scan DESC` -func TableIndexSizesQuery() string { - return fmt.Sprintf(`SELECT c.relname AS table, +const TABLE_INDEX_SIZE_QUERY = `SELECT c.relname AS table, pg_size_pretty(pg_indexes_size(c.oid)) AS index_size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN (%s) +WHERE n.nspname NOT IN (SELECT unnest($1::text[])) AND n.nspname !~ '^pg_toast' AND c.relkind='r' -ORDER BY pg_indexes_size(c.oid) DESC`, excludedString) -} +ORDER BY pg_indexes_size(c.oid) DESC` const TABLE_RECORD_COUNTS_QUERY = `SELECT relname AS name, @@ -241,52 +225,43 @@ pg_stat_user_tables ORDER BY n_live_tup DESC` -func TableSizesQuery() string { - return fmt.Sprintf(`SELECT c.relname AS name, +const TABLE_SIZE_QUERY = `SELECT c.relname AS name, pg_size_pretty(pg_table_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN (%s) +WHERE n.nspname NOT IN (SELECT unnest($1::text[])) AND n.nspname !~ '^pg_toast' AND c.relkind='r' -ORDER BY pg_table_size(c.oid) DESC`, excludedString) -} +ORDER BY pg_table_size(c.oid) DESC` -func TotalIndexSizesQuery() string { - return fmt.Sprintf(`SELECT pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size +const TOTAL_INDEX_SIZE_QUERY = `SELECT pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN (%s) +WHERE n.nspname NOT IN (SELECT unnest($1::text[])) AND n.nspname !~ '^pg_toast' -AND c.relkind='i'`, excludedString) -} +AND c.relkind='i'` -func TotalTableSizesQuery() string { - return fmt.Sprintf(`SELECT c.relname AS name, +const TOTAL_TABLE_SIZE_QUERY = `SELECT c.relname AS name, pg_size_pretty(pg_total_relation_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN (%s) +WHERE n.nspname NOT IN (SELECT unnest($1::text[])) AND n.nspname !~ '^pg_toast' AND c.relkind='r' -ORDER BY pg_total_relation_size(c.oid) DESC`, excludedString) -} +ORDER BY pg_total_relation_size(c.oid) DESC` -func UnusedIndexesQuery() string { - return fmt.Sprintf(`SELECT +const UNUSED_INDEXES_QUERY = `SELECT schemaname || '.' || relname AS table, indexrelname AS index, pg_size_pretty(pg_relation_size(i.indexrelid)) AS index_size, idx_scan as index_scans FROM pg_stat_user_indexes ui JOIN pg_index i ON ui.indexrelid = i.indexrelid -WHERE NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 AND schemaname NOT IN (%s) +WHERE NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 AND schemaname NOT IN (SELECT unnest($1::text[])) ORDER BY pg_relation_size(i.indexrelid) / nullif(idx_scan, 0) DESC NULLS FIRST, -pg_relation_size(i.indexrelid) DESC`, excludedString) -} +pg_relation_size(i.indexrelid) DESC` -func VacuumStatsQuery() string { - return fmt.Sprintf(`WITH table_opts AS ( +const VACUUM_STATS_QUERY = `WITH table_opts AS ( SELECT pg_class.oid, relname, nspname, array_to_string(reloptions, '') AS relopts FROM @@ -295,12 +270,12 @@ func VacuumStatsQuery() string { SELECT oid, relname, nspname, CASE - WHEN relopts LIKE '%%autovacuum_vacuum_threshold%%' + WHEN relopts LIKE '%autovacuum_vacuum_threshold%' THEN substring(relopts, '.*autovacuum_vacuum_threshold=([0-9.]+).*')::integer ELSE current_setting('autovacuum_vacuum_threshold')::integer END AS autovacuum_vacuum_threshold, CASE - WHEN relopts LIKE '%%autovacuum_vacuum_scale_factor%%' + WHEN relopts LIKE '%autovacuum_vacuum_scale_factor%' THEN substring(relopts, '.*autovacuum_vacuum_scale_factor=([0-9.]+).*')::real ELSE current_setting('autovacuum_vacuum_scale_factor')::real END AS autovacuum_vacuum_scale_factor @@ -324,11 +299,10 @@ SELECT FROM pg_stat_user_tables psut INNER JOIN pg_class ON psut.relid = pg_class.oid INNER JOIN vacuum_settings ON pg_class.oid = vacuum_settings.oid -WHERE schema NOT IN (%s) +WHERE schema NOT IN (SELECT unnest($1::text[])) ORDER BY case when pg_class.reltuples = -1 then 1 else 0 end, - 1`, excludedString) -} + 1` diff --git a/internal/inspect/table_index_sizes/table_index_sizes.go b/internal/inspect/table_index_sizes/table_index_sizes.go index f4f8addb3..0b7f7b6e7 100644 --- a/internal/inspect/table_index_sizes/table_index_sizes.go +++ b/internal/inspect/table_index_sizes/table_index_sizes.go @@ -24,7 +24,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TableIndexSizesQuery()) + rows, err := conn.Query(ctx, inspect.TABLE_INDEX_SIZE_QUERY, inspect.GetExcludedSchemas()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/total_index_size/total_index_size.go b/internal/inspect/total_index_size/total_index_size.go index b59e8590f..111f4a846 100644 --- a/internal/inspect/total_index_size/total_index_size.go +++ b/internal/inspect/total_index_size/total_index_size.go @@ -23,7 +23,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TotalIndexSizesQuery()) + rows, err := conn.Query(ctx, inspect.TOTAL_INDEX_SIZE_QUERY, inspect.GetExcludedSchemas()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/total_table_sizes/total_table_sizes.go b/internal/inspect/total_table_sizes/total_table_sizes.go index 2016af2e3..436d873a8 100644 --- a/internal/inspect/total_table_sizes/total_table_sizes.go +++ b/internal/inspect/total_table_sizes/total_table_sizes.go @@ -24,7 +24,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TotalTableSizesQuery()) + rows, err := conn.Query(ctx, inspect.TOTAL_TABLE_SIZE_QUERY, inspect.GetExcludedSchemas()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/unused_indexes/unused_indexes.go b/internal/inspect/unused_indexes/unused_indexes.go index 58cd3ce92..f1c17ffcf 100644 --- a/internal/inspect/unused_indexes/unused_indexes.go +++ b/internal/inspect/unused_indexes/unused_indexes.go @@ -26,7 +26,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.UnusedIndexesQuery()) + rows, err := conn.Query(ctx, inspect.UNUSED_INDEXES_QUERY, inspect.GetExcludedSchemas()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/vacuum_stats/vacuum_stats.go b/internal/inspect/vacuum_stats/vacuum_stats.go index 332305d3b..e3d7896ac 100644 --- a/internal/inspect/vacuum_stats/vacuum_stats.go +++ b/internal/inspect/vacuum_stats/vacuum_stats.go @@ -31,7 +31,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.VacuumStatsQuery()) + rows, err := conn.Query(ctx, inspect.VACUUM_STATS_QUERY, inspect.GetExcludedSchemas()) if err != nil { return errors.Errorf("failed to query rows: %w", err) } From 9c3b15f7d6c6a53db4bec793eaec6f4cc40a9fd4 Mon Sep 17 00:00:00 2001 From: Qiao Han Date: Fri, 12 Apr 2024 11:28:24 +0800 Subject: [PATCH 04/14] chore: reuse table size query --- internal/db/reset/reset.go | 4 ++-- internal/inspect/bloat/bloat.go | 3 ++- internal/inspect/index_sizes/index_sizes.go | 3 ++- internal/inspect/queries.go | 22 ++++++------------- .../table_index_sizes/table_index_sizes.go | 3 ++- internal/inspect/table_sizes/table_sizes.go | 14 +++--------- .../total_index_size/total_index_size.go | 3 ++- .../total_table_sizes/total_table_sizes.go | 3 ++- .../inspect/unused_indexes/unused_indexes.go | 3 ++- internal/inspect/vacuum_stats/vacuum_stats.go | 3 ++- 10 files changed, 26 insertions(+), 35 deletions(-) diff --git a/internal/db/reset/reset.go b/internal/db/reset/reset.go index 27ccd3d94..24aaab2c3 100644 --- a/internal/db/reset/reset.go +++ b/internal/db/reset/reset.go @@ -289,7 +289,7 @@ func resetRemote(ctx context.Context, version string, config pgconn.Config, fsys } func ListSchemas(ctx context.Context, conn *pgx.Conn, exclude ...string) ([]string, error) { - exclude = likeEscapeSchema(exclude) + exclude = LikeEscapeSchema(exclude) if len(exclude) == 0 { exclude = append(exclude, "") } @@ -300,7 +300,7 @@ func ListSchemas(ctx context.Context, conn *pgx.Conn, exclude ...string) ([]stri return pgxv5.CollectStrings(rows) } -func likeEscapeSchema(schemas []string) (result []string) { +func LikeEscapeSchema(schemas []string) (result []string) { // Treat _ as literal, * as any character replacer := strings.NewReplacer("_", `\_`, "*", "%") for _, sch := range schemas { diff --git a/internal/inspect/bloat/bloat.go b/internal/inspect/bloat/bloat.go index b9f63707a..6bb2c57c9 100644 --- a/internal/inspect/bloat/bloat.go +++ b/internal/inspect/bloat/bloat.go @@ -8,6 +8,7 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" @@ -27,7 +28,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.BLOAT_QUERY, inspect.GetExcludedSchemas()) + rows, err := conn.Query(ctx, inspect.BLOAT_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/index_sizes/index_sizes.go b/internal/inspect/index_sizes/index_sizes.go index d05e72c42..46e50f5c5 100644 --- a/internal/inspect/index_sizes/index_sizes.go +++ b/internal/inspect/index_sizes/index_sizes.go @@ -8,6 +8,7 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" @@ -24,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.INDEX_SIZE_QUERY, inspect.GetExcludedSchemas()) + rows, err := conn.Query(ctx, inspect.INDEX_SIZE_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index f097d41b4..b4d44b960 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -1,13 +1,5 @@ package inspect -import ( - "github.com/supabase/cli/internal/utils" -) - -func GetExcludedSchemas() []string { - return append(utils.InternalSchemas, "pg_catalog") -} - const BLOAT_QUERY = `WITH constants AS ( SELECT current_setting('block_size')::numeric AS bs, 23 AS hdr, 4 AS ma ), bloat_info AS ( @@ -68,7 +60,7 @@ SELECT FROM index_bloat) bloat_summary WHERE - schemaname NOT IN (SELECT unnest($1::text[])) + schemaname NOT LIKE ANY($1) ORDER BY raw_waste DESC, bloat DESC` // Ref: https://github.com/heroku/heroku-pg-extras/blob/main/commands/blocking.js#L7 @@ -212,7 +204,7 @@ const TABLE_INDEX_SIZE_QUERY = `SELECT c.relname AS table, pg_size_pretty(pg_indexes_size(c.oid)) AS index_size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN (SELECT unnest($1::text[])) +WHERE n.nspname NOT LIKE ANY($1) AND n.nspname !~ '^pg_toast' AND c.relkind='r' ORDER BY pg_indexes_size(c.oid) DESC` @@ -229,7 +221,7 @@ const TABLE_SIZE_QUERY = `SELECT c.relname AS name, pg_size_pretty(pg_table_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN (SELECT unnest($1::text[])) +WHERE n.nspname NOT LIKE ANY($1) AND n.nspname !~ '^pg_toast' AND c.relkind='r' ORDER BY pg_table_size(c.oid) DESC` @@ -237,7 +229,7 @@ ORDER BY pg_table_size(c.oid) DESC` const TOTAL_INDEX_SIZE_QUERY = `SELECT pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN (SELECT unnest($1::text[])) +WHERE n.nspname NOT LIKE ANY($1) AND n.nspname !~ '^pg_toast' AND c.relkind='i'` @@ -245,7 +237,7 @@ const TOTAL_TABLE_SIZE_QUERY = `SELECT c.relname AS name, pg_size_pretty(pg_total_relation_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN (SELECT unnest($1::text[])) +WHERE n.nspname NOT LIKE ANY($1) AND n.nspname !~ '^pg_toast' AND c.relkind='r' ORDER BY pg_total_relation_size(c.oid) DESC` @@ -257,7 +249,7 @@ pg_size_pretty(pg_relation_size(i.indexrelid)) AS index_size, idx_scan as index_scans FROM pg_stat_user_indexes ui JOIN pg_index i ON ui.indexrelid = i.indexrelid -WHERE NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 AND schemaname NOT IN (SELECT unnest($1::text[])) +WHERE NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 AND schemaname NOT LIKE ANY($1) ORDER BY pg_relation_size(i.indexrelid) / nullif(idx_scan, 0) DESC NULLS FIRST, pg_relation_size(i.indexrelid) DESC` @@ -299,7 +291,7 @@ SELECT FROM pg_stat_user_tables psut INNER JOIN pg_class ON psut.relid = pg_class.oid INNER JOIN vacuum_settings ON pg_class.oid = vacuum_settings.oid -WHERE schema NOT IN (SELECT unnest($1::text[])) +WHERE schema NOT LIKE ANY($1) ORDER BY case when pg_class.reltuples = -1 then 1 diff --git a/internal/inspect/table_index_sizes/table_index_sizes.go b/internal/inspect/table_index_sizes/table_index_sizes.go index 0b7f7b6e7..9d906ffee 100644 --- a/internal/inspect/table_index_sizes/table_index_sizes.go +++ b/internal/inspect/table_index_sizes/table_index_sizes.go @@ -8,6 +8,7 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" @@ -24,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TABLE_INDEX_SIZE_QUERY, inspect.GetExcludedSchemas()) + rows, err := conn.Query(ctx, inspect.TABLE_INDEX_SIZE_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/table_sizes/table_sizes.go b/internal/inspect/table_sizes/table_sizes.go index d807e315f..fdaa42159 100644 --- a/internal/inspect/table_sizes/table_sizes.go +++ b/internal/inspect/table_sizes/table_sizes.go @@ -8,21 +8,13 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" + "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" "github.com/supabase/cli/internal/utils/pgxv5" ) -const QUERY = ` -SELECT c.relname AS name, - pg_size_pretty(pg_table_size(c.oid)) AS size -FROM pg_class c -LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN ('pg_catalog', 'information_schema', 'auth', 'realtime', 'pgsodium', 'supabase_migrations', 'vault', 'storage') -AND n.nspname !~ '^pg_toast' -AND c.relkind='r' -ORDER BY pg_table_size(c.oid) DESC;` - type Result struct { Name string Size string @@ -33,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, QUERY) + rows, err := conn.Query(ctx, inspect.TABLE_SIZE_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/total_index_size/total_index_size.go b/internal/inspect/total_index_size/total_index_size.go index 111f4a846..73ee9e672 100644 --- a/internal/inspect/total_index_size/total_index_size.go +++ b/internal/inspect/total_index_size/total_index_size.go @@ -8,6 +8,7 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" @@ -23,7 +24,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TOTAL_INDEX_SIZE_QUERY, inspect.GetExcludedSchemas()) + rows, err := conn.Query(ctx, inspect.TOTAL_INDEX_SIZE_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/total_table_sizes/total_table_sizes.go b/internal/inspect/total_table_sizes/total_table_sizes.go index 436d873a8..3e9754555 100644 --- a/internal/inspect/total_table_sizes/total_table_sizes.go +++ b/internal/inspect/total_table_sizes/total_table_sizes.go @@ -8,6 +8,7 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" @@ -24,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TOTAL_TABLE_SIZE_QUERY, inspect.GetExcludedSchemas()) + rows, err := conn.Query(ctx, inspect.TOTAL_TABLE_SIZE_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/unused_indexes/unused_indexes.go b/internal/inspect/unused_indexes/unused_indexes.go index f1c17ffcf..f47533459 100644 --- a/internal/inspect/unused_indexes/unused_indexes.go +++ b/internal/inspect/unused_indexes/unused_indexes.go @@ -8,6 +8,7 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" @@ -26,7 +27,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.UNUSED_INDEXES_QUERY, inspect.GetExcludedSchemas()) + rows, err := conn.Query(ctx, inspect.UNUSED_INDEXES_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/vacuum_stats/vacuum_stats.go b/internal/inspect/vacuum_stats/vacuum_stats.go index e3d7896ac..cc98b6b06 100644 --- a/internal/inspect/vacuum_stats/vacuum_stats.go +++ b/internal/inspect/vacuum_stats/vacuum_stats.go @@ -9,6 +9,7 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" @@ -31,7 +32,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.VACUUM_STATS_QUERY, inspect.GetExcludedSchemas()) + rows, err := conn.Query(ctx, inspect.VACUUM_STATS_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } From 5c3e855c9817aff939e18669f43254652072b98b Mon Sep 17 00:00:00 2001 From: Qiao Han Date: Fri, 12 Apr 2024 11:39:32 +0800 Subject: [PATCH 05/14] fix: not operator order --- internal/inspect/queries.go | 15 +++++++-------- 1 file changed, 7 insertions(+), 8 deletions(-) diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index b4d44b960..79b207809 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -59,8 +59,7 @@ SELECT CASE WHEN ipages < iotta THEN '0' ELSE (bs*(ipages-iotta))::bigint END AS raw_waste FROM index_bloat) bloat_summary -WHERE - schemaname NOT LIKE ANY($1) +WHERE NOT schemaname LIKE ANY($1) ORDER BY raw_waste DESC, bloat DESC` // Ref: https://github.com/heroku/heroku-pg-extras/blob/main/commands/blocking.js#L7 @@ -204,7 +203,7 @@ const TABLE_INDEX_SIZE_QUERY = `SELECT c.relname AS table, pg_size_pretty(pg_indexes_size(c.oid)) AS index_size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT LIKE ANY($1) +WHERE NOT n.nspname LIKE ANY($1) AND n.nspname !~ '^pg_toast' AND c.relkind='r' ORDER BY pg_indexes_size(c.oid) DESC` @@ -221,7 +220,7 @@ const TABLE_SIZE_QUERY = `SELECT c.relname AS name, pg_size_pretty(pg_table_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT LIKE ANY($1) +WHERE NOT n.nspname LIKE ANY($1) AND n.nspname !~ '^pg_toast' AND c.relkind='r' ORDER BY pg_table_size(c.oid) DESC` @@ -229,7 +228,7 @@ ORDER BY pg_table_size(c.oid) DESC` const TOTAL_INDEX_SIZE_QUERY = `SELECT pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT LIKE ANY($1) +WHERE NOT n.nspname LIKE ANY($1) AND n.nspname !~ '^pg_toast' AND c.relkind='i'` @@ -237,7 +236,7 @@ const TOTAL_TABLE_SIZE_QUERY = `SELECT c.relname AS name, pg_size_pretty(pg_total_relation_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT LIKE ANY($1) +WHERE NOT n.nspname LIKE ANY($1) AND n.nspname !~ '^pg_toast' AND c.relkind='r' ORDER BY pg_total_relation_size(c.oid) DESC` @@ -249,7 +248,7 @@ pg_size_pretty(pg_relation_size(i.indexrelid)) AS index_size, idx_scan as index_scans FROM pg_stat_user_indexes ui JOIN pg_index i ON ui.indexrelid = i.indexrelid -WHERE NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 AND schemaname NOT LIKE ANY($1) +WHERE NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 AND NOT schemaname LIKE ANY($1) ORDER BY pg_relation_size(i.indexrelid) / nullif(idx_scan, 0) DESC NULLS FIRST, pg_relation_size(i.indexrelid) DESC` @@ -291,7 +290,7 @@ SELECT FROM pg_stat_user_tables psut INNER JOIN pg_class ON psut.relid = pg_class.oid INNER JOIN vacuum_settings ON pg_class.oid = vacuum_settings.oid -WHERE schema NOT LIKE ANY($1) +WHERE NOT schema LIKE ANY($1) ORDER BY case when pg_class.reltuples = -1 then 1 From be29d8339c1b7477c5280d97c2d190588def1312 Mon Sep 17 00:00:00 2001 From: Qiao Han Date: Fri, 12 Apr 2024 11:59:58 +0800 Subject: [PATCH 06/14] fix: vacuum stats query where clause --- internal/inspect/queries.go | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index 79b207809..91cdc6f2c 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -290,7 +290,7 @@ SELECT FROM pg_stat_user_tables psut INNER JOIN pg_class ON psut.relid = pg_class.oid INNER JOIN vacuum_settings ON pg_class.oid = vacuum_settings.oid -WHERE NOT schema LIKE ANY($1) +WHERE NOT vacuum_settings.nspname LIKE ANY($1) ORDER BY case when pg_class.reltuples = -1 then 1 From 03c5f1807fd498cf2b89ef433500980630fe66fc Mon Sep 17 00:00:00 2001 From: Han Qiao Date: Fri, 12 Apr 2024 12:13:21 +0800 Subject: [PATCH 07/14] Update queries.go --- internal/inspect/queries.go | 16 ++++++++-------- 1 file changed, 8 insertions(+), 8 deletions(-) diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index 91cdc6f2c..de95fc134 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -92,14 +92,14 @@ sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS ratio FROM pg_statio_user_tables` const CALLS_QUERY = `SELECT -'index hit rate' AS name, -(sum(idx_blks_hit)) / nullif(sum(idx_blks_hit + idx_blks_read),0) AS ratio -FROM pg_statio_user_indexes -UNION ALL -SELECT -'table hit rate' AS name, -sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS ratio -FROM pg_statio_user_tables` + query, + interval '1 millisecond' * total_exec_time AS total_exec_time, + to_char((total_exec_time/sum(total_exec_time) OVER()) * 100, 'FM90D0') || '%' AS prop_exec_time, + to_char(calls, 'FM999G999G990') AS ncalls, + interval '1 millisecond' * (blk_read_time + blk_write_time) AS sync_io_time +FROM pg_stat_statements +ORDER BY calls DESC +LIMIT 10` const INDEX_SIZE_QUERY = `SELECT c.relname AS name, pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size From 460cc907723d0323306c89d73eb80c8ba5fd50e3 Mon Sep 17 00:00:00 2001 From: Han Qiao Date: Fri, 12 Apr 2024 13:57:17 +0800 Subject: [PATCH 08/14] Apply suggestions from code review --- internal/inspect/queries.go | 15 +++++---------- 1 file changed, 5 insertions(+), 10 deletions(-) diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index de95fc134..c0141c2a4 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -106,8 +106,7 @@ pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE n.nspname NOT IN (%1) -AND n.nspname !~ '^pg_toast' -AND c.relkind='i' +AND c.relkind = 'i' GROUP BY c.relname ORDER BY sum(c.relpages) DESC` @@ -204,8 +203,7 @@ pg_size_pretty(pg_indexes_size(c.oid)) AS index_size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE NOT n.nspname LIKE ANY($1) -AND n.nspname !~ '^pg_toast' -AND c.relkind='r' +AND c.relkind = 'r' ORDER BY pg_indexes_size(c.oid) DESC` const TABLE_RECORD_COUNTS_QUERY = `SELECT @@ -221,24 +219,21 @@ pg_size_pretty(pg_table_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE NOT n.nspname LIKE ANY($1) -AND n.nspname !~ '^pg_toast' -AND c.relkind='r' +AND c.relkind = 'r' ORDER BY pg_table_size(c.oid) DESC` const TOTAL_INDEX_SIZE_QUERY = `SELECT pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE NOT n.nspname LIKE ANY($1) -AND n.nspname !~ '^pg_toast' -AND c.relkind='i'` +AND c.relkind = 'i'` const TOTAL_TABLE_SIZE_QUERY = `SELECT c.relname AS name, pg_size_pretty(pg_total_relation_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE NOT n.nspname LIKE ANY($1) -AND n.nspname !~ '^pg_toast' -AND c.relkind='r' +AND c.relkind = 'r' ORDER BY pg_total_relation_size(c.oid) DESC` const UNUSED_INDEXES_QUERY = `SELECT From e7aa6540c744bb24830744dba26a83c69bcfa7f8 Mon Sep 17 00:00:00 2001 From: Qiao Han Date: Sat, 13 Apr 2024 00:19:25 +0800 Subject: [PATCH 09/14] fix: update result types to match query --- internal/inspect/blocking/blocking.go | 6 +-- internal/inspect/index_usage/index_usage.go | 4 +- internal/inspect/locks/locks.go | 6 +-- .../long_running_queries.go | 4 +- internal/inspect/queries.go | 45 +++++++++---------- .../replication_slots/replication_slots.go | 4 +- internal/inspect/seq_scans/seq_scans.go | 4 +- .../table_record_counts.go | 4 +- .../inspect/unused_indexes/unused_indexes.go | 4 +- 9 files changed, 40 insertions(+), 41 deletions(-) diff --git a/internal/inspect/blocking/blocking.go b/internal/inspect/blocking/blocking.go index 717eec452..2367cf124 100644 --- a/internal/inspect/blocking/blocking.go +++ b/internal/inspect/blocking/blocking.go @@ -16,10 +16,10 @@ import ( ) type Result struct { - Blocked_pid string + Blocked_pid int Blocking_statement string Blocking_duration string - Blocking_pid string + Blocking_pid int Blocked_statement string Blocked_duration string } @@ -49,7 +49,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu re = regexp.MustCompile(`\|`) blocking_statement = re.ReplaceAllString(blocking_statement, `\|`) blocked_statement = re.ReplaceAllString(blocked_statement, `\|`) - table += fmt.Sprintf("|`%v`|`%v`|`%v`|`%v`|%s|`%v`|\n", r.Blocked_pid, blocking_statement, r.Blocking_duration, r.Blocking_pid, blocked_statement, r.Blocked_duration) + table += fmt.Sprintf("|`%d`|`%s`|`%s`|`%d`|%s|`%s`|\n", r.Blocked_pid, blocking_statement, r.Blocking_duration, r.Blocking_pid, blocked_statement, r.Blocked_duration) } return list.RenderTable(table) } diff --git a/internal/inspect/index_usage/index_usage.go b/internal/inspect/index_usage/index_usage.go index 25258e062..4b2eef55d 100644 --- a/internal/inspect/index_usage/index_usage.go +++ b/internal/inspect/index_usage/index_usage.go @@ -17,7 +17,7 @@ import ( type Result struct { Relname string Percent_of_times_index_used string - Rows_in_table string + Rows_in_table int64 } func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...func(*pgx.ConnConfig)) error { @@ -36,7 +36,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu // TODO: implement a markdown table marshaller table := "|Table name|Percentage of times index used|Rows in table|\n|-|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%v`|`%v`|\n", r.Relname, r.Percent_of_times_index_used, r.Rows_in_table) + table += fmt.Sprintf("|`%s`|`%s`|`%d`|\n", r.Relname, r.Percent_of_times_index_used, r.Rows_in_table) } return list.RenderTable(table) } diff --git a/internal/inspect/locks/locks.go b/internal/inspect/locks/locks.go index 5ab2fa06d..efeb82ae9 100644 --- a/internal/inspect/locks/locks.go +++ b/internal/inspect/locks/locks.go @@ -16,10 +16,10 @@ import ( ) type Result struct { - Pid string + Pid int Relname string Transactionid string - Granted string + Granted bool Query string Age string } @@ -47,7 +47,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu // escape pipes in query re = regexp.MustCompile(`\|`) query = re.ReplaceAllString(query, `\|`) - table += fmt.Sprintf("|`%v`|`%v`|`%v`|`%v`|%s|`%v`|\n", r.Pid, r.Relname, r.Transactionid, r.Granted, query, r.Age) + table += fmt.Sprintf("|`%d`|`%s`|`%s`|`%t`|%s|`%s`|\n", r.Pid, r.Relname, r.Transactionid, r.Granted, query, r.Age) } return list.RenderTable(table) } diff --git a/internal/inspect/long_running_queries/long_running_queries.go b/internal/inspect/long_running_queries/long_running_queries.go index fc1a56f90..e091515df 100644 --- a/internal/inspect/long_running_queries/long_running_queries.go +++ b/internal/inspect/long_running_queries/long_running_queries.go @@ -15,7 +15,7 @@ import ( ) type Result struct { - Pid string + Pid int Duration string Query string } @@ -36,7 +36,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu table := "|pid|Duration|Query|\n|-|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%s`|`%s`|\n", r.Pid, r.Duration, r.Query) + table += fmt.Sprintf("|`%d`|`%s`|`%s`|\n", r.Pid, r.Duration, r.Query) } return list.RenderTable(table) } diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index c0141c2a4..33261c9c5 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -63,14 +63,13 @@ WHERE NOT schemaname LIKE ANY($1) ORDER BY raw_waste DESC, bloat DESC` // Ref: https://github.com/heroku/heroku-pg-extras/blob/main/commands/blocking.js#L7 -const BLOCKING_QUERY = ` -SELECT - bl.pid AS blocked_pid, - ka.query AS blocking_statement, - now() - ka.query_start AS blocking_duration, - kl.pid AS blocking_pid, - a.query AS blocked_statement, - now() - a.query_start AS blocked_duration +const BLOCKING_QUERY = `SELECT + bl.pid AS blocked_pid, + ka.query AS blocking_statement, + age(now(), ka.query_start)::text AS blocking_duration, + kl.pid AS blocking_pid, + a.query AS blocked_statement, + age(now(), a.query_start)::text AS blocked_duration FROM pg_catalog.pg_locks bl JOIN pg_catalog.pg_stat_activity a ON bl.pid = a.pid @@ -92,12 +91,12 @@ sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS ratio FROM pg_statio_user_tables` const CALLS_QUERY = `SELECT - query, - interval '1 millisecond' * total_exec_time AS total_exec_time, - to_char((total_exec_time/sum(total_exec_time) OVER()) * 100, 'FM90D0') || '%' AS prop_exec_time, - to_char(calls, 'FM999G999G990') AS ncalls, - interval '1 millisecond' * (blk_read_time + blk_write_time) AS sync_io_time -FROM pg_stat_statements + query, + (interval '1 millisecond' * total_exec_time)::text AS total_exec_time, + to_char((total_exec_time/sum(total_exec_time) OVER()) * 100, 'FM90D0') || '%' AS prop_exec_time, + to_char(calls, 'FM999G999G990') AS ncalls, + (interval '1 millisecond' * (blk_read_time + blk_write_time))::text AS sync_io_time +FROM pg_stat_statements ORDER BY calls DESC LIMIT 10` @@ -105,7 +104,7 @@ const INDEX_SIZE_QUERY = `SELECT c.relname AS name, pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) -WHERE n.nspname NOT IN (%1) +WHERE NOT n.nspname LIKE ANY($1) AND c.relkind = 'i' GROUP BY c.relname ORDER BY sum(c.relpages) DESC` @@ -141,9 +140,9 @@ AND pg_locks.mode = 'ExclusiveLock' ORDER BY query_start` const LONG_RUNNING_QUERY = `SELECT -pid, -now() - pg_stat_activity.query_start AS duration, -query AS query + pid, + age(now(), pg_stat_activity.query_start)::text AS duration, + query AS query FROM pg_stat_activity WHERE @@ -154,11 +153,11 @@ ORDER BY now() - pg_stat_activity.query_start DESC` const OUTLIERS_QUERY = `SELECT -interval '1 millisecond' * total_exec_time AS total_exec_time, -to_char((total_exec_time/sum(total_exec_time) OVER()) * 100, 'FM90D0') || '%' AS prop_exec_time, -to_char(calls, 'FM999G999G999G990') AS ncalls, -interval '1 millisecond' * (blk_read_time + blk_write_time) AS sync_io_time, -query + (interval '1 millisecond' * total_exec_time)::text AS total_exec_time, + to_char((total_exec_time/sum(total_exec_time) OVER()) * 100, 'FM90D0') || '%' AS prop_exec_time, + to_char(calls, 'FM999G999G999G990') AS ncalls, + (interval '1 millisecond' * (blk_read_time + blk_write_time))::text AS sync_io_time, + query FROM pg_stat_statements WHERE userid = (SELECT usesysid FROM pg_user WHERE usename = current_user LIMIT 1) ORDER BY total_exec_time DESC LIMIT 10` diff --git a/internal/inspect/replication_slots/replication_slots.go b/internal/inspect/replication_slots/replication_slots.go index d86b12194..b66e7a0d3 100644 --- a/internal/inspect/replication_slots/replication_slots.go +++ b/internal/inspect/replication_slots/replication_slots.go @@ -16,7 +16,7 @@ import ( type Result struct { Slot_name string - Active string + Active bool State string Replication_client_address string Replication_lag_gb string @@ -38,7 +38,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu // TODO: implement a markdown table marshaller table := "|Name|Active|State|Replication Client Address|Replication Lag GB|\n|-|-|-|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%v`|`%v`|`%v`|`%v`|\n", r.Slot_name, r.Active, r.State, r.Replication_client_address, r.Replication_lag_gb) + table += fmt.Sprintf("|`%s`|`%t`|`%s`|`%s`|`%s`|\n", r.Slot_name, r.Active, r.State, r.Replication_client_address, r.Replication_lag_gb) } return list.RenderTable(table) } diff --git a/internal/inspect/seq_scans/seq_scans.go b/internal/inspect/seq_scans/seq_scans.go index 8d29a67ba..762c7acbb 100644 --- a/internal/inspect/seq_scans/seq_scans.go +++ b/internal/inspect/seq_scans/seq_scans.go @@ -16,7 +16,7 @@ import ( type Result struct { Name string - Count string + Count int64 } func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...func(*pgx.ConnConfig)) error { @@ -35,7 +35,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu table := "|Name|Count|\n|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%s`|\n", r.Name, r.Count) + table += fmt.Sprintf("|`%s`|`%d`|\n", r.Name, r.Count) } return list.RenderTable(table) } diff --git a/internal/inspect/table_record_counts/table_record_counts.go b/internal/inspect/table_record_counts/table_record_counts.go index c4ab62a2f..335f50983 100644 --- a/internal/inspect/table_record_counts/table_record_counts.go +++ b/internal/inspect/table_record_counts/table_record_counts.go @@ -16,7 +16,7 @@ import ( type Result struct { Name string - Estimated_count string + Estimated_count int64 } func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...func(*pgx.ConnConfig)) error { @@ -35,7 +35,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu table := "|Name|Estimated count|\n|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%s`|\n", r.Name, r.Estimated_count) + table += fmt.Sprintf("|`%s`|`%d`|\n", r.Name, r.Estimated_count) } return list.RenderTable(table) } diff --git a/internal/inspect/unused_indexes/unused_indexes.go b/internal/inspect/unused_indexes/unused_indexes.go index f47533459..ca0c4feff 100644 --- a/internal/inspect/unused_indexes/unused_indexes.go +++ b/internal/inspect/unused_indexes/unused_indexes.go @@ -19,7 +19,7 @@ type Result struct { Table string Index string Index_size string - Index_scans string + Index_scans int64 } func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...func(*pgx.ConnConfig)) error { @@ -38,7 +38,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu table := "|Table|Index|Index Size|Index Scans\n|-|-|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%s`|`%s`|`%s`|\n", r.Table, r.Index, r.Index_size, r.Index_scans) + table += fmt.Sprintf("|`%s`|`%s`|`%s`|`%d`|\n", r.Table, r.Index, r.Index_size, r.Index_scans) } return list.RenderTable(table) } From 446a8d66bcaafa8a907ed5e926c59b1eb6f6d5ea Mon Sep 17 00:00:00 2001 From: Qiao Han Date: Sat, 13 Apr 2024 00:23:09 +0800 Subject: [PATCH 10/14] fix: ignore managed schemas when reporting seq and idx scans --- internal/inspect/index_usage/index_usage.go | 3 +- internal/inspect/queries.go | 40 +++++++++++---------- internal/inspect/seq_scans/seq_scans.go | 3 +- 3 files changed, 25 insertions(+), 21 deletions(-) diff --git a/internal/inspect/index_usage/index_usage.go b/internal/inspect/index_usage/index_usage.go index 4b2eef55d..ed0145d5b 100644 --- a/internal/inspect/index_usage/index_usage.go +++ b/internal/inspect/index_usage/index_usage.go @@ -8,6 +8,7 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" @@ -25,7 +26,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.INDEX_USAGE_QUERY) + rows, err := conn.Query(ctx, inspect.INDEX_USAGE_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index 33261c9c5..bf44047ee 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -109,22 +109,23 @@ AND c.relkind = 'i' GROUP BY c.relname ORDER BY sum(c.relpages) DESC` -const INDEX_USAGE_QUERY = `SELECT relname, -CASE - WHEN idx_scan IS NULL THEN 'Insufficient data' - WHEN idx_scan = 0 THEN 'Insufficient data' - ELSE (100 * idx_scan / (seq_scan + idx_scan))::text -END percent_of_times_index_used, -n_live_tup rows_in_table -FROM -pg_stat_user_tables +const INDEX_USAGE_QUERY = `SELECT + relname, + CASE + WHEN idx_scan IS NULL THEN 'Insufficient data' + WHEN idx_scan = 0 THEN 'Insufficient data' + ELSE ROUND(100.0 * idx_scan / (seq_scan + idx_scan), 1) || '%' + END percent_of_times_index_used, + n_live_tup rows_in_table +FROM pg_stat_user_tables +WHERE NOT schemaname LIKE ANY($1) ORDER BY -CASE - WHEN idx_scan is null then 1 - WHEN idx_scan = 0 then 1 - ELSE 0 -END, -n_live_tup DESC` + CASE + WHEN idx_scan is null then 1 + WHEN idx_scan = 0 then 1 + ELSE 0 + END, + n_live_tup DESC` const LOCKS_QUERY = `SELECT pg_stat_activity.pid, @@ -191,10 +192,11 @@ FROM pg_roles ORDER BY 2 DESC` -const SEQ_SCANS_QUERY = `SELECT relname AS name, -seq_scan as count -FROM -pg_stat_user_tables +const SEQ_SCANS_QUERY = `SELECT + relname AS name, + seq_scan as count +FROM pg_stat_user_tables +WHERE NOT schemaname LIKE ANY($1) ORDER BY seq_scan DESC` const TABLE_INDEX_SIZE_QUERY = `SELECT c.relname AS table, diff --git a/internal/inspect/seq_scans/seq_scans.go b/internal/inspect/seq_scans/seq_scans.go index 762c7acbb..3cb4cf553 100644 --- a/internal/inspect/seq_scans/seq_scans.go +++ b/internal/inspect/seq_scans/seq_scans.go @@ -8,6 +8,7 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" @@ -24,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.SEQ_SCANS_QUERY) + rows, err := conn.Query(ctx, inspect.SEQ_SCANS_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } From 163712475b3a033c43539903a7cf8fc814483438 Mon Sep 17 00:00:00 2001 From: Qiao Han Date: Sat, 13 Apr 2024 00:23:32 +0800 Subject: [PATCH 11/14] chore: consistent indentation for sql queries --- internal/inspect/index_sizes/index_sizes.go | 2 +- internal/inspect/queries.go | 134 ++++++++++-------- .../table_index_sizes/table_index_sizes.go | 2 +- internal/inspect/table_sizes/table_sizes.go | 2 +- .../total_table_sizes/total_table_sizes.go | 2 +- 5 files changed, 75 insertions(+), 67 deletions(-) diff --git a/internal/inspect/index_sizes/index_sizes.go b/internal/inspect/index_sizes/index_sizes.go index 46e50f5c5..37e6f273f 100644 --- a/internal/inspect/index_sizes/index_sizes.go +++ b/internal/inspect/index_sizes/index_sizes.go @@ -25,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.INDEX_SIZE_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) + rows, err := conn.Query(ctx, inspect.INDEX_SIZES_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index bf44047ee..f49810e40 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -72,23 +72,23 @@ const BLOCKING_QUERY = `SELECT age(now(), a.query_start)::text AS blocked_duration FROM pg_catalog.pg_locks bl JOIN pg_catalog.pg_stat_activity a - ON bl.pid = a.pid + ON bl.pid = a.pid JOIN pg_catalog.pg_locks kl JOIN pg_catalog.pg_stat_activity ka - ON kl.pid = ka.pid - ON bl.transactionid = kl.transactionid AND bl.pid != kl.pid + ON kl.pid = ka.pid + ON bl.transactionid = kl.transactionid AND bl.pid != kl.pid WHERE NOT bl.granted` // Ref: https://github.com/heroku/heroku-pg-extras/blob/main/commands/cache_hit.js#L7 const CACHE_QUERY = `SELECT -'index hit rate' AS name, -(sum(idx_blks_hit)) / nullif(sum(idx_blks_hit + idx_blks_read),0) AS ratio + 'index hit rate' AS name, + (sum(idx_blks_hit)) / nullif(sum(idx_blks_hit + idx_blks_read),0) AS ratio FROM pg_statio_user_indexes UNION ALL SELECT -'table hit rate' AS name, -sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS ratio -FROM pg_statio_user_tables` + 'table hit rate' AS name, + sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS ratio +FROM pg_statio_user_tables;` const CALLS_QUERY = `SELECT query, @@ -100,8 +100,9 @@ FROM pg_stat_statements ORDER BY calls DESC LIMIT 10` -const INDEX_SIZE_QUERY = `SELECT c.relname AS name, -pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size +const INDEX_SIZES_QUERY = `SELECT + c.relname AS name, + pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE NOT n.nspname LIKE ANY($1) @@ -128,15 +129,15 @@ ORDER BY n_live_tup DESC` const LOCKS_QUERY = `SELECT -pg_stat_activity.pid, -COALESCE(pg_class.relname, 'null') AS relname, -COALESCE(pg_locks.transactionid, 'null') AS transactionid, -pg_locks.granted, -pg_stat_activity.query, -age(now(),pg_stat_activity.query_start) AS age + pg_stat_activity.pid, + COALESCE(pg_class.relname, 'null') AS relname, + COALESCE(pg_locks.transactionid, 'null') AS transactionid, + pg_locks.granted, + pg_stat_activity.query, + age(now(), pg_stat_activity.query_start)::text AS age FROM pg_stat_activity, pg_locks LEFT OUTER JOIN pg_class ON (pg_locks.relation = pg_class.oid) WHERE pg_stat_activity.query <> '' -AND pg_locks.pid=pg_stat_activity.pid +AND pg_locks.pid = pg_stat_activity.pid AND pg_locks.mode = 'ExclusiveLock' ORDER BY query_start` @@ -145,13 +146,13 @@ const LONG_RUNNING_QUERY = `SELECT age(now(), pg_stat_activity.query_start)::text AS duration, query AS query FROM -pg_stat_activity + pg_stat_activity WHERE -pg_stat_activity.query <> ''::text -AND state <> 'idle' -AND now() - pg_stat_activity.query_start > interval '5 minutes' + pg_stat_activity.query <> ''::text + AND state <> 'idle' + AND age(now(), pg_stat_activity.query_start) > interval '5 minutes' ORDER BY -now() - pg_stat_activity.query_start DESC` + age(now(), pg_stat_activity.query_start) DESC` const OUTLIERS_QUERY = `SELECT (interval '1 millisecond' * total_exec_time)::text AS total_exec_time, @@ -164,32 +165,32 @@ ORDER BY total_exec_time DESC LIMIT 10` const REPLICATION_SLOTS_QUERY = `SELECT -s.slot_name, -s.active, -COALESCE(r.state, 'N/A') as state, -CASE WHEN r.client_addr IS NULL - THEN 'N/A' - ELSE r.client_addr::text -END replication_client_address, -GREATEST(0, ROUND((redo_lsn-restart_lsn)/1024/1024/1024, 2)) as replication_lag_gb + s.slot_name, + s.active, + COALESCE(r.state, 'N/A') as state, + CASE WHEN r.client_addr IS NULL + THEN 'N/A' + ELSE r.client_addr::text + END replication_client_address, + GREATEST(0, ROUND((redo_lsn-restart_lsn)/1024/1024/1024, 2)) as replication_lag_gb FROM pg_control_checkpoint(), pg_replication_slots s LEFT JOIN pg_stat_replication r ON (r.pid = s.active_pid)` const ROLE_CONNECTIONS_QUERY = `SELECT -rolname, -( - SELECT - count(*) - FROM - pg_stat_activity - WHERE - pg_roles.rolname = pg_stat_activity.usename -) AS active_connections, -CASE WHEN rolconnlimit = -1 THEN current_setting('max_connections') :: int8 - ELSE rolconnlimit -END AS connection_limit -FROM -pg_roles + rolname, + ( + SELECT + count(*) + FROM + pg_stat_activity + WHERE + pg_roles.rolname = pg_stat_activity.usename + ) AS active_connections, + CASE WHEN rolconnlimit = -1 + THEN current_setting('max_connections')::int8 + ELSE rolconnlimit + END AS connection_limit +FROM pg_roles ORDER BY 2 DESC` const SEQ_SCANS_QUERY = `SELECT @@ -199,8 +200,9 @@ FROM pg_stat_user_tables WHERE NOT schemaname LIKE ANY($1) ORDER BY seq_scan DESC` -const TABLE_INDEX_SIZE_QUERY = `SELECT c.relname AS table, -pg_size_pretty(pg_indexes_size(c.oid)) AS index_size +const TABLE_INDEX_SIZES_QUERY = `SELECT + c.relname AS table, + pg_size_pretty(pg_indexes_size(c.oid)) AS index_size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE NOT n.nspname LIKE ANY($1) @@ -208,29 +210,32 @@ AND c.relkind = 'r' ORDER BY pg_indexes_size(c.oid) DESC` const TABLE_RECORD_COUNTS_QUERY = `SELECT -relname AS name, -n_live_tup AS estimated_count + relname AS name, + n_live_tup AS estimated_count FROM -pg_stat_user_tables + pg_stat_user_tables ORDER BY -n_live_tup DESC` + n_live_tup DESC` -const TABLE_SIZE_QUERY = `SELECT c.relname AS name, -pg_size_pretty(pg_table_size(c.oid)) AS size +const TABLE_SIZES_QUERY = `SELECT + c.relname AS name, + pg_size_pretty(pg_table_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE NOT n.nspname LIKE ANY($1) AND c.relkind = 'r' ORDER BY pg_table_size(c.oid) DESC` -const TOTAL_INDEX_SIZE_QUERY = `SELECT pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size +const TOTAL_INDEX_SIZE_QUERY = `SELECT + pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE NOT n.nspname LIKE ANY($1) AND c.relkind = 'i'` -const TOTAL_TABLE_SIZE_QUERY = `SELECT c.relname AS name, -pg_size_pretty(pg_total_relation_size(c.oid)) AS size +const TOTAL_TABLE_SIZES_QUERY = `SELECT + c.relname AS name, + pg_size_pretty(pg_total_relation_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE NOT n.nspname LIKE ANY($1) @@ -238,21 +243,24 @@ AND c.relkind = 'r' ORDER BY pg_total_relation_size(c.oid) DESC` const UNUSED_INDEXES_QUERY = `SELECT -schemaname || '.' || relname AS table, -indexrelname AS index, -pg_size_pretty(pg_relation_size(i.indexrelid)) AS index_size, -idx_scan as index_scans + schemaname || '.' || relname AS table, + indexrelname AS index, + pg_size_pretty(pg_relation_size(i.indexrelid)) AS index_size, + idx_scan as index_scans FROM pg_stat_user_indexes ui JOIN pg_index i ON ui.indexrelid = i.indexrelid -WHERE NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 AND NOT schemaname LIKE ANY($1) -ORDER BY pg_relation_size(i.indexrelid) / nullif(idx_scan, 0) DESC NULLS FIRST, -pg_relation_size(i.indexrelid) DESC` +WHERE + NOT indisunique AND idx_scan < 50 AND pg_relation_size(relid) > 5 * 8192 + AND NOT schemaname LIKE ANY($1) +ORDER BY + pg_relation_size(i.indexrelid) / nullif(idx_scan, 0) DESC NULLS FIRST, + pg_relation_size(i.indexrelid) DESC` const VACUUM_STATS_QUERY = `WITH table_opts AS ( SELECT pg_class.oid, relname, nspname, array_to_string(reloptions, '') AS relopts FROM - pg_class INNER JOIN pg_namespace ns ON relnamespace = ns.oid + pg_class INNER JOIN pg_namespace ns ON relnamespace = ns.oid ), vacuum_settings AS ( SELECT oid, relname, nspname, diff --git a/internal/inspect/table_index_sizes/table_index_sizes.go b/internal/inspect/table_index_sizes/table_index_sizes.go index 9d906ffee..905ad3b5a 100644 --- a/internal/inspect/table_index_sizes/table_index_sizes.go +++ b/internal/inspect/table_index_sizes/table_index_sizes.go @@ -25,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TABLE_INDEX_SIZE_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) + rows, err := conn.Query(ctx, inspect.TABLE_INDEX_SIZES_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/table_sizes/table_sizes.go b/internal/inspect/table_sizes/table_sizes.go index fdaa42159..6aa1723f2 100644 --- a/internal/inspect/table_sizes/table_sizes.go +++ b/internal/inspect/table_sizes/table_sizes.go @@ -25,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TABLE_SIZE_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) + rows, err := conn.Query(ctx, inspect.TABLE_SIZES_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/total_table_sizes/total_table_sizes.go b/internal/inspect/total_table_sizes/total_table_sizes.go index 3e9754555..71908116a 100644 --- a/internal/inspect/total_table_sizes/total_table_sizes.go +++ b/internal/inspect/total_table_sizes/total_table_sizes.go @@ -25,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TOTAL_TABLE_SIZE_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) + rows, err := conn.Query(ctx, inspect.TOTAL_TABLE_SIZES_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } From 8d83ff304166a82001854f3bfa9fa1021cdf4968 Mon Sep 17 00:00:00 2001 From: Qiao Han Date: Sat, 13 Apr 2024 00:44:26 +0800 Subject: [PATCH 12/14] fix: always append schema name to table name --- internal/inspect/index_usage/index_usage.go | 4 ++-- internal/inspect/queries.go | 14 +++++++------- 2 files changed, 9 insertions(+), 9 deletions(-) diff --git a/internal/inspect/index_usage/index_usage.go b/internal/inspect/index_usage/index_usage.go index ed0145d5b..c34d7deb9 100644 --- a/internal/inspect/index_usage/index_usage.go +++ b/internal/inspect/index_usage/index_usage.go @@ -16,7 +16,7 @@ import ( ) type Result struct { - Relname string + Name string Percent_of_times_index_used string Rows_in_table int64 } @@ -37,7 +37,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu // TODO: implement a markdown table marshaller table := "|Table name|Percentage of times index used|Rows in table|\n|-|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%s`|`%d`|\n", r.Relname, r.Percent_of_times_index_used, r.Rows_in_table) + table += fmt.Sprintf("|`%s`|`%s`|`%d`|\n", r.Name, r.Percent_of_times_index_used, r.Rows_in_table) } return list.RenderTable(table) } diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index f49810e40..25af8d0bf 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -101,7 +101,7 @@ ORDER BY calls DESC LIMIT 10` const INDEX_SIZES_QUERY = `SELECT - c.relname AS name, + n.nspname || '.' || c.relname AS name, pg_size_pretty(sum(c.relpages::bigint*8192)::bigint) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) @@ -111,7 +111,7 @@ GROUP BY c.relname ORDER BY sum(c.relpages) DESC` const INDEX_USAGE_QUERY = `SELECT - relname, + schemaname || '.' || relname AS name, CASE WHEN idx_scan IS NULL THEN 'Insufficient data' WHEN idx_scan = 0 THEN 'Insufficient data' @@ -194,14 +194,14 @@ FROM pg_roles ORDER BY 2 DESC` const SEQ_SCANS_QUERY = `SELECT - relname AS name, + schemaname || '.' || relname AS name, seq_scan as count FROM pg_stat_user_tables WHERE NOT schemaname LIKE ANY($1) ORDER BY seq_scan DESC` const TABLE_INDEX_SIZES_QUERY = `SELECT - c.relname AS table, + n.nspname || '.' || c.relname AS table, pg_size_pretty(pg_indexes_size(c.oid)) AS index_size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) @@ -210,7 +210,7 @@ AND c.relkind = 'r' ORDER BY pg_indexes_size(c.oid) DESC` const TABLE_RECORD_COUNTS_QUERY = `SELECT - relname AS name, + schemaname || '.' || relname AS name, n_live_tup AS estimated_count FROM pg_stat_user_tables @@ -218,7 +218,7 @@ ORDER BY n_live_tup DESC` const TABLE_SIZES_QUERY = `SELECT - c.relname AS name, + n.nspname || '.' || c.relname AS name, pg_size_pretty(pg_table_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) @@ -234,7 +234,7 @@ WHERE NOT n.nspname LIKE ANY($1) AND c.relkind = 'i'` const TOTAL_TABLE_SIZES_QUERY = `SELECT - c.relname AS name, + n.nspname || '.' || c.relname AS name, pg_size_pretty(pg_total_relation_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) From a6214be12e07c1264d8a3e81fc4c3dcc75b4fbf6 Mon Sep 17 00:00:00 2001 From: Qiao Han Date: Sat, 13 Apr 2024 00:48:22 +0800 Subject: [PATCH 13/14] fix: only exclude pg schemas when reporting table sizes --- internal/db/diff/diff_test.go | 4 ++-- internal/db/pull/pull_test.go | 4 ++-- internal/db/reset/reset_test.go | 4 ++-- internal/inspect/queries.go | 7 +++---- .../inspect/table_record_counts/table_record_counts.go | 3 ++- internal/inspect/table_sizes/table_sizes.go | 2 +- internal/inspect/total_table_sizes/total_table_sizes.go | 2 +- internal/utils/misc.go | 6 ++++-- 8 files changed, 17 insertions(+), 15 deletions(-) diff --git a/internal/db/diff/diff_test.go b/internal/db/diff/diff_test.go index 00d019d4e..5d714315d 100644 --- a/internal/db/diff/diff_test.go +++ b/internal/db/diff/diff_test.go @@ -43,8 +43,6 @@ var escapedSchemas = []string{ `\_analytics`, `supabase\_functions`, `supabase\_migrations`, - `information\_schema`, - `pg\_%`, "cron", "graphql", `graphql\_public`, @@ -59,6 +57,8 @@ var escapedSchemas = []string{ `\_timescaledb\_%`, "topology", "vault", + `information\_schema`, + `pg\_%`, } func TestRun(t *testing.T) { diff --git a/internal/db/pull/pull_test.go b/internal/db/pull/pull_test.go index 62c49ff91..fba4fa1a1 100644 --- a/internal/db/pull/pull_test.go +++ b/internal/db/pull/pull_test.go @@ -39,8 +39,6 @@ var escapedSchemas = []string{ `\_analytics`, `supabase\_functions`, `supabase\_migrations`, - `information\_schema`, - `pg\_%`, "cron", "graphql", `graphql\_public`, @@ -55,6 +53,8 @@ var escapedSchemas = []string{ `\_timescaledb\_%`, "topology", "vault", + `information\_schema`, + `pg\_%`, } func TestPullCommand(t *testing.T) { diff --git a/internal/db/reset/reset_test.go b/internal/db/reset/reset_test.go index 3b91a344b..cbeecb938 100644 --- a/internal/db/reset/reset_test.go +++ b/internal/db/reset/reset_test.go @@ -302,8 +302,6 @@ var escapedSchemas = []string{ "storage", `\_analytics`, `supabase\_functions`, - `information\_schema`, - `pg\_%`, "cron", "graphql", `graphql\_public`, @@ -318,6 +316,8 @@ var escapedSchemas = []string{ `\_timescaledb\_%`, "topology", "vault", + `information\_schema`, + `pg\_%`, } func TestResetRemote(t *testing.T) { diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index 25af8d0bf..9742b53da 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -212,10 +212,9 @@ ORDER BY pg_indexes_size(c.oid) DESC` const TABLE_RECORD_COUNTS_QUERY = `SELECT schemaname || '.' || relname AS name, n_live_tup AS estimated_count -FROM - pg_stat_user_tables -ORDER BY - n_live_tup DESC` +FROM pg_stat_user_tables +WHERE NOT schemaname LIKE ANY($1) +ORDER BY n_live_tup DESC` const TABLE_SIZES_QUERY = `SELECT n.nspname || '.' || c.relname AS name, diff --git a/internal/inspect/table_record_counts/table_record_counts.go b/internal/inspect/table_record_counts/table_record_counts.go index 335f50983..2f1f3648f 100644 --- a/internal/inspect/table_record_counts/table_record_counts.go +++ b/internal/inspect/table_record_counts/table_record_counts.go @@ -8,6 +8,7 @@ import ( "github.com/jackc/pgconn" "github.com/jackc/pgx/v4" "github.com/spf13/afero" + "github.com/supabase/cli/internal/db/reset" "github.com/supabase/cli/internal/inspect" "github.com/supabase/cli/internal/migration/list" "github.com/supabase/cli/internal/utils" @@ -24,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TABLE_RECORD_COUNTS_QUERY) + rows, err := conn.Query(ctx, inspect.TABLE_RECORD_COUNTS_QUERY, reset.LikeEscapeSchema(utils.PgSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/table_sizes/table_sizes.go b/internal/inspect/table_sizes/table_sizes.go index 6aa1723f2..7ce8b8667 100644 --- a/internal/inspect/table_sizes/table_sizes.go +++ b/internal/inspect/table_sizes/table_sizes.go @@ -25,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TABLE_SIZES_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) + rows, err := conn.Query(ctx, inspect.TABLE_SIZES_QUERY, reset.LikeEscapeSchema(utils.PgSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/inspect/total_table_sizes/total_table_sizes.go b/internal/inspect/total_table_sizes/total_table_sizes.go index 71908116a..a9bc4d24d 100644 --- a/internal/inspect/total_table_sizes/total_table_sizes.go +++ b/internal/inspect/total_table_sizes/total_table_sizes.go @@ -25,7 +25,7 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu if err != nil { return err } - rows, err := conn.Query(ctx, inspect.TOTAL_TABLE_SIZES_QUERY, reset.LikeEscapeSchema(utils.InternalSchemas)) + rows, err := conn.Query(ctx, inspect.TOTAL_TABLE_SIZES_QUERY, reset.LikeEscapeSchema(utils.PgSchemas)) if err != nil { return errors.Errorf("failed to query rows: %w", err) } diff --git a/internal/utils/misc.go b/internal/utils/misc.go index 58a13dfde..ab0693f24 100644 --- a/internal/utils/misc.go +++ b/internal/utils/misc.go @@ -107,9 +107,11 @@ var ( ImageNamePattern = regexp.MustCompile(`\/(.*):`) // These schemas are ignored from db diff and db dump - SystemSchemas = []string{ + PgSchemas = []string{ "information_schema", "pg_*", // Wildcard pattern follows pg_dump + } + SystemSchemas = append([]string{ // Owned by extensions "cron", "graphql", @@ -125,7 +127,7 @@ var ( "_timescaledb_*", "topology", "vault", - } + }, PgSchemas...) InternalSchemas = append([]string{ "auth", "extensions", From 8f06c609cd16b6b9628f0cb2b58c68e3d6758d2e Mon Sep 17 00:00:00 2001 From: Qiao Han Date: Sat, 13 Apr 2024 01:19:49 +0800 Subject: [PATCH 14/14] fix: add schema column to table sizes query --- internal/inspect/queries.go | 11 +++++++---- .../table_record_counts/table_record_counts.go | 5 +++-- internal/inspect/table_sizes/table_sizes.go | 9 +++++---- .../inspect/total_table_sizes/total_table_sizes.go | 9 +++++---- 4 files changed, 20 insertions(+), 14 deletions(-) diff --git a/internal/inspect/queries.go b/internal/inspect/queries.go index 9742b53da..42139729d 100644 --- a/internal/inspect/queries.go +++ b/internal/inspect/queries.go @@ -107,7 +107,7 @@ FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) WHERE NOT n.nspname LIKE ANY($1) AND c.relkind = 'i' -GROUP BY c.relname +GROUP BY n.nspname, c.relname ORDER BY sum(c.relpages) DESC` const INDEX_USAGE_QUERY = `SELECT @@ -210,14 +210,16 @@ AND c.relkind = 'r' ORDER BY pg_indexes_size(c.oid) DESC` const TABLE_RECORD_COUNTS_QUERY = `SELECT - schemaname || '.' || relname AS name, + schemaname AS schema, + relname AS name, n_live_tup AS estimated_count FROM pg_stat_user_tables WHERE NOT schemaname LIKE ANY($1) ORDER BY n_live_tup DESC` const TABLE_SIZES_QUERY = `SELECT - n.nspname || '.' || c.relname AS name, + n.nspname AS schema, + c.relname AS name, pg_size_pretty(pg_table_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) @@ -233,7 +235,8 @@ WHERE NOT n.nspname LIKE ANY($1) AND c.relkind = 'i'` const TOTAL_TABLE_SIZES_QUERY = `SELECT - n.nspname || '.' || c.relname AS name, + n.nspname AS schema, + c.relname AS name, pg_size_pretty(pg_total_relation_size(c.oid)) AS size FROM pg_class c LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) diff --git a/internal/inspect/table_record_counts/table_record_counts.go b/internal/inspect/table_record_counts/table_record_counts.go index 2f1f3648f..72ca70de4 100644 --- a/internal/inspect/table_record_counts/table_record_counts.go +++ b/internal/inspect/table_record_counts/table_record_counts.go @@ -16,6 +16,7 @@ import ( ) type Result struct { + Schema string Name string Estimated_count int64 } @@ -34,9 +35,9 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu return err } - table := "|Name|Estimated count|\n|-|-|\n" + table := "Schema|Table|Estimated count|\n|-|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%d`|\n", r.Name, r.Estimated_count) + table += fmt.Sprintf("|`%s`|`%s`|`%d`|\n", r.Schema, r.Name, r.Estimated_count) } return list.RenderTable(table) } diff --git a/internal/inspect/table_sizes/table_sizes.go b/internal/inspect/table_sizes/table_sizes.go index 7ce8b8667..74c0396d3 100644 --- a/internal/inspect/table_sizes/table_sizes.go +++ b/internal/inspect/table_sizes/table_sizes.go @@ -16,8 +16,9 @@ import ( ) type Result struct { - Name string - Size string + Schema string + Name string + Size string } func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...func(*pgx.ConnConfig)) error { @@ -34,9 +35,9 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu return err } - table := "|Name|size|\n|-|-|\n" + table := "Schema|Table|size|\n|-|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%s`|\n", r.Name, r.Size) + table += fmt.Sprintf("|`%s`|`%s`|`%s`|\n", r.Schema, r.Name, r.Size) } return list.RenderTable(table) } diff --git a/internal/inspect/total_table_sizes/total_table_sizes.go b/internal/inspect/total_table_sizes/total_table_sizes.go index a9bc4d24d..8fd441952 100644 --- a/internal/inspect/total_table_sizes/total_table_sizes.go +++ b/internal/inspect/total_table_sizes/total_table_sizes.go @@ -16,8 +16,9 @@ import ( ) type Result struct { - Name string - Size string + Schema string + Name string + Size string } func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...func(*pgx.ConnConfig)) error { @@ -34,9 +35,9 @@ func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...fu return err } - table := "|Name|Size|\n|-|-|\n" + table := "Schema|Table|Size|\n|-|-|-|\n" for _, r := range result { - table += fmt.Sprintf("|`%s`|`%s`|\n", r.Name, r.Size) + table += fmt.Sprintf("|`%s`|`%s`|`%s`|\n", r.Schema, r.Name, r.Size) } return list.RenderTable(table) }