Skip to content

Commit 501d6f6

Browse files
author
xiongcc
committed
添加第51章:Learn how to work with schema metadata by spying after psql
1 parent cdfd4d0 commit 501d6f6

2 files changed

+102
-0
lines changed

How to use subtransactions in Postgres.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -59,6 +59,7 @@ SQL 标准定义了描述这种机制的两个基本指令:`SAVEPOINT` 和扩
5959
- 避免深度嵌套
6060
- 在包含子事务的事务中谨慎使用 `SELECT ... FOR UPDATE`
6161
- 监控 `pg_stat_slru` 数值 (PG13+,[Monitoring stats](https://postgresql.org/docs/current/monitoring-stats.html)),以便迅速发现并解决 SLRU 溢出问题。
62+
6263

6364
# 我见
6465

Lines changed: 101 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,101 @@
1+
# **Learn how to work with schema metadata by spying after **psql
2+
3+
>我每天都会发布一篇新的 PostgreSQL "howto" 文章。加入我的旅程吧 — 订阅、提供反馈、分享!
4+
5+
## 不确定时,从何开始
6+
7+
[psql 文档](https://postgresql.org/docs/current/app-psql.html)
8+
9+
`psql` 有内置帮助文档 — 命令`\?` ;在使用 psql 时值得记住并将其作为起点。
10+
11+
当你不确定某个函数的确切名称时,可以使用搜索命令 `\df *关键字*`。例如:
12+
13+
```sql
14+
nik=# \df *clock*
15+
List of functions
16+
Schema | Name | Result data type | Argument data types | Type
17+
------------+-----------------+--------------------------+---------------------+------
18+
pg_catalog | clock_timestamp | timestamp with time zone | | func
19+
(1 row)
20+
```
21+
22+
## 如何查看 psql 正在做什么 – ECHO_HIDDEN
23+
24+
假设我们想查看表 `t1` 的大小,为此,我们可以构建一个返回表大小的查询 (或者只是在某处找到其大小或询问 LLM)。但是当使用 `psql` 时,我们只需使用 `\dt+ t1`
25+
26+
```sql
27+
nik=# \dt+ t1
28+
List of relations
29+
Schema | Name | Type | Owner | Persistence | Access method | Size | Description
30+
--------+------+-------+----------+-------------+---------------+-------+-------------
31+
public | t1 | table | postgres | permanent | heap | 25 MB |
32+
(1 row)
33+
```
34+
35+
我们可能想要循环执行,以观察表大小是如何增长的。为此,psql 支持 `\watch` — 但是,它不适用于其他反斜杠命令。
36+
37+
解决方案 — 打开 `ECHO_HIDDEN` 并查看 `\dt+` 后面的 SQL 查询 (或者,你可以在启动 `psql` 时使用选项 `--echo-hidden`):
38+
39+
```sql
40+
nik=# \set ECHO_HIDDEN 1
41+
nik=#
42+
nik=# \dt+ t1
43+
********* QUERY **********
44+
SELECT n.nspname as "Schema",
45+
c.relname as "Name",
46+
CASE c.relkind WHEN 'r' THEN 'table' WHEN 'v' THEN 'view' WHEN 'm' THEN 'materialized view' WHEN 'i' THEN 'index' WHEN 'S' THEN 'sequence' WHEN 't' THEN 'TOAST table' WHEN 'f' THEN 'foreign table' WHEN 'p' THEN 'partitioned table' WHEN 'I' THEN 'partitioned index' END as "Type",
47+
pg_catalog.pg_get_userbyid(c.relowner) as "Owner",
48+
CASE c.relpersistence WHEN 'p' THEN 'permanent' WHEN 't' THEN 'temporary' WHEN 'u' THEN 'unlogged' END as "Persistence",
49+
am.amname as "Access method",
50+
pg_catalog.pg_size_pretty(pg_catalog.pg_table_size(c.oid)) as "Size",
51+
pg_catalog.obj_description(c.oid, 'pg_class') as "Description"
52+
FROM pg_catalog.pg_class c
53+
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
54+
LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam
55+
WHERE c.relkind IN ('r','p','t','s','')
56+
AND c.relname OPERATOR(pg_catalog.~) '^(t1)$' COLLATE pg_catalog.default
57+
AND pg_catalog.pg_table_is_visible(c.oid)
58+
ORDER BY 1,2;
59+
**************************
60+
61+
List of relations
62+
Schema | Name | Type | Owner | Persistence | Access method | Size | Description
63+
--------+------+-------+----------+-------------+---------------+-------+-------------
64+
public | t1 | table | postgres | permanent | heap | 72 MB |
65+
(1 row)
66+
```
67+
68+
现在我们得到了 SQL 查询,便可以使用 `\watch 5` 每隔 5 秒查看一次表大小 (并且可以省略不需要的字段):
69+
70+
```sql
71+
nik=# SELECT n.nspname as "Schema",
72+
c.relname as "Name",
73+
pg_catalog.pg_size_pretty(pg_catalog.pg_table_size(c.oid)) as "Size"
74+
FROM pg_catalog.pg_class c
75+
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
76+
LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam
77+
WHERE c.relkind IN ('r','p','t','s','')
78+
AND c.relname OPERATOR(pg_catalog.~) '^(t1)$' COLLATE pg_catalog.default
79+
AND pg_catalog.pg_table_is_visible(c.oid)
80+
ORDER BY 1,2 \watch 5
81+
Thu 16 Nov 2023 08:00:10 AM UTC (every 5s)
82+
83+
Schema | Name | Size
84+
--------+------+-------
85+
public | t1 | 73 MB
86+
(1 row)
87+
88+
Thu 16 Nov 2023 08:00:15 AM UTC (every 5s)
89+
90+
Schema | Name | Size
91+
--------+------+-------
92+
public | t1 | 75 MB
93+
(1 row)
94+
95+
Thu 16 Nov 2023 08:00:20 AM UTC (every 5s)
96+
97+
Schema | Name | Size
98+
--------+------+-------
99+
public | t1 | 77 MB
100+
(1 row)
101+
```

0 commit comments

Comments
 (0)