Skip to content

Commit

Permalink
Improve pg_stat_activity query. (#92)
Browse files Browse the repository at this point in the history
Partial changes by @CyberDem0n

When joining pg_locks there is no need to consider every single
locktype independantly to figure out which rows should be used for join.
Join on all possible rows with using 'IS NOT DISTINCT FROM' works the
same and easy to read and support.

Query will return unique list of pids in locked_by

For 9.6 use pg_blocking_pids instead of retrieving list of pids
from pg_locks. The old technique is too obscure and doesn't really work
for parallel queries. In addition to that reformat all queries to look similar.

report only heavy-weight locks ('Lock' wait_event_type) in pg_stat_activity for the 'locked' status in pg_view.
  • Loading branch information
alexeyklyukin authored Aug 9, 2017
1 parent e4d7018 commit de5325a
Showing 1 changed file with 65 additions and 114 deletions.
179 changes: 65 additions & 114 deletions pg_view/collectors/pg_collector.py
Original file line number Diff line number Diff line change
Expand Up @@ -444,49 +444,35 @@ def _read_pg_stat_activity(self):
client_port,
round(extract(epoch from (now() - xact_start))) as age,
waiting,
string_agg(other.pid::TEXT, ',' ORDER BY other.pid) as locked_by,
CASE
WHEN current_query = '<IDLE>' THEN 'idle'
WHEN current_query = '<IDLE> in transaction' THEN
CASE WHEN xact_start != query_start THEN
'idle in transaction'||' '||CAST(
abs(round(extract(epoch from (now() - query_start)))) AS text
)
ELSE
'idle in transaction'
END
WHEN current_query = '<IDLE> in transaction (aborted)' THEN 'idle in transaction (aborted)'
ELSE current_query
NULLIF(array_to_string(array_agg(DISTINCT other.pid ORDER BY other.pid), ','), '')
as locked_by,
CASE WHEN current_query = '<IDLE> in transaction' THEN
CASE WHEN xact_start != query_start THEN
'idle in transaction ' || CAST(
abs(round(extract(epoch from (now() - query_start)))) AS text
)
ELSE 'idle in transaction'
END
WHEN current_query = '<IDLE>' THEN 'idle'
ELSE current_query
END AS query
FROM pg_stat_activity
FROM pg_stat_activity a
LEFT JOIN pg_locks this ON (this.pid = procpid and this.granted = 'f')
-- acquire the same type of lock that is granted
LEFT JOIN pg_locks other ON ((this.locktype = other.locktype AND other.granted = 't')
AND ( ( this.locktype IN ('relation', 'extend')
AND this.database = other.database
AND this.relation = other.relation)
OR (this.locktype ='page'
AND this.database = other.database
AND this.relation = other.relation
AND this.page = other.page)
OR (this.locktype ='tuple'
AND this.database = other.database
AND this.relation = other.relation
AND this.page = other.page
AND this.tuple = other.tuple)
OR (this.locktype ='transactionid'
AND this.transactionid = other.transactionid)
OR (this.locktype = 'virtualxid'
AND this.virtualxid = other.virtualxid)
OR (this.locktype IN ('object', 'userlock', 'advisory')
AND this.database = other.database
AND this.classid = other.classid
AND this.objid = other.objid
AND this.objsubid = other.objsubid))
)
LEFT JOIN pg_locks other ON this.locktype = other.locktype
AND this.database IS NOT DISTINCT FROM other.database
AND this.relation IS NOT DISTINCT FROM other.relation
AND this.page IS NOT DISTINCT FROM other.page
AND this.tuple IS NOT DISTINCT FROM other.tuple
AND this.virtualxid IS NOT DISTINCT FROM other.virtualxid
AND this.transactionid IS NOT DISTINCT FROM other.transactionid
AND this.classid IS NOT DISTINCT FROM other.classid
AND this.objid IS NOT DISTINCT FROM other.objid
AND this.objsubid IS NOT DISTINCT FROM other.objsubid
AND this.pid != other.pid
AND other.granted = 't'
WHERE procpid != pg_backend_pid()
GROUP BY 1,2,3,4,5,6,7,9
""")
""")
elif self.dbver < 9.6:
cur.execute("""
SELECT datname,
Expand All @@ -496,46 +482,35 @@ def _read_pg_stat_activity(self):
client_port,
round(extract(epoch from (now() - xact_start))) as age,
waiting,
string_agg(other.pid::TEXT, ',' ORDER BY other.pid) as locked_by,
CASE
WHEN state = 'idle in transaction' THEN
CASE WHEN xact_start != state_change THEN
state||' '||CAST( abs(round(extract(epoch from (now() - state_change)))) AS text )
ELSE
state
END
WHEN state = 'active' THEN query
ELSE state
END AS query
NULLIF(array_to_string(array_agg(DISTINCT other.pid ORDER BY other.pid), ','), '')
as locked_by,
CASE WHEN state = 'idle in transaction' THEN
CASE WHEN xact_start != state_change THEN
'idle in transaction ' || CAST(
abs(round(extract(epoch from (now() - state_change)))) AS text
)
ELSE 'idle in transaction'
END
WHEN state = 'active' THEN query
ELSE state
END AS query
FROM pg_stat_activity a
LEFT JOIN pg_locks this ON (this.pid = a.pid and this.granted = 'f')
-- acquire the same type of lock that is granted
LEFT JOIN pg_locks other ON ((this.locktype = other.locktype AND other.granted = 't')
AND ( ( this.locktype IN ('relation', 'extend')
AND this.database = other.database
AND this.relation = other.relation)
OR (this.locktype ='page'
AND this.database = other.database
AND this.relation = other.relation
AND this.page = other.page)
OR (this.locktype ='tuple'
AND this.database = other.database
AND this.relation = other.relation
AND this.page = other.page
AND this.tuple = other.tuple)
OR (this.locktype ='transactionid'
AND this.transactionid = other.transactionid)
OR (this.locktype = 'virtualxid'
AND this.virtualxid = other.virtualxid)
OR (this.locktype IN ('object', 'userlock', 'advisory')
AND this.database = other.database
AND this.classid = other.classid
AND this.objid = other.objid
AND this.objsubid = other.objsubid))
)
LEFT JOIN pg_locks other ON this.locktype = other.locktype
AND this.database IS NOT DISTINCT FROM other.database
AND this.relation IS NOT DISTINCT FROM other.relation
AND this.page IS NOT DISTINCT FROM other.page
AND this.tuple IS NOT DISTINCT FROM other.tuple
AND this.virtualxid IS NOT DISTINCT FROM other.virtualxid
AND this.transactionid IS NOT DISTINCT FROM other.transactionid
AND this.classid IS NOT DISTINCT FROM other.classid
AND this.objid IS NOT DISTINCT FROM other.objid
AND this.objsubid IS NOT DISTINCT FROM other.objsubid
AND this.pid != other.pid
AND other.granted = 't'
WHERE a.pid != pg_backend_pid()
GROUP BY 1,2,3,4,5,6,7,9
""")
""")
else:
cur.execute("""
SELECT datname,
Expand All @@ -544,47 +519,23 @@ def _read_pg_stat_activity(self):
client_addr,
client_port,
round(extract(epoch from (now() - xact_start))) as age,
CASE WHEN wait_event IS NULL THEN false ELSE true END as waiting,
string_agg(other.pid::TEXT, ',' ORDER BY other.pid) as locked_by,
CASE
WHEN state = 'idle in transaction' THEN
CASE WHEN xact_start != state_change THEN
state||' '||CAST( abs(round(extract(epoch from (now() - state_change)))) AS text )
ELSE
state
END
WHEN state = 'active' THEN query
ELSE state
END AS query
wait_event_type IS NOT DISTINCT FROM 'Lock' AS waiting,
NULLIF(array_to_string(ARRAY(SELECT unnest(pg_blocking_pids(a.pid)) ORDER BY 1), ','), '')
as locked_by,
CASE WHEN state = 'idle in transaction' THEN
CASE WHEN xact_start != state_change THEN
'idle in transaction ' || CAST(
abs(round(extract(epoch from (now() - state_change)))) AS text
)
ELSE 'idle in transaction'
END
WHEN state = 'active' THEN query
ELSE state
END AS query
FROM pg_stat_activity a
LEFT JOIN pg_locks this ON (this.pid = a.pid and this.granted = 'f')
-- acquire the same type of lock that is granted
LEFT JOIN pg_locks other ON ((this.locktype = other.locktype AND other.granted = 't')
AND ( ( this.locktype IN ('relation', 'extend')
AND this.database = other.database
AND this.relation = other.relation)
OR (this.locktype ='page'
AND this.database = other.database
AND this.relation = other.relation
AND this.page = other.page)
OR (this.locktype ='tuple'
AND this.database = other.database
AND this.relation = other.relation
AND this.page = other.page
AND this.tuple = other.tuple)
OR (this.locktype ='transactionid'
AND this.transactionid = other.transactionid)
OR (this.locktype = 'virtualxid'
AND this.virtualxid = other.virtualxid)
OR (this.locktype IN ('object', 'userlock', 'advisory')
AND this.database = other.database
AND this.classid = other.classid
AND this.objid = other.objid
AND this.objsubid = other.objsubid))
)
WHERE a.pid != pg_backend_pid()
WHERE a.pid != pg_backend_pid() AND a.datname IS NOT NULL
GROUP BY 1,2,3,4,5,6,7,9
""")
""")
results = cur.fetchall()
# fill in the number of total connections, including ourselves
self.total_connections = len(results) + 1
Expand Down

0 comments on commit de5325a

Please sign in to comment.