3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
6 # May you do good and not evil.
7 # May you find forgiveness for yourself and forgive others.
8 # May you share freely, never taking more than you give.
10 #***********************************************************************
13 source [file join [file dirname
$argv0] pg_common.tcl
]
15 #=========================================================================
17 start_test window4
"2018 June 04"
21 DROP TABLE IF EXISTS t3
;
22 CREATE TABLE t3
(a TEXT PRIMARY KEY
);
23 INSERT INTO t3 VALUES
('a'
), ('b'
), ('c'
), ('d'
), ('e'
);
24 INSERT INTO t3 VALUES
('f'
), ('g'
), ('h'
), ('i'
), ('j'
);
27 for {set i
1} {$i < 20} {incr i
} {
28 execsql_test
1.
$i "SELECT a, ntile($i) OVER (ORDER BY a) FROM t3"
32 DROP TABLE IF EXISTS t4
;
33 CREATE TABLE t4
(a INTEGER PRIMARY KEY
, b TEXT
, c INTEGER
);
34 INSERT INTO t4 VALUES
(1, 'A'
, 9);
35 INSERT INTO t4 VALUES
(2, 'B'
, 3);
36 INSERT INTO t4 VALUES
(3, 'C'
, 2);
37 INSERT INTO t4 VALUES
(4, 'D'
, 10);
38 INSERT INTO t4 VALUES
(5, 'E'
, 5);
39 INSERT INTO t4 VALUES
(6, 'F'
, 1);
40 INSERT INTO t4 VALUES
(7, 'G'
, 1);
41 INSERT INTO t4 VALUES
(8, 'H'
, 2);
42 INSERT INTO t4 VALUES
(9, 'I'
, 10);
43 INSERT INTO t4 VALUES
(10, 'J'
, 4);
47 SELECT a
, nth_value
(b
, c
) OVER
(ORDER BY a
) FROM t4
51 SELECT a
, lead
(b
) OVER
(ORDER BY a
) FROM t4
54 SELECT a
, lead
(b
, 2) OVER
(ORDER BY a
) FROM t4
57 SELECT a
, lead
(b
, 3, 'abc'
) OVER
(ORDER BY a
) FROM t4
61 SELECT a
, lag
(b
) OVER
(ORDER BY a
) FROM t4
64 SELECT a
, lag
(b
, 2) OVER
(ORDER BY a
) FROM t4
67 SELECT a
, lag
(b
, 3, 'abc'
) OVER
(ORDER BY a
) FROM t4
71 SELECT string_agg
(b
, '.'
) OVER
(
72 ORDER BY a ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
77 DROP TABLE IF EXISTS t5
;
78 CREATE TABLE t5
(a INTEGER PRIMARY KEY
, b TEXT
, c TEXT
, d INTEGER
);
79 INSERT INTO t5 VALUES
(1, 'A'
, 'one'
, 5);
80 INSERT INTO t5 VALUES
(2, 'B'
, 'two'
, 4);
81 INSERT INTO t5 VALUES
(3, 'A'
, 'three'
, 3);
82 INSERT INTO t5 VALUES
(4, 'B'
, 'four'
, 2);
83 INSERT INTO t5 VALUES
(5, 'A'
, 'five'
, 1);
87 SELECT a
, nth_value
(c
, d
) OVER
(ORDER BY b
) FROM t5
91 SELECT a
, nth_value
(c
, d
) OVER
(PARTITION BY b ORDER BY a
) FROM t5
95 SELECT a
, count
(*) OVER abc
, count
(*) OVER def FROM t5
96 WINDOW abc AS
(ORDER BY a
),
97 def AS
(ORDER BY a DESC
)
102 SELECT a
, max
(a
) FILTER
(WHERE
(a
%2)=0) OVER w FROM t5
103 WINDOW w AS
(ORDER BY a
)
107 SELECT a
, max
(c
) OVER
(ORDER BY a ROWS BETWEEN
1 PRECEDING AND
2 PRECEDING
)
111 SELECT a
, max
(c
) OVER
(ORDER BY a ROWS BETWEEN
1 PRECEDING AND
1 PRECEDING
)
115 SELECT a
, max
(c
) OVER
(ORDER BY a ROWS BETWEEN
0 PRECEDING AND
0 PRECEDING
)
120 SELECT a
, max
(c
) OVER
(ORDER BY a ROWS BETWEEN
2 FOLLOWING AND
1 FOLLOWING
)
124 SELECT a
, max
(c
) OVER
(ORDER BY a ROWS BETWEEN
1 FOLLOWING AND
1 FOLLOWING
)
128 SELECT a
, max
(c
) OVER
(ORDER BY a ROWS BETWEEN
0 FOLLOWING AND
0 FOLLOWING
)
135 DROP TABLE IF EXISTS ttt
;
136 CREATE TABLE ttt
(a INTEGER PRIMARY KEY
, b INTEGER
, c INTEGER
);
137 INSERT INTO ttt VALUES
(1, 1, 1);
138 INSERT INTO ttt VALUES
(2, 2, 2);
139 INSERT INTO ttt VALUES
(3, 3, 3);
141 INSERT INTO ttt VALUES
(4, 1, 2);
142 INSERT INTO ttt VALUES
(5, 2, 3);
143 INSERT INTO ttt VALUES
(6, 3, 4);
145 INSERT INTO ttt VALUES
(7, 1, 3);
146 INSERT INTO ttt VALUES
(8, 2, 4);
147 INSERT INTO ttt VALUES
(9, 3, 5);
151 SELECT max
(c
), max
(b
) OVER
(ORDER BY b
) FROM ttt GROUP BY b
;
155 SELECT max
(b
) OVER
(ORDER BY max
(c
)) FROM ttt GROUP BY b
;
159 SELECT abs
(max
(b
) OVER
(ORDER BY b
)) FROM ttt GROUP BY b
;
164 ORDER BY a RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
168 set lPart
[list "PARTITION BY b" "PARTITION BY b, a" "" "PARTITION BY a"]
169 set lOrder
[list "ORDER BY a" "ORDER BY a DESC" "" "ORDER BY b, a"]
171 "RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW"
172 "RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING"
173 "RANGE BETWEEN CURRENT ROW AND CURRENT ROW"
174 "RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING"
178 "ROWS BETWEEN 3 PRECEDING AND 1 FOLLOWING"
179 "ROWS BETWEEN 3 PRECEDING AND 2 FOLLOWING"
180 "ROWS BETWEEN 1 PRECEDING AND 1 PRECEDING"
181 "ROWS BETWEEN 0 PRECEDING AND 1 PRECEDING"
182 "ROWS BETWEEN 1 FOLLOWING AND 500 FOLLOWING"
187 SELECT max
(c
) OVER
($p1 $o1 $r1),
188 min
(c
) OVER
($p2 $o2 $r2)
192 SELECT sum
(c
) OVER
($p1 $o1 $r1),
193 sum
(c
) OVER
($p2 $o2 $r2)
197 set o1
[lindex $lOrder 0]
198 set o2
[lindex $lOrder 0]
199 set r1
[lindex $lRange 0]
200 set r2
[lindex $lRange 0]
201 foreach p1
$lPart { foreach p2
$lPart {
202 execsql_test
4.5.
$tn.1 [subst $SQL]
203 execsql_test
4.5.
$tn.2 [subst $SQL2]
207 set o1
[lindex $lOrder 0]
208 set o2
[lindex $lOrder 0]
209 set p1
[lindex $lPart 0]
210 set p2
[lindex $lPart 0]
211 foreach r1
$lRange { foreach r2
$lRange {
212 execsql_test
4.5.
$tn.1 [subst $SQL]
213 execsql_test
4.5.
$tn.2 [subst $SQL2]
216 foreach r1
$lRows { foreach r2
$lRows {
217 execsql_test
4.5.
$tn.1 [subst $SQL]
218 execsql_test
4.5.
$tn.2 [subst $SQL2]
222 set r1
[lindex $lRange 0]
223 set r2
[lindex $lRange 0]
224 set p1
[lindex $lPart 0]
225 set p2
[lindex $lPart 0]
226 foreach o1
$lOrder { foreach o2
$lOrder {
227 execsql_test
4.5.
$tn.1 [subst $SQL]
228 execsql_test
4.5.
$tn.2 [subst $SQL2]
235 DROP TABLE IF EXISTS t1
;
236 CREATE TABLE t1
(x INTEGER
, y INTEGER
);
237 INSERT INTO t1 VALUES
(1, 2);
238 INSERT INTO t1 VALUES
(3, 4);
239 INSERT INTO t1 VALUES
(5, 6);
240 INSERT INTO t1 VALUES
(7, 8);
241 INSERT INTO t1 VALUES
(9, 10);
245 SELECT lead
(y
) OVER win FROM t1
246 WINDOW win AS
(ORDER BY x
)
250 SELECT lead
(y
, 2) OVER win FROM t1
251 WINDOW win AS
(ORDER BY x
)
255 SELECT lead
(y
, 3, -1) OVER win FROM t1
256 WINDOW win AS
(ORDER BY x
)
261 lead
(y
) OVER win
, lead
(y
) OVER win
263 WINDOW win AS
(ORDER BY x
)
270 lead
(y
, 3, -1) OVER win
272 WINDOW win AS
(ORDER BY x
)
278 DROP TABLE IF EXISTS t1
;
279 CREATE TABLE t1
(a INTEGER
, b INTEGER
, c INTEGER
, d INTEGER
);
280 INSERT INTO t1 VALUES
(1, 2, 3, 4);
281 INSERT INTO t1 VALUES
(5, 6, 7, 8);
282 INSERT INTO t1 VALUES
(9, 10, 11, 12);
286 SELECT row_number
() OVER win
,
287 nth_value
(d
,2) OVER win
,
290 WINDOW win AS
(ORDER BY a
)
294 SELECT row_number
() OVER win
,
296 dense_rank
() OVER win
,
298 first_value
(d
) OVER win
,
299 last_value
(d
) OVER win
,
300 nth_value
(d
,2) OVER win
,
306 WINDOW win AS
(ORDER BY a
)
312 DROP TABLE IF EXISTS t2
;
313 CREATE TABLE t2
(x INTEGER
);
314 INSERT INTO t2 VALUES
(1), (1), (1), (4), (4), (6), (7);
318 SELECT rank
() OVER
() FROM t2
321 SELECT dense_rank
() OVER
(PARTITION BY x
) FROM t2
323 execsql_float_test
9.3 {
324 SELECT x
, percent_rank
() OVER
(PARTITION BY x ORDER BY x
) FROM t2
328 SELECT x
, rank
() OVER
(ORDER BY x
) FROM t2 ORDER BY
1,2
332 SELECT DISTINCT x
, rank
() OVER
(ORDER BY x
) FROM t2 ORDER BY
1,2
335 execsql_float_test
9.6 {
336 SELECT percent_rank
() OVER
() FROM t1
339 execsql_float_test
9.7 {
340 SELECT cume_dist
() OVER
() FROM t1
344 DROP TABLE IF EXISTS t7
;
345 CREATE TABLE t7
(id INTEGER PRIMARY KEY
, a INTEGER
, b INTEGER
);
346 INSERT INTO t7
(id
, a
, b
) VALUES
347 (1, 1, 2), (2, 1, NULL
), (3, 1, 4),
348 (4, 3, NULL
), (5, 3, 8), (6, 3, 1);
351 SELECT id
, min
(b
) OVER
(PARTITION BY a ORDER BY id
) FROM t7
;
355 SELECT id
, lead
(b
, -1) OVER
(PARTITION BY a ORDER BY id
) FROM t7
;
358 SELECT id
, lag
(b
, -1) OVER
(PARTITION BY a ORDER BY id
) FROM t7
;