diff --git a/artifact_builder/indexer.py b/artifact_builder/indexer.py index 047d6d0..0c3800c 100644 --- a/artifact_builder/indexer.py +++ b/artifact_builder/indexer.py @@ -27,7 +27,7 @@ def indexDir(sqlDirectory: str, _engine: str) -> fileMap: _fileMap[key].update({'fpath': fpath, 'category': root.removeprefix(sqlDirectory + '/'), 'query': f.read()}) - elif filename.endswith(".md") and filename.removesuffix(".md").lower() != 'readme': + elif filename.endswith(".md") and filename.removesuffix(".md").lower() not in ('readme', '.gitkeep'): with open(fpath, encoding="utf-8") as f: _fileMap[key].update({'docFPath': fpath, 'doc': f.read()}) diff --git a/requirements.txt b/requirements.txt index 11e27d7..be9df40 100644 --- a/requirements.txt +++ b/requirements.txt @@ -1 +1,2 @@ pgsanity +ndjson==0.3.1 \ No newline at end of file diff --git a/sql/Locks/lock_contention_analysis.md b/sql/Locks/lock_contention_analysis.md new file mode 100644 index 0000000..0d83e61 --- /dev/null +++ b/sql/Locks/lock_contention_analysis.md @@ -0,0 +1,11 @@ +# Lock contention analysis + +Originilly published by Nikolai Samodkalov from [Modern Postgres Monitoring](https://docs.google.com/presentation/d/1taKST9H59FG7MKtVLUlqQ_WozJfRQ1MFidnN7HxBQ6U/edit#slide=id.g24d913ededf_0_22). + +Recommended to execute with `\watch Nsecs` (where Nsecs is the wait seconds). + +This query returns the locks affecting PIDS, the state of the lock and the query from +the PID. It also provides the current xid held by the PID and the longest xmin impacting +on the query. + +Use this statement whenever you want to hunt locking transactions. \ No newline at end of file diff --git a/sql/Locks/lock_contention_analysis.sql b/sql/Locks/lock_contention_analysis.sql new file mode 100644 index 0000000..8c89fd9 --- /dev/null +++ b/sql/Locks/lock_contention_analysis.sql @@ -0,0 +1,65 @@ +-- Lock contention query analysis +-- Original source https://docs.google.com/presentation/d/1taKST9H59FG7MKtVLUlqQ_WozJfRQ1MFidnN7HxBQ6U/edit#slide=id.g24d913ededf_0_22 +with recursive activity as ( + select + pg_blocking_pids(pid) blocked_by, + *, + age(clock_timestamp(), xact_start)::interval(0) as tx_age, + -- "pg_locks.waitstart" – PG14+ only; for older versions: age(clock_timestamp(), state_change) as wait_age + age(clock_timestamp(), (select max(l.waitstart) from pg_locks l where a.pid = l.pid))::interval(0) as wait_age + from pg_stat_activity a + where state is distinct from 'idle' +), blockers as ( + select + array_agg(distinct c order by c) as pids + from ( + select unnest(blocked_by) + from activity + ) as dt(c) +), tree as ( + select + activity.*, + 1 as level, + activity.pid as top_blocker_pid, + array[activity.pid] as path, + array[activity.pid]::int[] as all_blockers_above + from activity, blockers + where + array[pid] <@ blockers.pids + and blocked_by = '{}'::int[] + union all + select + activity.*, + tree.level + 1 as level, + tree.top_blocker_pid, + path || array[activity.pid] as path, + tree.all_blockers_above || array_agg(activity.pid) over () as all_blockers_above + from activity, tree + where + not array[activity.pid] <@ tree.all_blockers_above + and activity.blocked_by <> '{}'::int[] + and activity.blocked_by <@ tree.all_blockers_above +) +select + pid, + blocked_by, + case when wait_event_type <> 'Lock' then replace(state, 'idle in transaction', 'idletx') + else 'waiting' end as state, + wait_event_type || ':' || wait_event as wait, + wait_age, + tx_age, + to_char(age(backend_xid), 'FM999,999,999,990') as xid_age, + to_char(2147483647 - age(backend_xmin), 'FM999,999,999,990') as xmin_ttf, + datname, + usename, + (select count(distinct t1.pid) from tree t1 where array[tree.pid] <@ t1.path and t1.pid <> tree.pid) + as blkd, + format( + '%s %s%s', + lpad('[' || pid::text || ']', 9, ' '), + repeat('.', level - 1) || case when level > 1 then ' ' end, + left(query, 1000) + ) as query +from tree +order by top_blocker_pid, level, pid; + diff --git a/sql/Transaction/xmin_horizon.md b/sql/Transaction/xmin_horizon.md new file mode 100644 index 0000000..87303f4 --- /dev/null +++ b/sql/Transaction/xmin_horizon.md @@ -0,0 +1,10 @@ +# xmin horizon query + +> Original source by Nikolai Samokhvalov from [Modern PG Monitoring](https://docs.google.com/presentation/d/1taKST9H59FG7MKtVLUlqQ_WozJfRQ1MFidnN7HxBQ6U/edit#slide=id.g123822391b9_0_11). + +The query uses the `age` functions with `xmin` parameter and extracts +from the catalog (activity, replication slots, and prepared transactions) +the oldest transaction currently held. + +Useful for detecting long-execution transactions. + diff --git a/sql/Transaction/xmin_horizon.sql b/sql/Transaction/xmin_horizon.sql new file mode 100644 index 0000000..bcee07c --- /dev/null +++ b/sql/Transaction/xmin_horizon.sql @@ -0,0 +1,30 @@ +-- xmin horizon +-- Originally written by Nikolai Samokhvalov +-- Slides can be found at https://docs.google.com/presentation/d/1taKST9H59FG7MKtVLUlqQ_WozJfRQ1MFidnN7HxBQ6U/edit#slide=id.g24d913ededf_0_14 +with bits as ( + select + ( + select age(backend_xmin) as xmin_age_local + from pg_stat_activity + order by xmin_age_local desc nulls last + limit 1), + ( + select age(xmin) as xmin_age_slots + from pg_replication_slots + order by xmin_age_slots desc nulls last + limit 1 + ), + ( + select age(transaction) as xmin_age_prepared_xacts + from pg_prepared_xacts + order by xmin_age_prepared_xacts desc nulls last + limit 1 + ) +) +select + *, + case + when pg_is_in_recovery() then null + else greatest(xmin_age_local, xmin_age_slots, xmin_age_prepared_xacts) + end as xmin_age +from bits;