Re: Two Window aggregate node for logically same over clause - Mailing list pgsql-hackers

From Ashutosh Bapat
Subject Re: Two Window aggregate node for logically same over clause
Date
Msg-id CAExHW5vFH7Ndwc3QcSA6JjbeUzy3jWjLUddtxZ3p7g_3BOBxhA@mail.gmail.com
Whole thread Raw
In response to Two Window aggregate node for logically same over clause  ("\"Anitha S\"" <anitha.sg@zohocorp.com>)
Responses Re: Two Window aggregate node for logically same over clause
Re: Two Window aggregate node for logically same over clause
List pgsql-hackers
On Thu, Oct 5, 2023 at 8:53 PM "Anitha S" <anitha.sg@zohocorp.com> wrote:
>
>
>
> Hi team,
>
>       We have observed that for logically same over clause two different window aggregate nodes are created in plan.
> The below query contains two window functions. Both Over clause contain the same partition & order clause in it. But
inone over clause ordering option is mentioned as ascending but not in another over clause which represents the default
option"ascending". 
>
>
> Sample Query:
>
> CREATE TEMPORARY TABLE empsalary (
> depname varchar,
> empno bigint,
> salary int,
> enroll_date date
> );
>
> INSERT INTO empsalary VALUES ('develop', 10, 5200, '2007-08-01'), ('sales', 1, 5000, '2006-10-01'),
> ('personnel', 5, 3500, '2007-12-10'),('sales', 4, 4800, '2007-08-08'),('personnel', 2, 3900, '2006-12-23'),
> ('develop', 7, 4200, '2008-01-01'),('develop', 9, 4500, '2008-01-01'),('sales', 3, 4800, '2007-08-01'),
> ('develop', 8, 6000, '2006-10-01'),('develop', 11, 5200, '2007-08-15');
>
> explain verbose select rank() over (partition by depname order by salary), percent_rank() over(partition by depname
orderby salary asc) from empsalary; 
>                   QUERY PLAN
> ------------------------------------------------------------------------------------------
>      WindowAgg (cost=10000000074.54..10000000114.66 rows=1070 width=52)
>      Output: (rank() OVER (?)), percent_rank() OVER (?), salary, depname
>       -> WindowAgg (cost=10000000074.54..10000000095.94 rows=1070 width=44)
>           Output: salary, depname, rank() OVER (?)
>             -> Sort (cost=10000000074.54..10000000077.21 rows=1070 width=36)
>                 Output: salary, depname
>                 Sort Key: empsalary.depname, empsalary.salary
>                    -> Seq Scan on pg_temp_7.empsalary (cost=0.00..20.70 rows=1070 width=36)
>                        Output: salary, depname
>
>
> Ordering option of Sort is represented by enum SortByDir (parsenodes.h).
>
> List of SortBy is present in WindowDef structure which has info of order by clause in Over clause
>
> /* Sort ordering options for ORDER BY and CREATE INDEX */
> typedef enum SortByDir
> {
> SORTBY_DEFAULT,
> SORTBY_ASC,
> SORTBY_DESC,
> SORTBY_USING /* not allowed in CREATE INDEX ... */
> } SortByDir;
> typedef struct SortBy
> {
> NodeTag type;
> Node *node; /* expression to sort on */
> SortByDir sortby_dir; /* ASC/DESC/USING/default */
> SortByNulls sortby_nulls; /* NULLS FIRST/LAST */
> List *useOp; /* name of op to use, if SORTBY_USING */
> int location; /* operator location, or -1 if none/unknown */
> } SortBy;
>
>
> In transformWindowFuncCall API, Equality check of order clause in window definition failed while comparing SortByDir
enumof both over clause i.e SORT_DEFAULT  is not equal to SORT_ASC. Hence two window clause are created in parse tree
resultingin the creation of two different window aggregate node. 
>
> This check can be modified to form a single window aggregate node for the above results in faster query execution. Is
thereany reason for creating two different window aggregate node? 

I don't see any. https://www.postgresql.org/docs/16/sql-select.html
description of ORDER BY clause clearly says that ASC is assumed when
no direction is mentioned. The only place in code which is used to
create the node treats DEFAULT and ASC as same. May be we want to
allow default to be ASC or DESC based on some setting (read GUC) in
some future.

Another angle is to ask: Why would the query add ASC to one window
specification and not the other?

--
Best Wishes,
Ashutosh Bapat



pgsql-hackers by date:

Previous
From: Peter Eisentraut
Date:
Subject: Re: ALTER COLUMN ... SET EXPRESSION to alter stored generated column's expression
Next
From: torikoshia
Date:
Subject: Re: Make --help output fit within 80 columns per line