Skip to content

Commit 8299fe8

Browse files
craig[bot]yuzefovich
andcommitted
Merge #28244
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>
2 parents 56c9249 + 09609b3 commit 8299fe8

File tree

20 files changed

+1078
-474
lines changed

20 files changed

+1078
-474
lines changed

docs/generated/sql/bnf/stmt_block.bnf

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -683,6 +683,7 @@ unreserved_keyword ::=
683683
| 'FORCE_INDEX'
684684
| 'GIN'
685685
| 'GRANTS'
686+
| 'GROUPS'
686687
| 'HIGH'
687688
| 'HISTOGRAM'
688689
| 'HOUR'
@@ -2104,6 +2105,7 @@ opt_partition_clause ::=
21042105
opt_frame_clause ::=
21052106
'RANGE' frame_extent
21062107
| 'ROWS' frame_extent
2108+
| 'GROUPS' frame_extent
21072109
|
21082110

21092111
extract_list ::=

pkg/sql/distsqlrun/processors.go

Lines changed: 16 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1121,6 +1121,8 @@ func (spec *WindowerSpec_Frame_Mode) initFromAST(w tree.WindowFrameMode) {
11211121
*spec = WindowerSpec_Frame_RANGE
11221122
case tree.ROWS:
11231123
*spec = WindowerSpec_Frame_ROWS
1124+
case tree.GROUPS:
1125+
*spec = WindowerSpec_Frame_GROUPS
11241126
default:
11251127
panic("unexpected WindowFrameMode")
11261128
}
@@ -1186,6 +1188,12 @@ func (spec *WindowerSpec_Frame_Bounds) initFromAST(
11861188
return err
11871189
}
11881190
spec.Start.TypedOffset = buf
1191+
case tree.GROUPS:
1192+
startOffset := int(tree.MustBeDInt(dStartOffset))
1193+
if startOffset < 0 {
1194+
return pgerror.NewErrorf(pgerror.CodeInvalidWindowFrameOffsetError, "frame starting offset must not be negative")
1195+
}
1196+
spec.Start.IntOffset = uint32(startOffset)
11891197
}
11901198
}
11911199

@@ -1225,6 +1233,12 @@ func (spec *WindowerSpec_Frame_Bounds) initFromAST(
12251233
return err
12261234
}
12271235
spec.End.TypedOffset = buf
1236+
case tree.GROUPS:
1237+
endOffset := int(tree.MustBeDInt(dEndOffset))
1238+
if endOffset < 0 {
1239+
return pgerror.NewErrorf(pgerror.CodeInvalidWindowFrameOffsetError, "frame ending offset must not be negative")
1240+
}
1241+
spec.End.IntOffset = uint32(endOffset)
12281242
}
12291243
}
12301244
}
@@ -1261,6 +1275,8 @@ func (spec WindowerSpec_Frame_Mode) convertToAST() tree.WindowFrameMode {
12611275
return tree.RANGE
12621276
case WindowerSpec_Frame_ROWS:
12631277
return tree.ROWS
1278+
case WindowerSpec_Frame_GROUPS:
1279+
return tree.GROUPS
12641280
default:
12651281
panic("unexpected WindowerSpec_Frame_Mode")
12661282
}

pkg/sql/distsqlrun/processors.pb.go

Lines changed: 244 additions & 238 deletions
Some generated files are not rendered by default. Learn more about customizing how changed files appear on GitHub.

pkg/sql/distsqlrun/processors.proto

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -899,6 +899,9 @@ message WindowerSpec {
899899
RANGE = 0;
900900
// ROWS specifies frame in terms of physical offsets (e.g. 1 row before).
901901
ROWS = 1;
902+
// GROUPS specifies frame in terms of peer groups (where "peers" mean
903+
// rows not distinct in the ordering columns).
904+
GROUPS = 2;
902905
}
903906

904907
// BoundType indicates which type of boundary is used.

pkg/sql/distsqlrun/windower.go

Lines changed: 13 additions & 19 deletions
Original file line numberDiff line numberDiff line change
@@ -410,7 +410,7 @@ func (w *windower) emitRow() (windowerState, sqlbase.EncDatumRow, *ProducerMetad
410410
// After all window functions have been computed, the remaining columns
411411
// are also simply appended to corresponding rows in outputRows.
412412
func (w *windower) computeWindowFunctions(ctx context.Context, evalCtx *tree.EvalContext) error {
413-
var peerGrouper peerGroupChecker
413+
var peerGrouper tree.PeerGroupChecker
414414
usage := sliceOfRowsSliceOverhead + sizeOfSliceOfRows*int64(len(w.windowFns))
415415
if err := w.resultsAcc.Grow(w.Ctx, usage); err != nil {
416416
return err
@@ -500,6 +500,8 @@ func (w *windower) computeWindowFunctions(ctx context.Context, evalCtx *tree.Eva
500500
return errors.Errorf("%d trailing bytes in encoded value", len(rem))
501501
}
502502
frameRun.StartBoundOffset = datum
503+
case WindowerSpec_Frame_GROUPS:
504+
frameRun.StartBoundOffset = tree.NewDInt(tree.DInt(int(startBound.IntOffset)))
503505
default:
504506
panic("unexpected WindowFrameMode")
505507
}
@@ -519,6 +521,8 @@ func (w *windower) computeWindowFunctions(ctx context.Context, evalCtx *tree.Eva
519521
return errors.Errorf("%d trailing bytes in encoded value", len(rem))
520522
}
521523
frameRun.EndBoundOffset = datum
524+
case WindowerSpec_Frame_GROUPS:
525+
frameRun.EndBoundOffset = tree.NewDInt(tree.DInt(int(endBound.IntOffset)))
522526
default:
523527
panic("unexpected WindowFrameMode")
524528
}
@@ -611,25 +615,21 @@ func (w *windower) computeWindowFunctions(ctx context.Context, evalCtx *tree.Eva
611615
builtins.ShouldReset(builtin)
612616
}
613617

614-
for frameRun.RowIdx < partition.Len() {
615-
// Compute the size of the current peer group.
616-
frameRun.FirstPeerIdx = frameRun.RowIdx
617-
frameRun.PeerRowCount = 1
618-
for ; frameRun.FirstPeerIdx+frameRun.PeerRowCount < frameRun.PartitionSize(); frameRun.PeerRowCount++ {
619-
cur := frameRun.FirstPeerIdx + frameRun.PeerRowCount
620-
if !peerGrouper.InSameGroup(cur, cur-1) {
621-
break
622-
}
623-
}
618+
frameRun.PeerHelper.Init(frameRun, peerGrouper)
619+
frameRun.CurRowPeerGroupNum = 0
624620

621+
for frameRun.RowIdx < partition.Len() {
625622
// Perform calculations on each row in the current peer group.
626-
for ; frameRun.RowIdx < frameRun.FirstPeerIdx+frameRun.PeerRowCount; frameRun.RowIdx++ {
623+
peerGroupEndIdx := frameRun.PeerHelper.GetFirstPeerIdx(frameRun.CurRowPeerGroupNum) + frameRun.PeerHelper.GetRowCount(frameRun.CurRowPeerGroupNum)
624+
for ; frameRun.RowIdx < peerGroupEndIdx; frameRun.RowIdx++ {
627625
res, err := builtin.Compute(ctx, evalCtx, frameRun)
628626
if err != nil {
629627
return err
630628
}
631629
w.windowValues[windowFnIdx][partitionIdx][frameRun.Rows.GetRow(frameRun.RowIdx).GetIdx()] = res
632630
}
631+
frameRun.PeerHelper.Update(frameRun)
632+
frameRun.CurRowPeerGroupNum++
633633
}
634634
}
635635
}
@@ -695,7 +695,7 @@ func (n *partitionSorter) Swap(i, j int) {
695695
}
696696
func (n *partitionSorter) Less(i, j int) bool { return n.Compare(i, j) < 0 }
697697

698-
// partitionSorter implements the peerGroupChecker interface.
698+
// partitionSorter implements the tree.PeerGroupChecker interface.
699699
func (n *partitionSorter) InSameGroup(i, j int) bool { return n.Compare(i, j) == 0 }
700700

701701
func (n *partitionSorter) Compare(i, j int) int {
@@ -718,12 +718,6 @@ type allPeers struct{}
718718
// allPeers implements the peerGroupChecker interface.
719719
func (allPeers) InSameGroup(i, j int) bool { return true }
720720

721-
// peerGroupChecker can check if a pair of row indexes within a partition are
722-
// in the same peer group.
723-
type peerGroupChecker interface {
724-
InSameGroup(i, j int) bool
725-
}
726-
727721
const sizeOfIndexedRowsStruct = int64(unsafe.Sizeof(indexedRows{}))
728722
const indexedRowsStructSliceOverhead = int64(unsafe.Sizeof([]indexedRows{}))
729723
const sizeOfSliceOfIndexedRows = int64(unsafe.Sizeof([]indexedRows{}))

pkg/sql/logictest/testdata/logic_test/window

Lines changed: 147 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2811,3 +2811,150 @@ Dell {"Microsoft Lumia","HTC One","Nexus","iPhone","HP Elite","Lenov
28112811
iPad {"Microsoft Lumia","HTC One","Nexus","iPhone","HP Elite","Lenovo Thinkpad","Sony VAIO","Dell","iPad"}
28122812
Kindle Fire {"Microsoft Lumia","HTC One","Nexus","iPhone","HP Elite","Lenovo Thinkpad","Sony VAIO","Dell","iPad","Kindle Fire"}
28132813
Samsung {"Microsoft Lumia","HTC One","Nexus","iPhone","HP Elite","Lenovo Thinkpad","Sony VAIO","Dell","iPad","Kindle Fire","Samsung"}
2814+
2815+
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
2838+
2839+
statement error incompatible window frame start type: decimal
2840+
SELECT avg(price) OVER (PARTITION BY group_name GROUPS 1.5 PRECEDING) AS avg_price FROM products
2841+
2842+
statement error incompatible window frame start type: decimal
2843+
SELECT avg(price) OVER w AS avg_price FROM products WINDOW w AS (PARTITION BY group_name GROUPS 1.5 PRECEDING)
2844+
2845+
statement error incompatible window frame start type: decimal
2846+
SELECT avg(price) OVER (PARTITION BY group_name GROUPS BETWEEN 1.5 PRECEDING AND UNBOUNDED FOLLOWING) AS avg_price FROM products
2847+
2848+
statement error incompatible window frame start type: decimal
2849+
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
2874+
----
2875+
150.00 1 NULL NULL 150.00 237.50 586.36363636363636364 586.36363636363636364
2876+
200.00 2 NULL NULL 183.33333333333333333 290.00 586.36363636363636364 586.36363636363636364
2877+
200.00 2 NULL NULL 183.33333333333333333 290.00 586.36363636363636364 586.36363636363636364
2878+
400.00 3 NULL 150.00 237.50 443.75 586.36363636363636364 586.36363636363636364
2879+
500.00 4 NULL 183.33333333333333333 290.00 483.33333333333333333 586.36363636363636364 586.36363636363636364
2880+
700.00 5 NULL 237.50 443.75 525.00 586.36363636363636364 586.36363636363636364
2881+
700.00 5 NULL 237.50 443.75 525.00 586.36363636363636364 586.36363636363636364
2882+
700.00 5 NULL 237.50 443.75 525.00 586.36363636363636364 586.36363636363636364
2883+
800.00 6 NULL 290.00 483.33333333333333333 586.36363636363636364 586.36363636363636364 586.36363636363636364
2884+
900.00 7 NULL 443.75 525.00 586.36363636363636364 586.36363636363636364 586.36363636363636364
2885+
1200.00 8 NULL 483.33333333333333333 586.36363636363636364 586.36363636363636364 586.36363636363636364 586.36363636363636364
2886+
2887+
query RIRRRRRR
2888+
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
2889+
----
2890+
150.00 1 NULL NULL 150.00 237.50 586.36363636363636364 586.36363636363636364
2891+
200.00 2 NULL NULL 183.33333333333333333 290.00 586.36363636363636364 586.36363636363636364
2892+
200.00 2 NULL NULL 183.33333333333333333 290.00 586.36363636363636364 586.36363636363636364
2893+
400.00 3 NULL 150.00 237.50 485.71428571428571429 630.00 630.00
2894+
500.00 4 NULL 183.33333333333333333 325.00 633.33333333333333333 737.50 737.50
2895+
700.00 5 NULL 266.66666666666666667 600.00 716.66666666666666667 785.71428571428571429 785.71428571428571429
2896+
700.00 5 NULL 266.66666666666666667 600.00 716.66666666666666667 785.71428571428571429 785.71428571428571429
2897+
700.00 5 NULL 266.66666666666666667 600.00 716.66666666666666667 785.71428571428571429 785.71428571428571429
2898+
800.00 6 NULL 450.00 680.00 833.33333333333333333 833.33333333333333333 833.33333333333333333
2899+
900.00 7 NULL 650.00 760.00 966.66666666666666667 966.66666666666666667 966.66666666666666667
2900+
1200.00 8 NULL 725.00 966.66666666666666667 1050.00 1050.00 1050.00
2901+
2902+
query RIRRRRRRR
2903+
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
2904+
----
2905+
150.00 1 150.00 150.00 150.00 150.00 237.50 586.36363636363636364 586.36363636363636364
2906+
200.00 2 200.00 200.00 200.00 200.00 325.00 630.00 630.00
2907+
200.00 2 200.00 200.00 200.00 200.00 325.00 630.00 630.00
2908+
400.00 3 400.00 400.00 400.00 400.00 600.00 737.50 737.50
2909+
500.00 4 500.00 500.00 500.00 500.00 680.00 785.71428571428571429 785.71428571428571429
2910+
700.00 5 700.00 700.00 700.00 700.00 760.00 833.33333333333333333 833.33333333333333333
2911+
700.00 5 700.00 700.00 700.00 700.00 760.00 833.33333333333333333 833.33333333333333333
2912+
700.00 5 700.00 700.00 700.00 700.00 760.00 833.33333333333333333 833.33333333333333333
2913+
800.00 6 800.00 800.00 800.00 800.00 966.66666666666666667 966.66666666666666667 966.66666666666666667
2914+
900.00 7 900.00 900.00 900.00 900.00 1050.00 1050.00 1050.00
2915+
1200.00 8 1200.00 1200.00 1200.00 1200.00 1200.00 1200.00 1200.00
2916+
2917+
query RIRRRRRR
2918+
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
2919+
----
2920+
150.00 1 785.71428571428571429 NULL 671.42857142857142857 500.00 443.75 966.66666666666666667
2921+
200.00 2 833.33333333333333333 NULL 785.71428571428571429 700.00 525.00 1050.00
2922+
200.00 2 833.33333333333333333 NULL 785.71428571428571429 700.00 525.00 1050.00
2923+
400.00 3 966.66666666666666667 NULL 833.33333333333333333 800.00 671.42857142857142857 1200.00
2924+
500.00 4 1050.00 NULL 966.66666666666666667 900.00 785.71428571428571429 NULL
2925+
700.00 5 1200.00 NULL 1050.00 1200.00 833.33333333333333333 NULL
2926+
700.00 5 1200.00 NULL 1050.00 1200.00 833.33333333333333333 NULL
2927+
700.00 5 1200.00 NULL 1050.00 1200.00 833.33333333333333333 NULL
2928+
800.00 6 NULL NULL 1200.00 NULL 966.66666666666666667 NULL
2929+
900.00 7 NULL NULL NULL NULL 1050.00 NULL
2930+
1200.00 8 NULL NULL NULL NULL 1200.00 NULL
2931+
2932+
query TTRRR
2933+
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
2937+
Smartphone Nexus 500.00 700.00 586.36363636363636364
2938+
Smartphone iPhone 900.00 900.00 586.36363636363636364
2939+
Laptop HP Elite 1200.00 1200.00 586.36363636363636364
2940+
Laptop Lenovo Thinkpad 700.00 850.00 586.36363636363636364
2941+
Laptop Sony VAIO 700.00 850.00 586.36363636363636364
2942+
Laptop Dell 800.00 1000.00 586.36363636363636364
2943+
Tablet iPad 700.00 700.00 586.36363636363636364
2944+
Tablet Kindle Fire 150.00 350.00 586.36363636363636364
2945+
Tablet Samsung 200.00 450.00 586.36363636363636364
2946+
2947+
query TTRRR
2948+
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
2949+
----
2950+
Smartphone Microsoft Lumia 200.00 NULL 200.00
2951+
Smartphone HTC One 400.00 NULL 400.00
2952+
Smartphone Nexus 500.00 NULL 500.00
2953+
Smartphone iPhone 900.00 NULL 900.00
2954+
Laptop HP Elite 1200.00 NULL 1200.00
2955+
Laptop Lenovo Thinkpad 700.00 NULL 700.00
2956+
Laptop Sony VAIO 700.00 NULL 700.00
2957+
Laptop Dell 800.00 NULL 800.00
2958+
Tablet iPad 700.00 NULL 700.00
2959+
Tablet Kindle Fire 150.00 NULL 150.00
2960+
Tablet Samsung 200.00 NULL 200.00

0 commit comments

Comments
 (0)