Teach planner about more monotonic window functions

9d9c02ccd introduced runConditions for window functions to allow
monotonic window function evaluation to be made more efficient when the
window function value went beyond some value that it would never go back
from due to its monotonic nature.  That commit added prosupport functions
to inform the planner that row_number(), rank(), dense_rank() and some
forms of count(*) were monotonic.  Here we add support for ntile(),
cume_dist() and percent_rank().

Reviewed-by: Melanie Plageman
Discussion: https://postgr.es/m/CAApHDvqR+VqB8s+xR-24bzJbU8xyFrBszJ17qKgECf7cWxLCaA@mail.gmail.com
This commit is contained in:
David Rowley 2023-01-27 16:08:41 +13:00
parent 783d8abc3b
commit 456fa635a9
3 changed files with 50 additions and 16 deletions

View File

@ -288,6 +288,15 @@ window_percent_rank_support(PG_FUNCTION_ARGS)
{
Node *rawreq = (Node *) PG_GETARG_POINTER(0);
if (IsA(rawreq, SupportRequestWFuncMonotonic))
{
SupportRequestWFuncMonotonic *req = (SupportRequestWFuncMonotonic *) rawreq;
/* percent_rank() is monotonically increasing */
req->monotonic = MONOTONICFUNC_INCREASING;
PG_RETURN_POINTER(req);
}
if (IsA(rawreq, SupportRequestOptimizeWindowClause))
{
SupportRequestOptimizeWindowClause *req = (SupportRequestOptimizeWindowClause *) rawreq;
@ -362,6 +371,15 @@ window_cume_dist_support(PG_FUNCTION_ARGS)
{
Node *rawreq = (Node *) PG_GETARG_POINTER(0);
if (IsA(rawreq, SupportRequestWFuncMonotonic))
{
SupportRequestWFuncMonotonic *req = (SupportRequestWFuncMonotonic *) rawreq;
/* cume_dist() is monotonically increasing */
req->monotonic = MONOTONICFUNC_INCREASING;
PG_RETURN_POINTER(req);
}
if (IsA(rawreq, SupportRequestOptimizeWindowClause))
{
SupportRequestOptimizeWindowClause *req = (SupportRequestOptimizeWindowClause *) rawreq;
@ -465,6 +483,18 @@ window_ntile_support(PG_FUNCTION_ARGS)
{
Node *rawreq = (Node *) PG_GETARG_POINTER(0);
if (IsA(rawreq, SupportRequestWFuncMonotonic))
{
SupportRequestWFuncMonotonic *req = (SupportRequestWFuncMonotonic *) rawreq;
/*
* ntile() is monotonically increasing as the number of buckets cannot
* change after the first call
*/
req->monotonic = MONOTONICFUNC_INCREASING;
PG_RETURN_POINTER(req);
}
if (IsA(rawreq, SupportRequestOptimizeWindowClause))
{
SupportRequestOptimizeWindowClause *req = (SupportRequestOptimizeWindowClause *) rawreq;

View File

@ -3766,19 +3766,20 @@ SELECT * FROM
count(salary) OVER (PARTITION BY depname || '') c1, -- w1
row_number() OVER (PARTITION BY depname) rn, -- w2
count(*) OVER (PARTITION BY depname) c2, -- w2
count(*) OVER (PARTITION BY '' || depname) c3 -- w3
count(*) OVER (PARTITION BY '' || depname) c3, -- w3
ntile(2) OVER (PARTITION BY depname) nt -- w2
FROM empsalary
) e WHERE rn <= 1 AND c1 <= 3;
QUERY PLAN
-------------------------------------------------------------------------------------------
) e WHERE rn <= 1 AND c1 <= 3 AND nt < 2;
QUERY PLAN
-----------------------------------------------------------------------------------------------
Subquery Scan on e
-> WindowAgg
Filter: ((row_number() OVER (?)) <= 1)
Filter: (((row_number() OVER (?)) <= 1) AND ((ntile(2) OVER (?)) < 2))
Run Condition: (count(empsalary.salary) OVER (?) <= 3)
-> Sort
Sort Key: (((empsalary.depname)::text || ''::text))
-> WindowAgg
Run Condition: (row_number() OVER (?) <= 1)
Run Condition: ((row_number() OVER (?) <= 1) AND (ntile(2) OVER (?) < 2))
-> Sort
Sort Key: empsalary.depname
-> WindowAgg
@ -3793,13 +3794,14 @@ SELECT * FROM
count(salary) OVER (PARTITION BY depname || '') c1, -- w1
row_number() OVER (PARTITION BY depname) rn, -- w2
count(*) OVER (PARTITION BY depname) c2, -- w2
count(*) OVER (PARTITION BY '' || depname) c3 -- w3
count(*) OVER (PARTITION BY '' || depname) c3, -- w3
ntile(2) OVER (PARTITION BY depname) nt -- w2
FROM empsalary
) e WHERE rn <= 1 AND c1 <= 3;
depname | empno | salary | enroll_date | c1 | rn | c2 | c3
-----------+-------+--------+-------------+----+----+----+----
personnel | 5 | 3500 | 12-10-2007 | 2 | 1 | 2 | 2
sales | 3 | 4800 | 08-01-2007 | 3 | 1 | 3 | 3
) e WHERE rn <= 1 AND c1 <= 3 AND nt < 2;
depname | empno | salary | enroll_date | c1 | rn | c2 | c3 | nt
-----------+-------+--------+-------------+----+----+----+----+----
personnel | 5 | 3500 | 12-10-2007 | 2 | 1 | 2 | 2 | 1
sales | 3 | 4800 | 08-01-2007 | 3 | 1 | 3 | 3 | 1
(2 rows)
-- Tests to ensure we don't push down the run condition when it's not valid to

View File

@ -1220,9 +1220,10 @@ SELECT * FROM
count(salary) OVER (PARTITION BY depname || '') c1, -- w1
row_number() OVER (PARTITION BY depname) rn, -- w2
count(*) OVER (PARTITION BY depname) c2, -- w2
count(*) OVER (PARTITION BY '' || depname) c3 -- w3
count(*) OVER (PARTITION BY '' || depname) c3, -- w3
ntile(2) OVER (PARTITION BY depname) nt -- w2
FROM empsalary
) e WHERE rn <= 1 AND c1 <= 3;
) e WHERE rn <= 1 AND c1 <= 3 AND nt < 2;
-- Ensure we correctly filter out all of the run conditions from each window
SELECT * FROM
@ -1230,9 +1231,10 @@ SELECT * FROM
count(salary) OVER (PARTITION BY depname || '') c1, -- w1
row_number() OVER (PARTITION BY depname) rn, -- w2
count(*) OVER (PARTITION BY depname) c2, -- w2
count(*) OVER (PARTITION BY '' || depname) c3 -- w3
count(*) OVER (PARTITION BY '' || depname) c3, -- w3
ntile(2) OVER (PARTITION BY depname) nt -- w2
FROM empsalary
) e WHERE rn <= 1 AND c1 <= 3;
) e WHERE rn <= 1 AND c1 <= 3 AND nt < 2;
-- Tests to ensure we don't push down the run condition when it's not valid to
-- do so.