You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
28244: sql: Adds support for GROUPS mode of window framing r=knz a=yuzefovich
Adds support for GROUPS mode of window framing that
allows specifying the frame in terms of peer groups
which is like a mix of ROWS and RANGE introduced in
SQL:2011.
Peer groups are all rows not distinct in the ordering
columns. Let's go through an example: suppose we have
a table with the schema `(product_id INT PRIMARY KEY,
price INT)`
with 6 rows: (1, 1), (2, 1), (3, 1), (4, 2),
(5, 3), (6, 3). If a window function has `ORDER BY price`,
we will have three peer groups (1: rows 1, 2, 3; 2: row 4;
3: rows 5, 6). GROUPS mode allows us specify the frame
in terms of the number of these peer groups. For example,
with `GROUPS BETWEEN 2 PRECEDING AND 1 FOLLOWING`, the
frame of row 3 will contain rows 1-4 (there are no
preceding peer groups), and the frame of row 4 will
contain rows 1-6. Other combinations are also possible:
`GROUPS BETWEEN 1 PRECEDING AND 2 PRECEDING` produces
an empty frame, `GROUPS BETWEEN CURRENT ROW AND CURRENT
ROW`
will include only rows of the current row's peer
group.
Incremental change towards: #27100.
Release note (sql change): CockroachDB now supports
GROUPS mode of window frame specification.
Co-authored-by: yuzefovich <yahor@cockroachlabs.com>
statement error frame starting offset must not be null
2816
+
SELECT avg(price) OVER (GROUPS NULL PRECEDING) FROM products
2817
+
2818
+
statement error frame starting offset must not be null
2819
+
SELECT avg(price) OVER (GROUPS BETWEEN NULL PRECEDING AND 1 FOLLOWING) FROM products
2820
+
2821
+
statement error frame starting offset must not be negative
2822
+
SELECT price, avg(price) OVER (PARTITION BY price GROUPS -1 PRECEDING) AS avg_price FROM products
2823
+
2824
+
statement error frame starting offset must not be negative
2825
+
SELECT price, avg(price) OVER w AS avg_price FROM products WINDOW w AS (PARTITION BY price GROUPS -1 PRECEDING)
2826
+
2827
+
statement error frame ending offset must not be null
2828
+
SELECT avg(price) OVER (GROUPS BETWEEN 1 PRECEDING AND NULL FOLLOWING) FROM products
2829
+
2830
+
statement error frame ending offset must not be negative
2831
+
SELECT price, avg(price) OVER (PARTITION BY price GROUPS BETWEEN 1 FOLLOWING AND -1 FOLLOWING) AS avg_price FROM products
2832
+
2833
+
statement error frame ending offset must not be negative
2834
+
SELECT price, avg(price) OVER w AS avg_price FROM products WINDOW w AS (PARTITION BY price GROUPS BETWEEN 1 FOLLOWING AND -1 FOLLOWING)
2835
+
2836
+
statement error frame ending offset must not be negative
2837
+
SELECT product_name, price, min(price) OVER (PARTITION BY group_name GROUPS BETWEEN 1 PRECEDING AND 1 FOLLOWING) AS min_over_three, max(price) OVER (PARTITION BY group_name GROUPS BETWEEN UNBOUNDED PRECEDING AND -1 FOLLOWING) AS max_over_partition FROM products ORDER BY group_id
SELECT avg(price) OVER w AS avg_price FROM products WINDOW w AS (PARTITION BY group_name GROUPS BETWEEN 1.5 PRECEDING AND UNBOUNDED FOLLOWING)
2850
+
2851
+
statement error incompatible window frame end type: decimal
2852
+
SELECT avg(price) OVER (PARTITION BY group_name GROUPS BETWEEN UNBOUNDED PRECEDING AND 1.5 FOLLOWING) AS avg_price FROM products
2853
+
2854
+
statement error incompatible window frame end type: decimal
2855
+
SELECT avg(price) OVER w AS avg_price FROM products WINDOW w AS (PARTITION BY group_name GROUPS BETWEEN UNBOUNDED PRECEDING AND 1.5 FOLLOWING)
2856
+
2857
+
query RRRRR
2858
+
SELECT price, sum(price) OVER (ORDER BY price GROUPS UNBOUNDED PRECEDING), sum(price) OVER (ORDER BY price GROUPS 100 PRECEDING), sum(price) OVER (ORDER BY price GROUPS 1 PRECEDING), sum(price) OVER (ORDER BY group_name GROUPS CURRENT ROW) FROM products ORDER BY price, group_id
2859
+
----
2860
+
150.00 150.00 150.00 150.00 1050.00
2861
+
200.00 550.00 550.00 550.00 2000.00
2862
+
200.00 550.00 550.00 550.00 1050.00
2863
+
400.00 950.00 950.00 800.00 2000.00
2864
+
500.00 1450.00 1450.00 900.00 2000.00
2865
+
700.00 3550.00 3550.00 2600.00 3400.00
2866
+
700.00 3550.00 3550.00 2600.00 3400.00
2867
+
700.00 3550.00 3550.00 2600.00 1050.00
2868
+
800.00 4350.00 4350.00 2900.00 3400.00
2869
+
900.00 5250.00 5250.00 1700.00 2000.00
2870
+
1200.00 6450.00 6450.00 2100.00 3400.00
2871
+
2872
+
query RIRRRRRR
2873
+
SELECT price, dense_rank() OVER w, avg(price) OVER (w GROUPS BETWEEN UNBOUNDED PRECEDING AND 100 PRECEDING), avg(price) OVER (w GROUPS BETWEEN UNBOUNDED PRECEDING AND 2 PRECEDING), avg(price) OVER (w GROUPS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW), avg(price) OVER (w GROUPS BETWEEN UNBOUNDED PRECEDING AND 2 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN UNBOUNDED PRECEDING AND 100 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) FROM products WINDOW w AS (ORDER BY price) ORDER BY price
SELECT price, dense_rank() OVER w, avg(price) OVER (w GROUPS BETWEEN 4 PRECEDING AND 100 PRECEDING), avg(price) OVER (w GROUPS BETWEEN 3 PRECEDING AND 2 PRECEDING), avg(price) OVER (w GROUPS BETWEEN 2 PRECEDING AND CURRENT ROW), avg(price) OVER (w GROUPS BETWEEN 1 PRECEDING AND 2 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN 1 PRECEDING AND 100 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN 1 PRECEDING AND UNBOUNDED FOLLOWING) FROM products WINDOW w AS (ORDER BY price) ORDER BY price
SELECT price, dense_rank() OVER w, avg(price) OVER (w GROUPS BETWEEN 0 PRECEDING AND 0 PRECEDING), avg(price) OVER (w GROUPS BETWEEN 0 PRECEDING AND CURRENT ROW), avg(price) OVER (w GROUPS BETWEEN 0 PRECEDING AND 0 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN CURRENT ROW AND CURRENT ROW), avg(price) OVER (w GROUPS BETWEEN CURRENT ROW AND 2 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN CURRENT ROW AND 100 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING) FROM products WINDOW w AS (ORDER BY price) ORDER BY price
SELECT price, dense_rank() OVER w, avg(price) OVER (w GROUPS BETWEEN 3 FOLLOWING AND 100 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN 3 FOLLOWING AND 1 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN 2 FOLLOWING AND 6 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN 3 FOLLOWING AND 3 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN 0 FOLLOWING AND 4 FOLLOWING), avg(price) OVER (w GROUPS BETWEEN 5 FOLLOWING AND UNBOUNDED FOLLOWING) FROM products WINDOW w AS (ORDER BY price) ORDER BY price
SELECT group_name, product_name, price, avg(price) OVER (PARTITION BY group_name ORDER BY price GROUPS BETWEEN CURRENT ROW AND 3 FOLLOWING), avg(price) OVER (ORDER BY price GROUPS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) FROM products ORDER BY group_id
2934
+
----
2935
+
Smartphone Microsoft Lumia 200.00 500.00 586.36363636363636364
2936
+
Smartphone HTC One 400.00 600.00 586.36363636363636364
SELECT group_name, product_name, price, avg(price) OVER (GROUPS BETWEEN 1 PRECEDING AND 2 PRECEDING), avg(price) OVER (ORDER BY price GROUPS BETWEEN CURRENT ROW AND CURRENT ROW) FROM products ORDER BY group_id
0 commit comments