Skip to content

Commit 676dbeb

Browse files
author
xiongcc
committed
add chapter 79,80
1 parent 14fdb56 commit 676dbeb

2 files changed

+160
-0
lines changed
Lines changed: 103 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,103 @@
1+
# How to find int4 PKs with out-of-range risks in a large database
2+
3+
>我每天都会发布一篇新的 PostgreSQL "howto" 文章。加入我的旅程吧 — 订阅、提供反馈、分享!
4+
5+
如今,现代 ORM 比如 Rails 或 Django 使用 int8 (bigint) 类型的主键 (PK)。然而,在旧项目中,可能存在使用 int4 (integer, int, serial) 主键的老表,这些表可能已增长并存在 int4 溢出的风险 — int4 的最大值为 [2,147,483,647](https://postgresql.org/docs/current/datatype-numeric.html),且不停机将主键从 int4 转换为 int8 并不是一项简单的任务 (TODO:在另一篇使用指南中介绍转换过程)。
6+
7+
以下是快速检查是否存在 int2 或 int4 PK 表的方法,并了解在每种情况下已使用了多少"容量" (来自postgres-checkup 的查询):
8+
9+
```sql
10+
do $$
11+
declare
12+
min_relpages int8 := 0; -- in very large DBs, skip small tables by setting this to 100
13+
rec record;
14+
out text := '';
15+
out1 json;
16+
i numeric := 0;
17+
val int8;
18+
ratio numeric;
19+
sql text;
20+
begin
21+
for rec in
22+
select
23+
c.oid,
24+
spcname as tblspace,
25+
nspname as schema_name,
26+
relname as table_name,
27+
t.typname,
28+
pg_get_serial_sequence(format('%I.%I', nspname, relname), attname) as seq,
29+
min(attname) as attname
30+
from pg_index i
31+
join pg_class c on c.oid = i.indrelid
32+
left join pg_tablespace tsp on tsp.oid = reltablespace
33+
left join pg_namespace n on n.oid = c.relnamespace
34+
join pg_attribute a on
35+
a.attrelid = i.indrelid
36+
and a.attnum = any(i.indkey)
37+
join pg_type t on t.oid = atttypid
38+
where
39+
i.indisprimary
40+
and (
41+
c.relpages >= min_relpages
42+
or pg_get_serial_sequence(format('%I.%I', nspname, relname), attname) is not null
43+
) and t.typname in ('int2', 'int4')
44+
and nspname <> 'pg_toast'
45+
group by 1, 2, 3, 4, 5, 6
46+
having count(*) = 1 -- skip PKs with 2+ columns (TODO: analyze them too)
47+
loop
48+
raise debug 'table: %', rec.table_name;
49+
50+
if rec.seq is null then
51+
sql := format('select max(%I) from %I.%I;', rec.attname, rec.schema_name, rec.table_name);
52+
else
53+
sql := format('select last_value from %s;', rec.seq);
54+
end if;
55+
56+
raise debug 'sql: %', sql;
57+
execute sql into val;
58+
59+
if rec.typname = 'int4' then
60+
ratio := (val::numeric / 2^31)::numeric;
61+
elsif rec.typname = 'int2' then
62+
ratio := (val::numeric / 2^15)::numeric;
63+
else
64+
assert false, 'unreachable point';
65+
end if;
66+
67+
if ratio > 0.1 then -- report only if > 10% of capacity is reached
68+
i := i + 1;
69+
70+
out1 := json_build_object(
71+
'table', (
72+
coalesce(nullif(quote_ident(rec.schema_name), 'public') || '.', '')
73+
|| quote_ident(rec.table_name)
74+
),
75+
'pk', rec.attname,
76+
'type', rec.typname,
77+
'current_max_value', val,
78+
'capacity_used_percent', round(100 * ratio, 2)
79+
);
80+
81+
raise debug 'cur: %', out1;
82+
83+
if out <> '' then
84+
out := out || e',\n';
85+
end if;
86+
87+
out := out || format(' "%s": %s', rec.table_name, out1);
88+
end if;
89+
end loop;
90+
91+
raise info e'{\n%\n}', out;
92+
end;
93+
$$ language plpgsql;
94+
```
95+
96+
输出示例
97+
98+
```sql
99+
INFO: {
100+
"oldbig": {"table" : "oldbig", "pk" : "id", "type" : "int4", "current_max_value" : 2107480000, "capacity_used_percent" : 98.14},
101+
"oldbig2": {"table" : "oldbig2", "pk" : "id", "type" : "int4", "current_max_value" : 1107480000, "capacity_used_percent" : 51.57}
102+
}
103+
```
Lines changed: 57 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,57 @@
1+
# How to rebuild many indexes using many backends avoiding deadlocks
2+
3+
> 我每天都会发布一篇新的 PostgreSQL "howto" 文章。加入我的旅程吧 — 订阅、提供反馈、分享!
4+
5+
有时我们需要重建多个索引,甚至全部索引,并希望加快速度。
6+
7+
例如,在从 Postgres 14 之前的版本升级到 14+ 后,为了从降低膨胀增长率这一优化项中受益,我们可能希望重建所有 B 树索引。
8+
9+
我们可以选择使用单一会话并设置较高的 [max_parallel_maintenance_workers](https://postgresqlco.nf/doc/en/param/max_parallel_maintenance_workers/) 值,一次处理一个索引。但如果我们有足够的资源 (大量的 vCPU 和快速的磁盘),那么 `max_parallel_maintenance_workers` 最大值可能也不足以充分利用资源 (更改 `max_parallel_maintenance_workers` 不需要重启,但不能超过 `max_worker_processes` 的数量,且更改该值需要重启)。在这种情况下,使用 `REINDEX INDEX CONCURRENTLY`,并行处理多个索引可能更合适。
10+
11+
但在这种情况下,索引需要按正确的顺序处理。问题在于,如果你尝试并行重建属于同一张表的两个索引,那么会检测到死锁,并且其中一个会话将失败:
12+
13+
```sql
14+
nik=# reindex index concurrently t1_hash_record_idx3;
15+
ERROR: deadlock detected
16+
DETAIL: Process 40 waits for ShareLock on virtual transaction 4/2506; blocked by process 1313.
17+
Process 1313 waits for ShareUpdateExclusiveLock on relation 16634 of database 16401; blocked by process 40.
18+
HINT: See server log for query details.
19+
```
20+
21+
为了解决这个问题,我们可以使用以下方式:
22+
23+
1. 决定要使用多少个重建会话,考虑 `max_parallel_maintenance_workers` 和预期资源利用率/饱和的风险 (CPU 和磁盘 IO)。
24+
2. 假设我们想使用 N 个重建会话,构建索引的完整列表及其所属的表名称,并为每个表"分配"一个特定的重建会话,见下方的查询。
25+
3. 使用此"分配",将整个索引列表划分为 N 个独立的列表,以确保每个表的所有索引仅出现在一个独立列表中 — 然后我们可以使用这 N 个列表运行 N 个会话。
26+
27+
以下查询可以帮助完成步骤 2:
28+
29+
```sql
30+
\set NUMBER_OF_SESSIONS 10
31+
32+
SELECT
33+
format('%I.%I', n.nspname, c.relname) AS table_fqn,
34+
format('%I.%I', n.nspname, i.relname) AS index_fqn,
35+
mod(
36+
hashtext(format('%I.%I', n.nspname, c.relname)) & 2147483647,
37+
:NUMBER_OF_SESSIONS
38+
) AS session_id
39+
FROM
40+
pg_index idx
41+
JOIN pg_class c ON idx.indrelid = c.oid
42+
JOIN pg_class i ON idx.indexrelid = i.oid
43+
JOIN pg_namespace n ON c.relnamespace = n.oid
44+
WHERE
45+
n.nspname NOT IN ('pg_catalog', 'pg_toast', 'information_schema')
46+
-- and ... additional filters if needed
47+
ORDER BY
48+
table_fqn, index_fqn;
49+
```
50+
51+
## 我见
52+
53+
这个技巧挺不错:
54+
55+
- **NUMBER_OF_SESSIONS**:设置需要的重建会话数量。
56+
- **session_id**:通过 `hashtext` 函数和模运算将表分配给不同的会话。
57+
- **WHERE 子句**:排除系统模式 (`pg_catalog``pg_toast``information_schema`) 中的索引,避免不必要的重建。

0 commit comments

Comments
 (0)