Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Update the PLPGSQL queries to resolve duplicate queries #1013

Open
wants to merge 1 commit into
base: master
Choose a base branch
from
Open
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
76 changes: 36 additions & 40 deletions collector/pg_stat_statements.go
Original file line number Diff line number Diff line change
Expand Up @@ -71,47 +71,43 @@ var (
prometheus.Labels{},
)

pgStatStatementsQuery = `SELECT
pg_get_userbyid(userid) as user,
pg_database.datname,
pg_stat_statements.queryid,
pg_stat_statements.calls as calls_total,
pg_stat_statements.total_time / 1000.0 as seconds_total,
pg_stat_statements.rows as rows_total,
pg_stat_statements.blk_read_time / 1000.0 as block_read_seconds_total,
pg_stat_statements.blk_write_time / 1000.0 as block_write_seconds_total
FROM pg_stat_statements
JOIN pg_database
ON pg_database.oid = pg_stat_statements.dbid
WHERE
total_time > (
SELECT percentile_cont(0.1)
WITHIN GROUP (ORDER BY total_time)
FROM pg_stat_statements
pgStatStatementsQuery = `WITH percentiles AS (
SELECT percentile_cont(0.1) WITHIN GROUP (ORDER BY total_time) AS percentile
FROM pg_stat_statements
)
ORDER BY seconds_total DESC
LIMIT 100;`

pgStatStatementsNewQuery = `SELECT
pg_get_userbyid(userid) as user,
pg_database.datname,
pg_stat_statements.queryid,
pg_stat_statements.calls as calls_total,
pg_stat_statements.total_exec_time / 1000.0 as seconds_total,
pg_stat_statements.rows as rows_total,
pg_stat_statements.blk_read_time / 1000.0 as block_read_seconds_total,
pg_stat_statements.blk_write_time / 1000.0 as block_write_seconds_total
FROM pg_stat_statements
JOIN pg_database
ON pg_database.oid = pg_stat_statements.dbid
WHERE
total_exec_time > (
SELECT percentile_cont(0.1)
WITHIN GROUP (ORDER BY total_exec_time)
FROM pg_stat_statements
)
ORDER BY seconds_total DESC
LIMIT 100;`
SELECT DISTINCT ON (pss.queryid, pg_get_userbyid(pss.userid), pg_database.datname)
pg_get_userbyid(pss.userid) as user,
pg_database.datname,
pss.queryid,
pss.calls as calls_total,
pss.total_time / 1000.0 as seconds_total,
pss.rows as rows_total,
pss.blk_read_time / 1000.0 as block_read_seconds_total,
pss.blk_write_time / 1000.0 as block_write_seconds_total
FROM pg_stat_statements pss
JOIN pg_database ON pg_database.oid = pss.dbid
CROSS JOIN percentiles
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Can you explain the CROSS JOIN here? I'm having trouble understanding the why. My understanding is that CROSS JOIN will produce a cartesian product where every possible combination of table A and B will exist.

WHERE pss.total_time > (SELECT percentile FROM percentiles)
ORDER BY pss.queryid, pg_get_userbyid(pss.userid) DESC, pg_database.datname
LIMIT 100;`

pgStatStatementsNewQuery = `SELECT DISTINCT ON (pss.queryid, pg_get_userbyid(pss.userid), pg_database.datname)
pg_get_userbyid(pss.userid) AS user,
pg_database.datname AS database_name,
pss.queryid,
pss.calls AS calls_total,
pss.total_exec_time / 1000.0 AS seconds_total,
pss.rows AS rows_total,
pss.blk_read_time / 1000.0 AS block_read_seconds_total,
pss.blk_write_time / 1000.0 AS block_write_seconds_total
FROM pg_stat_statements pss
JOIN pg_database ON pg_database.oid = pss.dbid
JOIN (
SELECT percentile_cont(0.1) WITHIN GROUP (ORDER BY total_exec_time) AS percentile_val
FROM pg_stat_statements
) AS perc ON pss.total_exec_time > perc.percentile_val
ORDER BY pss.queryid, pg_get_userbyid(pss.userid) DESC, pg_database.datname
LIMIT 100;`
)

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