Skip to content
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.

Commit 1081775

Browse files
committedMar 20, 2024
Update the PLPGSQL queries to resolve duplicate queries
Update the PLPGSQL queries to resolve duplicate queries Signed-off-by: VigneshViggu <vigneshkumar.venugopal@outlook.com>
1 parent ddd5136 commit 1081775

File tree

1 file changed

+36
-40
lines changed

1 file changed

+36
-40
lines changed
 

Diff for: ‎collector/pg_stat_statements.go

+36-40
Original file line numberDiff line numberDiff line change
@@ -71,47 +71,43 @@ var (
7171
prometheus.Labels{},
7272
)
7373

74-
pgStatStatementsQuery = `SELECT
75-
pg_get_userbyid(userid) as user,
76-
pg_database.datname,
77-
pg_stat_statements.queryid,
78-
pg_stat_statements.calls as calls_total,
79-
pg_stat_statements.total_time / 1000.0 as seconds_total,
80-
pg_stat_statements.rows as rows_total,
81-
pg_stat_statements.blk_read_time / 1000.0 as block_read_seconds_total,
82-
pg_stat_statements.blk_write_time / 1000.0 as block_write_seconds_total
83-
FROM pg_stat_statements
84-
JOIN pg_database
85-
ON pg_database.oid = pg_stat_statements.dbid
86-
WHERE
87-
total_time > (
88-
SELECT percentile_cont(0.1)
89-
WITHIN GROUP (ORDER BY total_time)
90-
FROM pg_stat_statements
74+
pgStatStatementsQuery = `WITH percentiles AS (
75+
SELECT percentile_cont(0.1) WITHIN GROUP (ORDER BY total_time) AS percentile
76+
FROM pg_stat_statements
9177
)
92-
ORDER BY seconds_total DESC
93-
LIMIT 100;`
94-
95-
pgStatStatementsNewQuery = `SELECT
96-
pg_get_userbyid(userid) as user,
97-
pg_database.datname,
98-
pg_stat_statements.queryid,
99-
pg_stat_statements.calls as calls_total,
100-
pg_stat_statements.total_exec_time / 1000.0 as seconds_total,
101-
pg_stat_statements.rows as rows_total,
102-
pg_stat_statements.blk_read_time / 1000.0 as block_read_seconds_total,
103-
pg_stat_statements.blk_write_time / 1000.0 as block_write_seconds_total
104-
FROM pg_stat_statements
105-
JOIN pg_database
106-
ON pg_database.oid = pg_stat_statements.dbid
107-
WHERE
108-
total_exec_time > (
109-
SELECT percentile_cont(0.1)
110-
WITHIN GROUP (ORDER BY total_exec_time)
111-
FROM pg_stat_statements
112-
)
113-
ORDER BY seconds_total DESC
114-
LIMIT 100;`
78+
SELECT DISTINCT ON (pss.queryid, pg_get_userbyid(pss.userid), pg_database.datname)
79+
pg_get_userbyid(pss.userid) as user,
80+
pg_database.datname,
81+
pss.queryid,
82+
pss.calls as calls_total,
83+
pss.total_time / 1000.0 as seconds_total,
84+
pss.rows as rows_total,
85+
pss.blk_read_time / 1000.0 as block_read_seconds_total,
86+
pss.blk_write_time / 1000.0 as block_write_seconds_total
87+
FROM pg_stat_statements pss
88+
JOIN pg_database ON pg_database.oid = pss.dbid
89+
CROSS JOIN percentiles
90+
WHERE pss.total_time > (SELECT percentile FROM percentiles)
91+
ORDER BY pss.queryid, pg_get_userbyid(pss.userid) DESC, pg_database.datname
92+
LIMIT 100;`
93+
94+
pgStatStatementsNewQuery = `SELECT DISTINCT ON (pss.queryid, pg_get_userbyid(pss.userid), pg_database.datname)
95+
pg_get_userbyid(pss.userid) AS user,
96+
pg_database.datname AS database_name,
97+
pss.queryid,
98+
pss.calls AS calls_total,
99+
pss.total_exec_time / 1000.0 AS seconds_total,
100+
pss.rows AS rows_total,
101+
pss.blk_read_time / 1000.0 AS block_read_seconds_total,
102+
pss.blk_write_time / 1000.0 AS block_write_seconds_total
103+
FROM pg_stat_statements pss
104+
JOIN pg_database ON pg_database.oid = pss.dbid
105+
JOIN (
106+
SELECT percentile_cont(0.1) WITHIN GROUP (ORDER BY total_exec_time) AS percentile_val
107+
FROM pg_stat_statements
108+
) AS perc ON pss.total_exec_time > perc.percentile_val
109+
ORDER BY pss.queryid, pg_get_userbyid(pss.userid) DESC, pg_database.datname
110+
LIMIT 100;`
115111
)
116112

117113
func (PGStatStatementsCollector) Update(ctx context.Context, instance *instance, ch chan<- prometheus.Metric) error {

0 commit comments

Comments
 (0)
Please sign in to comment.