9d9c02ccd [1] added infrastructure in the query planner and executor
so that the executor would know to stop processing a monotonic
WindowFunc when its value went beyond what some qual in the outer
query could possibly match in future evaluations due to the
WindowFunc's monotonic nature.

In that commit, support was added so that the optimisation would work
for row_number(), rank(), dense_rank() and forms of count(*).  On
further inspection, it looks like the same can be done for ntile(),
percent_rank() and cume_dist(). These WindowFuncs are always
monotonically increasing.

I've attached a trivial patch to add the required support request type
to the existing prosupport functions for these window functions.

David

[1] https://git.postgresql.org/gitweb/?p=postgresql.git;a=commit;h=9d9c02ccd
diff --git a/src/backend/utils/adt/windowfuncs.c 
b/src/backend/utils/adt/windowfuncs.c
index af13b8e53d..b87a624fb2 100644
--- a/src/backend/utils/adt/windowfuncs.c
+++ b/src/backend/utils/adt/windowfuncs.c
@@ -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;
diff --git a/src/test/regress/expected/window.out 
b/src/test/regress/expected/window.out
index 26e2df6da5..747608e3c1 100644
--- a/src/test/regress/expected/window.out
+++ b/src/test/regress/expected/window.out
@@ -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
diff --git a/src/test/regress/sql/window.sql b/src/test/regress/sql/window.sql
index b7bd0a83da..1009b438de 100644
--- a/src/test/regress/sql/window.sql
+++ b/src/test/regress/sql/window.sql
@@ -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.

Reply via email to