Skip to content

Commit 1240cbc

Browse files
authored
feat: command to analyze table read/write I/O patterns (#4334)
* feat: add command to profile traffic * fix: docs table example * fix: add attribution to sql file * fix: format traffic_profile_test.go * fix: remove trailing semicolon from traffic_profile.sql for report compatibility * fix: clarify categorization behavior
1 parent 8d34a0f commit 1240cbc

File tree

5 files changed

+170
-0
lines changed

5 files changed

+170
-0
lines changed

cmd/inspect.go

Lines changed: 10 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -18,6 +18,7 @@ import (
1818
"github.com/supabase/cli/internal/inspect/replication_slots"
1919
"github.com/supabase/cli/internal/inspect/role_stats"
2020
"github.com/supabase/cli/internal/inspect/table_stats"
21+
"github.com/supabase/cli/internal/inspect/traffic_profile"
2122
"github.com/supabase/cli/internal/inspect/vacuum_stats"
2223
"github.com/supabase/cli/internal/utils/flags"
2324
)
@@ -135,6 +136,14 @@ var (
135136
},
136137
}
137138

139+
inspectTrafficProfileCmd = &cobra.Command{
140+
Use: "traffic-profile",
141+
Short: "Show read/write activity ratio for tables based on block I/O operations",
142+
RunE: func(cmd *cobra.Command, args []string) error {
143+
return traffic_profile.Run(cmd.Context(), flags.DbConfig, afero.NewOsFs())
144+
},
145+
}
146+
138147
inspectCacheHitCmd = &cobra.Command{
139148
Deprecated: `use "db-stats" instead.`,
140149
Use: "cache-hit",
@@ -270,6 +279,7 @@ func init() {
270279
inspectDBCmd.AddCommand(inspectBloatCmd)
271280
inspectDBCmd.AddCommand(inspectVacuumStatsCmd)
272281
inspectDBCmd.AddCommand(inspectTableStatsCmd)
282+
inspectDBCmd.AddCommand(inspectTrafficProfileCmd)
273283
inspectDBCmd.AddCommand(inspectRoleStatsCmd)
274284
inspectDBCmd.AddCommand(inspectDBStatsCmd)
275285
// DEPRECATED
Lines changed: 24 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,24 @@
1+
# db-traffic-profile
2+
3+
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.
4+
5+
6+
The command classifies tables into categories:
7+
- **Read-Heavy** - Read operations are more than 5x write operations (e.g., 1:10, 1:50)
8+
- **Write-Heavy** - Write operations are more than 20% of read operations (e.g., 1:2, 1:4, 2:1, 10:1)
9+
- **Balanced** - Mixed workload where writes are between 20% and 500% of reads
10+
- **Read-Only** - Only read operations detected
11+
- **Write-Only** - Only write operations detected
12+
13+
```
14+
SCHEMA │ TABLE │ BLOCKS READ │ WRITE TUPLES │ BLOCKS WRITE │ ACTIVITY RATIO
15+
───────┼──────────────┼─────────────┼──────────────┼──────────────┼────────────────────
16+
public │ user_events │ 450,234 │ 9,004,680│ 23,450 │ 20:1 (Write-Heavy)
17+
public │ users │ 89,203 │ 12,451│ 1,203 │ 7.2:1 (Read-Heavy)
18+
public │ sessions │ 15,402 │ 14,823│ 2,341 │ ≈1:1 (Balanced)
19+
public │ cache_data │ 123,456 │ 0│ 0 │ Read-Only
20+
auth │ audit_logs │ 0 │ 98,234│ 12,341 │ Write-Only
21+
```
22+
23+
**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.
24+
Lines changed: 49 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,49 @@
1+
package traffic_profile
2+
3+
import (
4+
"context"
5+
_ "embed"
6+
"fmt"
7+
8+
"github.com/go-errors/errors"
9+
"github.com/jackc/pgconn"
10+
"github.com/jackc/pgx/v4"
11+
"github.com/spf13/afero"
12+
"github.com/supabase/cli/internal/utils"
13+
"github.com/supabase/cli/pkg/pgxv5"
14+
)
15+
16+
//go:embed traffic_profile.sql
17+
var TrafficProfileQuery string
18+
19+
type Result struct {
20+
Schemaname string
21+
Table_name string
22+
Blocks_read int64
23+
Write_tuples int64
24+
Blocks_write float64
25+
Activity_ratio string
26+
}
27+
28+
func Run(ctx context.Context, config pgconn.Config, fsys afero.Fs, options ...func(*pgx.ConnConfig)) error {
29+
conn, err := utils.ConnectByConfig(ctx, config, options...)
30+
if err != nil {
31+
return err
32+
}
33+
defer conn.Close(context.Background())
34+
rows, err := conn.Query(ctx, TrafficProfileQuery)
35+
if err != nil {
36+
return errors.Errorf("failed to query rows: %w", err)
37+
}
38+
result, err := pgxv5.CollectRows[Result](rows)
39+
if err != nil {
40+
return err
41+
}
42+
43+
table := "|Schema|Table|Blocks Read|Write Tuples|Blocks Write|Activity Ratio|\n|-|-|-|-|-|-|\n"
44+
for _, r := range result {
45+
table += fmt.Sprintf("|`%s`|`%s`|`%d`|`%d`|`%.1f`|`%s`|\n",
46+
r.Schemaname, r.Table_name, r.Blocks_read, r.Write_tuples, r.Blocks_write, r.Activity_ratio)
47+
}
48+
return utils.RenderTable(table)
49+
}
Lines changed: 45 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,45 @@
1+
-- Query adapted from Crunchy Data blog: "Is Postgres Read Heavy or Write Heavy? (And Why You Should Care)" by David Christensen
2+
WITH
3+
ratio_target AS (SELECT 5 AS ratio),
4+
table_list AS (SELECT
5+
s.schemaname,
6+
s.relname AS table_name,
7+
si.heap_blks_read + si.idx_blks_read AS blocks_read,
8+
s.n_tup_ins + s.n_tup_upd + s.n_tup_del AS write_tuples,
9+
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
10+
FROM
11+
pg_stat_user_tables AS s
12+
JOIN pg_statio_user_tables AS si ON s.relid = si.relid
13+
JOIN pg_class c ON c.oid = s.relid
14+
WHERE
15+
(s.n_tup_ins + s.n_tup_upd + s.n_tup_del) > 0
16+
AND
17+
(si.heap_blks_read + si.idx_blks_read) > 0
18+
)
19+
SELECT
20+
schemaname,
21+
table_name,
22+
blocks_read,
23+
write_tuples,
24+
blocks_write,
25+
CASE
26+
WHEN blocks_read = 0 and blocks_write = 0 THEN
27+
'No Activity'
28+
WHEN blocks_write * ratio > blocks_read THEN
29+
CASE
30+
WHEN blocks_read = 0 THEN 'Write-Only'
31+
ELSE
32+
ROUND(blocks_write :: numeric / blocks_read :: numeric, 1)::text || ':1 (Write-Heavy)'
33+
END
34+
WHEN blocks_read > blocks_write * ratio THEN
35+
CASE
36+
WHEN blocks_write = 0 THEN 'Read-Only'
37+
ELSE
38+
'1:' || ROUND(blocks_read::numeric / blocks_write :: numeric, 1)::text || ' (Read-Heavy)'
39+
END
40+
ELSE
41+
'1:1 (Balanced)'
42+
END AS activity_ratio
43+
FROM table_list, ratio_target
44+
ORDER BY
45+
(blocks_read + blocks_write) DESC
Lines changed: 42 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,42 @@
1+
package traffic_profile
2+
3+
import (
4+
"context"
5+
"testing"
6+
7+
"github.com/jackc/pgconn"
8+
"github.com/spf13/afero"
9+
"github.com/stretchr/testify/assert"
10+
"github.com/supabase/cli/pkg/pgtest"
11+
)
12+
13+
var dbConfig = pgconn.Config{
14+
Host: "127.0.0.1",
15+
Port: 5432,
16+
User: "admin",
17+
Password: "password",
18+
Database: "postgres",
19+
}
20+
21+
func TestTrafficProfile(t *testing.T) {
22+
t.Run("inspects traffic profile", func(t *testing.T) {
23+
// Setup in-memory fs
24+
fsys := afero.NewMemMapFs()
25+
// Setup mock postgres
26+
conn := pgtest.NewConn()
27+
defer conn.Close(t)
28+
conn.Query(TrafficProfileQuery).
29+
Reply("SELECT 6", Result{
30+
Schemaname: "public",
31+
Table_name: "users",
32+
Blocks_read: 1000,
33+
Write_tuples: 500,
34+
Blocks_write: 250.5,
35+
Activity_ratio: "1:4.0 (Read-Heavy)",
36+
})
37+
// Run test
38+
err := Run(context.Background(), dbConfig, fsys, conn.Intercept)
39+
// Check error
40+
assert.NoError(t, err)
41+
})
42+
}

0 commit comments

Comments
 (0)