Skip to content

Commit 17546c1

Browse files
msdoustiNikolayS
authored andcommitted
Days 41 & 42
1 parent 488a978 commit 17546c1

3 files changed

+248
-0
lines changed

0041_harmful_workloads.md

Lines changed: 117 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,117 @@
1+
Originally from: [tweet](https://twitter.com/samokhvalov/status/1721397029979779140), [LinkedIn post]().
2+
3+
---
4+
5+
# How to break a database, Part 3: Harmful workloads
6+
7+
> I post a new PostgreSQL "howto" article every day. Join me in this
8+
> journey – [subscribe](https://twitter.com/samokhvalov/), provide feedback, share!
9+
10+
See also
11+
12+
- [Part 1: How to Corrupt](0039_how_to_break_a_database_part_1_how_to_corrupt.md).
13+
- [Part 2: Simulate infamous transaction ID wraparound](0040_how_to_break_a_database_part_2_simulate_xid_wraparound.md).
14+
15+
## Too many connections
16+
17+
A simple snippet that creates 100 idle connections just with `psql` and a named pipe (a.k.a. FIFO, works in both macOS
18+
and Linux):
19+
20+
```bash
21+
mkfifo dummy
22+
23+
for i in $(seq 100); do
24+
psql -Xf dummy >/dev/null 2>&1 &
25+
done
26+
27+
❯ psql -Xc 'select count(*) from pg_stat_activity'
28+
count
29+
-------
30+
106
31+
(1 row)
32+
```
33+
34+
To close these connections, we can open a writing file descriptor to the FIFO and close it without writing any data:
35+
36+
```bash
37+
exec 3>dummy && exec 3>&-
38+
```
39+
40+
Now the 100 extra connections have gone:
41+
42+
```bash
43+
❯ psql -Xc 'select count(*) from pg_stat_activity'
44+
count
45+
-------
46+
6
47+
(1 row)
48+
```
49+
50+
And if the number of connections reaches `max_connections` when we perform the steps above, we should see this when
51+
trying to establish a new connection:
52+
53+
```bash
54+
❯ psql
55+
psql: error: connection to server on socket "/tmp/.s.PGSQL.5432" failed: FATAL: sorry, too many clients already
56+
```
57+
58+
## Idle-in-transaction sessions
59+
60+
This recipe we used in the XID wraparound simulation:
61+
62+
```bash
63+
mkfifo dummy
64+
65+
psql -Xc "
66+
set idle_in_transaction_session_timeout = 0;
67+
begin;
68+
select pg_current_xact_id()
69+
" \
70+
-f dummy &
71+
```
72+
73+
To release:
74+
75+
```bash
76+
exec 3>dummy && exec 3>&-
77+
```
78+
79+
## More types of harm using various tools
80+
81+
This tool can help you simulate various harmful workloads:
82+
[noisia – harmful workload generator for PostgreSQL](https://github.com/lesovsky/noisia).
83+
84+
As of 2023, it supports:
85+
86+
- idle transactions - active transactions on hot-write tables that do nothing during their lifetime
87+
- rollbacks - fake invalid queries that generate errors and increase rollbacks counter
88+
- waiting transactions - transactions that lock hot-write tables and then idle, leading to other transactions getting
89+
stuck
90+
- deadlocks - simultaneous transactions where each holds locks that the other transactions want
91+
- temporary files - queries that produce on-disk temporary files due to lack of `work_mem`
92+
- terminate backends - terminate random backends (or queries) using `pg_terminate_backend()`, `pg_cancel_backend()`
93+
- failed connections - exhaust all available connections (other clients unable to connect to Postgres)
94+
- fork connections - execute single, short query in a dedicated connection (lead to excessive forking of Postgres
95+
backends)
96+
97+
And this tool will crash your database periodically: [pg_crash](https://github.com/cybertec-postgresql/pg_crash)
98+
99+
For Aurora users, there are interesting functions: `aurora_inject_crash()`, `aurora_inject_replica_failure()`,
100+
`aurora_inject_disk_failure()`, `aurora_inject_disk_congestion()`: See
101+
[Testing Amazon Aurora PostgreSQL by using fault injection queries](https://docs.aws.amazon.com/AmazonRDS/latest/AuroraUserGuide/AuroraPostgreSQL.Managing.FaultInjectionQueries.html).
102+
103+
## Summary
104+
105+
The whole topic of chaos engineering is interesting and, in my opinion, has a great potential in there are of
106+
databases – to test recovery, failover, practice various incident situations. Some resources (beyond databases):
107+
108+
- Wikipedia: [Chaos engineering](https://en.wikipedia.org/wiki/Chaos_engineering)
109+
- Netflix's [Chaos Monkey](https://github.com/Netflix/chaosmonkey), a resiliency tool that helps applications tolerate
110+
random instance failures
111+
112+
Ideally, mature processes of database administration. whether in the cloud or not, managed or not, should include:
113+
114+
1. Regular simulation of incidents in non-production, to practice and improve runbooks for incident mitigation.
115+
116+
2. Regular initiation of incidents in production to see how *actually* automated mitigation works. For example:
117+
auto-removal of a crashed replica, autofailover, alerts and team response to long-running transactions.
Lines changed: 131 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,131 @@
1+
Originally from: [tweet](https://twitter.com/samokhvalov/status/1721799840886387097), [LinkedIn post]().
2+
3+
---
4+
5+
# How to analyze heavyweight locks, part 2: Lock trees (a.k.a. "lock queues", "wait queues", "blocking chains")
6+
7+
> I post a new PostgreSQL "howto" article every day. Join me in this
8+
> journey – [subscribe](https://twitter.com/samokhvalov/), provide feedback, share!
9+
10+
See also [Part 1](0022_how_to_analyze_heavyweight_locks_part_1.md).
11+
12+
Good sources of knowledge:
13+
14+
- [13.3. Explicit Locking](https://postgresql.org/docs/current/explicit-locking.html) – the docs (despite the title,
15+
it's only about the explicit locking).
16+
- [PostgreSQL rocks, except when it blocks: Understanding locks (2018)](https://citusdata.com/blog/2018/02/15/when-postgresql-blocks/),
17+
a blog post by [@marcoslot](https://twitter.com/marcoslot)
18+
- Egor Rogov's book [PostgreSQL 14 Internals](https://postgrespro.com/community/books/internals), Part III "Locks".
19+
- [PostgreSQL Lock Conflicts](https://postgres-locks.husseinnasser.com) – a reference-like tool by
20+
[@hnasr](https://twitter.com/hnasr) to study the relationships between various lock types and what types of locks
21+
various SQL commands acquire.
22+
23+
When locking issues occur, we usually need to:
24+
25+
1. Understand the nature and the scale of the problem.
26+
2. Consider terminating the initial "offending" sessions
27+
– tree roots – to stop the storm ASAP (usually, using `select pg_terminate_backend(<pid>);`).
28+
29+
Here is an advanced query that, in general case, shows the "forest of lock trees" (since there might be several "root"
30+
sessions, from which multiple "trees" grow):
31+
32+
```sql
33+
\timing on
34+
set statement_timeout to '100ms';
35+
36+
with recursive activity as (
37+
select
38+
pg_blocking_pids(pid) blocked_by,
39+
*,
40+
age(clock_timestamp(), xact_start)::interval(0) as tx_age,
41+
-- "pg_locks.waitstart" – PG14+ only; for older versions: age(clock_timestamp(), state_change) as wait_age
42+
age(clock_timestamp(), (select max(l.waitstart) from pg_locks l where http://a.pid = http://l.pid))::interval(0) as wait_age
43+
from pg_stat_activity a
44+
where state is distinct from 'idle'
45+
), blockers as (
46+
select
47+
array_agg(distinct c order by c) as pids
48+
from (
49+
select unnest(blocked_by)
50+
from activity
51+
) as dt(c)
52+
), tree as (
53+
select
54+
activity.*,
55+
1 as level,
56+
http://activity.pid as top_blocker_pid,
57+
array[http://activity.pid] as path,
58+
array[http://activity.pid]::int[] as all_blockers_above
59+
from activity, blockers
60+
where
61+
array[pid] <@ blockers.pids
62+
and blocked_by = '{}'::int[]
63+
union all
64+
select
65+
activity.*,
66+
tree.level + 1 as level,
67+
http://tree.top_blocker_pid,
68+
path || array[http://activity.pid] as path,
69+
tree.all_blockers_above || array_agg(http://activity.pid) over () as all_blockers_above
70+
from activity, tree
71+
where
72+
not array[http://activity.pid] <@ tree.all_blockers_above
73+
and activity.blocked_by <> '{}'::int[]
74+
and activity.blocked_by <@ tree.all_blockers_above
75+
)
76+
select
77+
pid,
78+
blocked_by,
79+
case when wait_event_type <> 'Lock' then replace(state, 'idle in transaction', 'idletx') else 'waiting' end as state,
80+
wait_event_type || ':' || wait_event as wait,
81+
wait_age,
82+
tx_age,
83+
to_char(age(backend_xid), 'FM999,999,999,990') as xid_age,
84+
to_char(2147483647 - age(backend_xmin), 'FM999,999,999,990') as xmin_ttf,
85+
datname,
86+
usename,
87+
(select count(distinct http://t1.pid) from tree t1 where array[http://tree.pid] <@ t1.path and http://t1.pid <> http://tree.pid) as blkd,
88+
format(
89+
'%s %s%s',
90+
lpad('[' || pid::text || ']', 9, ' '),
91+
repeat('.', level - 1) || case when level > 1 then ' ' end,
92+
left(query, 1000)
93+
) as query
94+
from tree
95+
order by top_blocker_pid, level, pid
96+
97+
\watch 10
98+
```
99+
100+
Notes:
101+
102+
1) It is present in the for ready to be executed in `psql`. For other clients, remove backslash commands; instead
103+
of `\watch`, use `;`.
104+
105+
2) The function `pg_blocking_pids(...)`, according to the docs, should be used with care:
106+
107+
> Frequent calls to this function could have some impact on database performance, because it needs exclusive access to
108+
> the lock manager's shared state for a short time.
109+
110+
It is not recommended to use it in an automated fashion (e.g., putting into monitoring). And this is why we have a low
111+
value for `statement_timeout` above – as protection.
112+
113+
Example output:
114+
115+
![Example output that shows the "forest of lock trees"](files/0042_example_output.jpeg)
116+
117+
Notes:
118+
119+
- Two trees with two root sessions – those with PIDs 46015 and 46081.
120+
- Both are waiting on client (`wait_event_type:wait_event` pair is `Client:ClientRead`), acquired some locks (last
121+
queries in session 46015 being an `UPDATE`, in session 46081 – `DROP TABLE`) and holding them.
122+
- The first tree (with root 46015) is bigger (11 blocked sessions) and reached the `height=4` (or the depth, depending
123+
on the point of view/terminology). This is exactly that an unfortunate situation when an `ALTER TABLE`, attempting to
124+
modify some table but being blocked by another session, starts blocking any session that tries to work with that
125+
table – even `SELECT`s (the problem discussed
126+
in [Zero-downtime Postgres schema migrations need this: lock_timeout and retries](https://postgres.ai/blog/20210923-zero-downtime-postgres-schema-migrations-lock-timeout-and-retries)).
127+
- While we're analyzing this, the situation might quickly change, so it might make sense to add timestamps or
128+
intervals (e.g., based on `xact_start`, `state_change` from `pg_stat_acitivty`). Also note, that since the results
129+
might have inconsistencies – when we read from `pg_stat_statements`, we deal with some dynamic data, not a snapshot,
130+
so there having some skews in the results is normal, if session states change quickly. Usually, it makes sense to
131+
analyze several sample results of the query before making conclusions and decisions.

files/0042_example_output.jpeg

141 KB
Loading

0 commit comments

Comments
 (0)