diff --git a/cmd/inspect.go b/cmd/inspect.go index 24c3ff465..2405e8d78 100644 --- a/cmd/inspect.go +++ b/cmd/inspect.go @@ -18,6 +18,7 @@ import ( "github.com/supabase/cli/internal/inspect/replication_slots" "github.com/supabase/cli/internal/inspect/role_stats" "github.com/supabase/cli/internal/inspect/table_stats" + "github.com/supabase/cli/internal/inspect/traffic_profile" "github.com/supabase/cli/internal/inspect/vacuum_stats" "github.com/supabase/cli/internal/utils/flags" ) @@ -135,6 +136,14 @@ var ( }, } + inspectTrafficProfileCmd = &cobra.Command{ + Use: "traffic-profile", + Short: "Show read/write activity ratio for tables based on block I/O operations", + RunE: func(cmd *cobra.Command, args []string) error { + return traffic_profile.Run(cmd.Context(), flags.DbConfig, afero.NewOsFs()) + }, + } + inspectCacheHitCmd = &cobra.Command{ Deprecated: `use "db-stats" instead.`, Use: "cache-hit", @@ -270,6 +279,7 @@ func init() { inspectDBCmd.AddCommand(inspectBloatCmd) inspectDBCmd.AddCommand(inspectVacuumStatsCmd) inspectDBCmd.AddCommand(inspectTableStatsCmd) + inspectDBCmd.AddCommand(inspectTrafficProfileCmd) inspectDBCmd.AddCommand(inspectRoleStatsCmd) inspectDBCmd.AddCommand(inspectDBStatsCmd) // DEPRECATED diff --git a/docs/supabase/inspect/db-traffic-profile.md b/docs/supabase/inspect/db-traffic-profile.md new file mode 100644 index 000000000..161706f75 --- /dev/null +++ b/docs/supabase/inspect/db-traffic-profile.md @@ -0,0 +1,24 @@ +# db-traffic-profile + +This command analyzes table I/O patterns to show read/write activity ratios based on block-level operations. It combines data from PostgreSQL's `pg_stat_user_tables` (for tuple operations) and `pg_statio_user_tables` (for block I/O) to categorize each table's workload profile. + + +The command classifies tables into categories: +- **Read-Heavy** - Read operations are more than 5x write operations (e.g., 1:10, 1:50) +- **Write-Heavy** - Write operations are more than 20% of read operations (e.g., 1:2, 1:4, 2:1, 10:1) +- **Balanced** - Mixed workload where writes are between 20% and 500% of reads +- **Read-Only** - Only read operations detected +- **Write-Only** - Only write operations detected + +``` +SCHEMA │ TABLE │ BLOCKS READ │ WRITE TUPLES │ BLOCKS WRITE │ ACTIVITY RATIO +───────┼──────────────┼─────────────┼──────────────┼──────────────┼──────────────────── +public │ user_events │ 450,234 │ 9,004,680│ 23,450 │ 20:1 (Write-Heavy) +public │ users │ 89,203 │ 12,451│ 1,203 │ 7.2:1 (Read-Heavy) +public │ sessions │ 15,402 │ 14,823│ 2,341 │ ≈1:1 (Balanced) +public │ cache_data │ 123,456 │ 0│ 0 │ Read-Only +auth │ audit_logs │ 0 │ 98,234│ 12,341 │ Write-Only +``` + +**Note:** This command only displays tables that have had both read and write activity. Tables with no I/O operations are not shown. The classification ratio threshold (default: 5:1) determines when a table is considered "heavy" in one direction versus balanced. + diff --git a/internal/inspect/traffic_profile/traffic_profile.go b/internal/inspect/traffic_profile/traffic_profile.go new file mode 100644 index 000000000..fb58ec3e1 --- /dev/null +++ b/internal/inspect/traffic_profile/traffic_profile.go @@ -0,0 +1,49 @@ +package traffic_profile + +import ( + "context" + _ "embed" + "fmt" + + "github.com/go-errors/errors" + "github.com/jackc/pgconn" + "github.com/jackc/pgx/v4" + "github.com/spf13/afero" + "github.com/supabase/cli/internal/utils" + "github.com/supabase/cli/pkg/pgxv5" +) + +//go:embed traffic_profile.sql +var TrafficProfileQuery string + +type Result struct { + Schemaname string + Table_name string + Blocks_read int64 + Write_tuples int64 + Blocks_write float64 + Activity_ratio string +} + +func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...func(*pgx.ConnConfig)) error { + conn, err := utils.ConnectByConfig(ctx, config, options...) + if err != nil { + return err + } + defer conn.Close(context.Background()) + rows, err := conn.Query(ctx, TrafficProfileQuery) + if err != nil { + return errors.Errorf("failed to query rows: %w", err) + } + result, err := pgxv5.CollectRows[Result](rows) + if err != nil { + return err + } + + table := "|Schema|Table|Blocks Read|Write Tuples|Blocks Write|Activity Ratio|\n|-|-|-|-|-|-|\n" + for _, r := range result { + table += fmt.Sprintf("|`%s`|`%s`|`%d`|`%d`|`%.1f`|`%s`|\n", + r.Schemaname, r.Table_name, r.Blocks_read, r.Write_tuples, r.Blocks_write, r.Activity_ratio) + } + return utils.RenderTable(table) +} diff --git a/internal/inspect/traffic_profile/traffic_profile.sql b/internal/inspect/traffic_profile/traffic_profile.sql new file mode 100644 index 000000000..b56298ac0 --- /dev/null +++ b/internal/inspect/traffic_profile/traffic_profile.sql @@ -0,0 +1,45 @@ + -- Query adapted from Crunchy Data blog: "Is Postgres Read Heavy or Write Heavy? (And Why You Should Care)" by David Christensen +WITH +ratio_target AS (SELECT 5 AS ratio), +table_list AS (SELECT + s.schemaname, + s.relname AS table_name, + si.heap_blks_read + si.idx_blks_read AS blocks_read, +s.n_tup_ins + s.n_tup_upd + s.n_tup_del AS write_tuples, +relpages * (s.n_tup_ins + s.n_tup_upd + s.n_tup_del ) / (case when reltuples = 0 then 1 else reltuples end) as blocks_write +FROM + pg_stat_user_tables AS s +JOIN pg_statio_user_tables AS si ON s.relid = si.relid +JOIN pg_class c ON c.oid = s.relid +WHERE +(s.n_tup_ins + s.n_tup_upd + s.n_tup_del) > 0 +AND + (si.heap_blks_read + si.idx_blks_read) > 0 + ) +SELECT + schemaname, + table_name, + blocks_read, + write_tuples, + blocks_write, + CASE + WHEN blocks_read = 0 and blocks_write = 0 THEN + 'No Activity' + WHEN blocks_write * ratio > blocks_read THEN + CASE + WHEN blocks_read = 0 THEN 'Write-Only' + ELSE + ROUND(blocks_write :: numeric / blocks_read :: numeric, 1)::text || ':1 (Write-Heavy)' + END + WHEN blocks_read > blocks_write * ratio THEN + CASE + WHEN blocks_write = 0 THEN 'Read-Only' + ELSE + '1:' || ROUND(blocks_read::numeric / blocks_write :: numeric, 1)::text || ' (Read-Heavy)' + END + ELSE + '1:1 (Balanced)' + END AS activity_ratio +FROM table_list, ratio_target +ORDER BY + (blocks_read + blocks_write) DESC diff --git a/internal/inspect/traffic_profile/traffic_profile_test.go b/internal/inspect/traffic_profile/traffic_profile_test.go new file mode 100644 index 000000000..870076c68 --- /dev/null +++ b/internal/inspect/traffic_profile/traffic_profile_test.go @@ -0,0 +1,42 @@ +package traffic_profile + +import ( + "context" + "testing" + + "github.com/jackc/pgconn" + "github.com/spf13/afero" + "github.com/stretchr/testify/assert" + "github.com/supabase/cli/pkg/pgtest" +) + +var dbConfig = pgconn.Config{ + Host: "127.0.0.1", + Port: 5432, + User: "admin", + Password: "password", + Database: "postgres", +} + +func TestTrafficProfile(t *testing.T) { + t.Run("inspects traffic profile", func(t *testing.T) { + // Setup in-memory fs + fsys := afero.NewMemMapFs() + // Setup mock postgres + conn := pgtest.NewConn() + defer conn.Close(t) + conn.Query(TrafficProfileQuery). + Reply("SELECT 6", Result{ + Schemaname: "public", + Table_name: "users", + Blocks_read: 1000, + Write_tuples: 500, + Blocks_write: 250.5, + Activity_ratio: "1:4.0 (Read-Heavy)", + }) + // Run test + err := Run(context.Background(), dbConfig, fsys, conn.Intercept) + // Check error + assert.NoError(t, err) + }) +}