|
| 1 | +Originally from: [tweet](https://twitter.com/samokhvalov/status/1714543861975204241), [LinkedIn post](). |
| 2 | + |
| 3 | +--- |
| 4 | + |
| 5 | +## How to analyze heavyweight locks, part 1 |
| 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 | +Heavyweight locks, both relation- and row-level, are acquired by a query and always held until the end of the |
| 11 | +transaction this query belongs to. So, important principle to remember: once acquired, a lock is not released until |
| 12 | +`COMMIT` or `ROLLBACK`. |
| 13 | + |
| 14 | +Docs: [Explicit locking](https://postgresql.org/docs/current/explicit-locking.html). A few notes about this doc: |
| 15 | + |
| 16 | +- The title "Explicit Locking" might seem misleading – it actually describes the levels of locks that can be acquired |
| 17 | + implicitly by any statement, not just explicitly via `LOCK`. |
| 18 | +- This page also contains a very useful table, "Conflicting Lock Modes", that helps understand the rules according which |
| 19 | + certain locks cannot be acquired due to conflicts and need to wait until the transaction holding such locks finishes, |
| 20 | + releasing the "blocking" locks. This article has an alternative table that might be also helpful: |
| 21 | + [PostgreSQL rocks, except when it blocks: Understanding locks](https://citusdata.com/blog/2018/02/15/when-postgresql-blocks/) |
| 22 | +- There also might be confusion in terminology. When discussing "table-level" locks, we might actually mean |
| 23 | + "relation-level" locks. Here, the term "relation" assumes a broader meaning: tables, indexes, views, materialized |
| 24 | + views. |
| 25 | + |
| 26 | +How can we see which locks have already been acquired (granted), or are being attempted but not yet acquired (pending) |
| 27 | +for a particular transaction/session? |
| 28 | + |
| 29 | +For this, there is a system view: [pg_locks](https://postgresql.org/docs/current/view-pg-locks.html). |
| 30 | + |
| 31 | +Important rule to remember: the analysis should be conducted in a separate session, to exclude the "observer effect" |
| 32 | +(the locks that are acquired by the analysis itself). |
| 33 | + |
| 34 | +For example, consider a table: |
| 35 | + |
| 36 | +``` |
| 37 | +nik=# \d t1 |
| 38 | + Table "public.t1" |
| 39 | + Column | Type | Collation | Nullable | Default |
| 40 | +--------+--------+-----------+----------+--------- |
| 41 | + c1 | bigint | | | |
| 42 | +Indexes: |
| 43 | + "t1_c1_idx" btree (c1) |
| 44 | + "t1_c1_idx1" btree (c1) |
| 45 | + "t1_c1_idx10" btree (c1) |
| 46 | + "t1_c1_idx11" btree (c1) |
| 47 | + "t1_c1_idx12" btree (c1) |
| 48 | + "t1_c1_idx13" btree (c1) |
| 49 | + "t1_c1_idx14" btree (c1) |
| 50 | + "t1_c1_idx15" btree (c1) |
| 51 | + "t1_c1_idx16" btree (c1) |
| 52 | + "t1_c1_idx17" btree (c1) |
| 53 | + "t1_c1_idx18" btree (c1) |
| 54 | + "t1_c1_idx19" btree (c1) |
| 55 | + "t1_c1_idx2" btree (c1) |
| 56 | + "t1_c1_idx20" btree (c1) |
| 57 | + "t1_c1_idx3" btree (c1) |
| 58 | + "t1_c1_idx4" btree (c1) |
| 59 | + "t1_c1_idx5" btree (c1) |
| 60 | + "t1_c1_idx6" btree (c1) |
| 61 | + "t1_c1_idx7" btree (c1) |
| 62 | + "t1_c1_idx8" btree (c1) |
| 63 | + "t1_c1_idx9" btree (c1) |
| 64 | +``` |
| 65 | + |
| 66 | +In the first (main) session: |
| 67 | + |
| 68 | +``` |
| 69 | +nik=# begin; |
| 70 | +BEGIN |
| 71 | +
|
| 72 | +nik=*# select from t1 limit 0; |
| 73 | +-- |
| 74 | +(0 rows) |
| 75 | +``` |
| 76 | + |
| 77 | +– we opened a transaction, performed a `SELECT from t1` - requesting 0 rows and 0 columns, but this is enough to acquire |
| 78 | +relation-level locks. To view these locks, we need to first obtain the `PID` of the first session, running this inside |
| 79 | +it: |
| 80 | + |
| 81 | +``` |
| 82 | +nik=*# select pg_backend_pid(); |
| 83 | + pg_backend_pid |
| 84 | +---------------- |
| 85 | + 73053 |
| 86 | +(1 row) |
| 87 | +``` |
| 88 | + |
| 89 | +Then, in a separate session: |
| 90 | + |
| 91 | +``` |
| 92 | +nik=# select relation, relation::regclass as relname, mode, granted, fastpath |
| 93 | +from pg_locks |
| 94 | +where pid = 73053 and locktype = 'relation' |
| 95 | +order by relname; |
| 96 | + relation | relname | mode | granted | fastpath |
| 97 | +----------+-------------+-----------------+---------+---------- |
| 98 | + 74298 | t1 | AccessShareLock | t | t |
| 99 | + 74301 | t1_c1_idx | AccessShareLock | t | t |
| 100 | + 74318 | t1_c1_idx1 | AccessShareLock | t | t |
| 101 | + 74319 | t1_c1_idx2 | AccessShareLock | t | t |
| 102 | + 74320 | t1_c1_idx3 | AccessShareLock | t | t |
| 103 | + 74321 | t1_c1_idx4 | AccessShareLock | t | t |
| 104 | + 74322 | t1_c1_idx5 | AccessShareLock | t | t |
| 105 | + 74323 | t1_c1_idx6 | AccessShareLock | t | t |
| 106 | + 74324 | t1_c1_idx7 | AccessShareLock | t | t |
| 107 | + 74325 | t1_c1_idx8 | AccessShareLock | t | t |
| 108 | + 74326 | t1_c1_idx9 | AccessShareLock | t | t |
| 109 | + 74327 | t1_c1_idx10 | AccessShareLock | t | t |
| 110 | + 74328 | t1_c1_idx11 | AccessShareLock | t | t |
| 111 | + 74337 | t1_c1_idx12 | AccessShareLock | t | t |
| 112 | + 74338 | t1_c1_idx13 | AccessShareLock | t | t |
| 113 | + 74339 | t1_c1_idx14 | AccessShareLock | t | t |
| 114 | + 74345 | t1_c1_idx20 | AccessShareLock | t | f |
| 115 | + 74346 | t1_c1_idx15 | AccessShareLock | t | f |
| 116 | + 74347 | t1_c1_idx16 | AccessShareLock | t | f |
| 117 | + 74348 | t1_c1_idx17 | AccessShareLock | t | f |
| 118 | + 74349 | t1_c1_idx18 | AccessShareLock | t | f |
| 119 | + 74350 | t1_c1_idx19 | AccessShareLock | t | f |
| 120 | +(22 rows) |
| 121 | +``` |
| 122 | + |
| 123 | +Notes: |
| 124 | + |
| 125 | +- For brevity, we are only requesting locks with the `locktype` set to `'relation'`. In a general case, we might be |
| 126 | + interested in other lock types too. |
| 127 | +- To see relation names, we convert `oid` values to `regclass`, this is the shortest way to retrieve the table/index |
| 128 | + names (so, `select 74298::oid::regclass` returns `t1`). |
| 129 | +- The lock mode `AccessShareLock` is the "weakest" possible, it blocks operations like `DROP TABLE`, `REINDEX`, certain |
| 130 | + types of `ALTER TABLE/INDEX`. By locking both the table and all its indexes, Postgres guarantees that they will remain |
| 131 | + present during our transaction. |
| 132 | +- Again: **all** indexes are locked with `AccessShareLock`. |
| 133 | +- In this case, all locks are granted. One might think it is always so with `AccessShareLock`, but it's not – if there |
| 134 | + is a granted or **pending** `AccessExclusiveLock` (the "strongest" on), then our attempt to acquire |
| 135 | + an `AccessShareLock` will be in the pending state. When might a pending `AccessExclusiveLock` occur? If there is an |
| 136 | + attempt of `AccessExclusiveLock` (e.g. `ALTER TABLE`), but there is some long-lasting `AccessShareLock` – a "sandwich" |
| 137 | + situation. This scenario can lead to downtimes when, during an attempt to deploy a very |
| 138 | + simple `ALTER TABLE .. ADD COLUMN` without proper precaution measures (low `lock_timeout` and retries), it is blocked |
| 139 | + by a long-running `SELECT`, which, in its turn, blocks subsequent `SELECT`s (and other DML). More: |
| 140 | + [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). |
| 141 | +- Only 16 of the locks have `fastpath=true`. When `fastpath=false`, Postgres lock manager uses a slower, but more |
| 142 | + comprehensive method to acquire locks. It is discussed in #PostgresMarathon |
| 143 | + [Day 18: Over-indexing](0018_over_indexing.md). |
0 commit comments