pgsql: Teach planner and executor about monotonic window funcs - Mailing list pgsql-committers

From David Rowley
Subject pgsql: Teach planner and executor about monotonic window funcs
Date
Msg-id E1ncaj6-000nex-Sn@gemulon.postgresql.org
Whole thread Raw
List pgsql-committers
Teach planner and executor about monotonic window funcs

Window functions such as row_number() always return a value higher than
the previously returned value for tuples in any given window partition.

Traditionally queries such as;

SELECT * FROM (
   SELECT *, row_number() over (order by c) rn
   FROM t
) t WHERE rn <= 10;

were executed fairly inefficiently.  Neither the query planner nor the
executor knew that once rn made it to 11 that nothing further would match
the outer query's WHERE clause.  It would blindly continue until all
tuples were exhausted from the subquery.

Here we implement means to make the above execute more efficiently.

This is done by way of adding a pg_proc.prosupport function to various of
the built-in window functions and adding supporting code to allow the
support function to inform the planner if the window function is
monotonically increasing, monotonically decreasing, both or neither.  The
planner is then able to make use of that information and possibly allow
the executor to short-circuit execution by way of adding a "run condition"
to the WindowAgg to allow it to determine if some of its execution work
can be skipped.

This "run condition" is not like a normal filter.  These run conditions
are only built using quals comparing values to monotonic window functions.
For monotonic increasing functions, quals making use of the btree
operators for <, <= and = can be used (assuming the window function column
is on the left). You can see here that once such a condition becomes false
that a monotonic increasing function could never make it subsequently true
again.  For monotonically decreasing functions the >, >= and = btree
operators for the given type can be used for run conditions.

The best-case situation for this is when there is a single WindowAgg node
without a PARTITION BY clause.  Here when the run condition becomes false
the WindowAgg node can simply return NULL.  No more tuples will ever match
the run condition.  It's a little more complex when there is a PARTITION
BY clause.  In this case, we cannot return NULL as we must still process
other partitions.  To speed this case up we pull tuples from the outer
plan to check if they're from the same partition and simply discard them
if they are.  When we find a tuple belonging to another partition we start
processing as normal again until the run condition becomes false or we run
out of tuples to process.

When there are multiple WindowAgg nodes to evaluate then this complicates
the situation.  For intermediate WindowAggs we must ensure we always
return all tuples to the calling node.  Any filtering done could lead to
incorrect results in WindowAgg nodes above.  For all intermediate nodes,
we can still save some work when the run condition becomes false.  We've
no need to evaluate the WindowFuncs anymore.  Other WindowAgg nodes cannot
reference the value of these and these tuples will not appear in the final
result anyway.  The savings here are small in comparison to what can be
saved in the top-level WingowAgg, but still worthwhile.

Intermediate WindowAgg nodes never filter out tuples, but here we change
WindowAgg so that the top-level WindowAgg filters out tuples that don't
match the intermediate WindowAgg node's run condition.  Such filters
appear in the "Filter" clause in EXPLAIN for the top-level WindowAgg node.

Here we add prosupport functions to allow the above to work for;
row_number(), rank(), dense_rank(), count(*) and count(expr).  It appears
technically possible to do the same for min() and max(), however, it seems
unlikely to be useful enough, so that's not done here.

Bump catversion

Author: David Rowley
Reviewed-by: Andy Fan, Zhihong Yu
Discussion: https://postgr.es/m/CAApHDvqvp3At8++yF8ij06sdcoo1S_b2YoaT9D4Nf+MObzsrLQ@mail.gmail.com

Branch
------
master

Details
-------
https://git.postgresql.org/pg/commitdiff/9d9c02ccd1aea8e9131d8f4edb21bf1687e40782

Modified Files
--------------
src/backend/commands/explain.c          |   8 +
src/backend/executor/nodeWindowAgg.c    | 380 ++++++++++++++++++++----------
src/backend/nodes/copyfuncs.c           |   4 +
src/backend/nodes/equalfuncs.c          |   1 +
src/backend/nodes/outfuncs.c            |   6 +
src/backend/nodes/readfuncs.c           |   4 +
src/backend/optimizer/path/allpaths.c   | 284 ++++++++++++++++++++++-
src/backend/optimizer/plan/createplan.c |  13 +-
src/backend/optimizer/plan/planner.c    |  15 +-
src/backend/optimizer/plan/setrefs.c    | 102 ++++++++
src/backend/optimizer/util/pathnode.c   |  13 +-
src/backend/utils/adt/int8.c            |  44 ++++
src/backend/utils/adt/windowfuncs.c     |  63 +++++
src/include/catalog/catversion.h        |   2 +-
src/include/catalog/pg_proc.dat         |  35 ++-
src/include/nodes/execnodes.h           |  24 +-
src/include/nodes/nodes.h               |   3 +-
src/include/nodes/parsenodes.h          |   1 +
src/include/nodes/pathnodes.h           |   3 +
src/include/nodes/plannodes.h           |  21 ++
src/include/nodes/supportnodes.h        |  64 ++++-
src/include/optimizer/pathnode.h        |   4 +-
src/test/regress/expected/window.out    | 398 ++++++++++++++++++++++++++++++++
src/test/regress/sql/window.sql         | 206 +++++++++++++++++
24 files changed, 1547 insertions(+), 151 deletions(-)


pgsql-committers by date:

Previous
From: Tom Lane
Date:
Subject: pgsql: Extend plsample example to include a trigger handler.
Next
From: Peter Geoghegan
Date:
Subject: pgsql: Truncate line pointer array during heap pruning.