mirror of
https://github.com/postgres/postgres.git
synced 2025-07-26 01:22:12 +03:00
Support all SQL:2011 options for window frame clauses.
This patch adds the ability to use "RANGE offset PRECEDING/FOLLOWING" frame boundaries in window functions. We'd punted on that back in the original patch to add window functions, because it was not clear how to do it in a reasonably data-type-extensible fashion. That problem is resolved here by adding the ability for btree operator classes to provide an "in_range" support function that defines how to add or subtract the RANGE offset value. Factoring it this way also allows the operator class to avoid overflow problems near the ends of the datatype's range, if it wishes to expend effort on that. (In the committed patch, the integer opclasses handle that issue, but it did not seem worth the trouble to avoid overflow failures for datetime types.) The patch includes in_range support for the integer_ops opfamily (int2/int4/int8) as well as the standard datetime types. Support for other numeric types has been requested, but that seems like suitable material for a follow-on patch. In addition, the patch adds GROUPS mode which counts the offset in ORDER-BY peer groups rather than rows, and it adds the frame_exclusion options specified by SQL:2011. As far as I can see, we are now fully up to spec on window framing options. Existing behaviors remain unchanged, except that I changed the errcode for a couple of existing error reports to meet the SQL spec's expectation that negative "offset" values should be reported as SQLSTATE 22013. Internally and in relevant parts of the documentation, we now consistently use the terminology "offset PRECEDING/FOLLOWING" rather than "value PRECEDING/FOLLOWING", since the term "value" is confusingly vague. Oliver Ford, reviewed and whacked around some by me Discussion: https://postgr.es/m/CAGMVOdu9sivPAxbNN0X+q19Sfv9edEPv=HibOJhB14TJv_RCQg@mail.gmail.com
This commit is contained in:
@ -354,9 +354,9 @@ ERROR: invalid operator number 0, must be between 1 and 5
|
||||
ALTER OPERATOR FAMILY alt_opf4 USING btree ADD OPERATOR 1 < ; -- operator without argument types
|
||||
ERROR: operator argument types must be specified in ALTER OPERATOR FAMILY
|
||||
ALTER OPERATOR FAMILY alt_opf4 USING btree ADD FUNCTION 0 btint42cmp(int4, int2); -- function number should be between 1 and 5
|
||||
ERROR: invalid procedure number 0, must be between 1 and 2
|
||||
ERROR: invalid procedure number 0, must be between 1 and 3
|
||||
ALTER OPERATOR FAMILY alt_opf4 USING btree ADD FUNCTION 6 btint42cmp(int4, int2); -- function number should be between 1 and 5
|
||||
ERROR: invalid procedure number 6, must be between 1 and 2
|
||||
ERROR: invalid procedure number 6, must be between 1 and 3
|
||||
ALTER OPERATOR FAMILY alt_opf4 USING btree ADD STORAGE invalid_storage; -- Ensure STORAGE is not a part of ALTER OPERATOR FAMILY
|
||||
ERROR: STORAGE cannot be specified in ALTER OPERATOR FAMILY
|
||||
DROP OPERATOR FAMILY alt_opf4 USING btree;
|
||||
|
File diff suppressed because it is too large
Load Diff
@ -189,6 +189,46 @@ SELECT sum(unique1) over (rows between 2 preceding and 2 following),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (rows between 2 preceding and 2 following exclude no others),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (rows between 2 preceding and 2 following exclude current row),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (rows between 2 preceding and 2 following exclude group),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (rows between 2 preceding and 2 following exclude ties),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT first_value(unique1) over (ORDER BY four rows between current row and 2 following exclude current row),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT first_value(unique1) over (ORDER BY four rows between current row and 2 following exclude group),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT first_value(unique1) over (ORDER BY four rows between current row and 2 following exclude ties),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT last_value(unique1) over (ORDER BY four rows between current row and 2 following exclude current row),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT last_value(unique1) over (ORDER BY four rows between current row and 2 following exclude group),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT last_value(unique1) over (ORDER BY four rows between current row and 2 following exclude ties),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (rows between 2 preceding and 1 preceding),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
@ -205,10 +245,17 @@ SELECT sum(unique1) over (w range between current row and unbounded following),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10 WINDOW w AS (order by four);
|
||||
|
||||
-- fail: not implemented yet
|
||||
SELECT sum(unique1) over (order by four range between 2::int8 preceding and 1::int2 preceding),
|
||||
SELECT sum(unique1) over (w range between unbounded preceding and current row exclude current row),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
FROM tenk1 WHERE unique1 < 10 WINDOW w AS (order by four);
|
||||
|
||||
SELECT sum(unique1) over (w range between unbounded preceding and current row exclude group),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10 WINDOW w AS (order by four);
|
||||
|
||||
SELECT sum(unique1) over (w range between unbounded preceding and current row exclude ties),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10 WINDOW w AS (order by four);
|
||||
|
||||
SELECT first_value(unique1) over w,
|
||||
nth_value(unique1, 2) over w AS nth_2,
|
||||
@ -230,6 +277,449 @@ SELECT * FROM v_window;
|
||||
|
||||
SELECT pg_get_viewdef('v_window');
|
||||
|
||||
CREATE OR REPLACE TEMP VIEW v_window AS
|
||||
SELECT i, sum(i) over (order by i rows between 1 preceding and 1 following
|
||||
exclude current row) as sum_rows FROM generate_series(1, 10) i;
|
||||
|
||||
SELECT * FROM v_window;
|
||||
|
||||
SELECT pg_get_viewdef('v_window');
|
||||
|
||||
CREATE OR REPLACE TEMP VIEW v_window AS
|
||||
SELECT i, sum(i) over (order by i rows between 1 preceding and 1 following
|
||||
exclude group) as sum_rows FROM generate_series(1, 10) i;
|
||||
|
||||
SELECT * FROM v_window;
|
||||
|
||||
SELECT pg_get_viewdef('v_window');
|
||||
|
||||
CREATE OR REPLACE TEMP VIEW v_window AS
|
||||
SELECT i, sum(i) over (order by i rows between 1 preceding and 1 following
|
||||
exclude ties) as sum_rows FROM generate_series(1, 10) i;
|
||||
|
||||
SELECT * FROM v_window;
|
||||
|
||||
SELECT pg_get_viewdef('v_window');
|
||||
|
||||
CREATE OR REPLACE TEMP VIEW v_window AS
|
||||
SELECT i, sum(i) over (order by i rows between 1 preceding and 1 following
|
||||
exclude no others) as sum_rows FROM generate_series(1, 10) i;
|
||||
|
||||
SELECT * FROM v_window;
|
||||
|
||||
SELECT pg_get_viewdef('v_window');
|
||||
|
||||
CREATE OR REPLACE TEMP VIEW v_window AS
|
||||
SELECT i, sum(i) over (order by i groups between 1 preceding and 1 following) as sum_rows FROM generate_series(1, 10) i;
|
||||
|
||||
SELECT * FROM v_window;
|
||||
|
||||
SELECT pg_get_viewdef('v_window');
|
||||
|
||||
DROP VIEW v_window;
|
||||
|
||||
CREATE TEMP VIEW v_window AS
|
||||
SELECT i, min(i) over (order by i range between '1 day' preceding and '10 days' following) as min_i
|
||||
FROM generate_series(now(), now()+'100 days'::interval, '1 hour') i;
|
||||
|
||||
SELECT pg_get_viewdef('v_window');
|
||||
|
||||
-- RANGE offset PRECEDING/FOLLOWING tests
|
||||
|
||||
SELECT sum(unique1) over (order by four range between 2::int8 preceding and 1::int2 preceding),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four desc range between 2::int8 preceding and 1::int2 preceding),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four range between 2::int8 preceding and 1::int2 preceding exclude no others),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four range between 2::int8 preceding and 1::int2 preceding exclude current row),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four range between 2::int8 preceding and 1::int2 preceding exclude group),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four range between 2::int8 preceding and 1::int2 preceding exclude ties),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four range between 2::int8 preceding and 6::int2 following exclude ties),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four range between 2::int8 preceding and 6::int2 following exclude group),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (partition by four order by unique1 range between 5::int8 preceding and 6::int2 following),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (partition by four order by unique1 range between 5::int8 preceding and 6::int2 following
|
||||
exclude current row),unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
select sum(salary) over (order by enroll_date range between '1 year'::interval preceding and '1 year'::interval following),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
select sum(salary) over (order by enroll_date desc range between '1 year'::interval preceding and '1 year'::interval following),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
select sum(salary) over (order by enroll_date desc range between '1 year'::interval following and '1 year'::interval following),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
select sum(salary) over (order by enroll_date range between '1 year'::interval preceding and '1 year'::interval following
|
||||
exclude current row), salary, enroll_date from empsalary;
|
||||
|
||||
select sum(salary) over (order by enroll_date range between '1 year'::interval preceding and '1 year'::interval following
|
||||
exclude group), salary, enroll_date from empsalary;
|
||||
|
||||
select sum(salary) over (order by enroll_date range between '1 year'::interval preceding and '1 year'::interval following
|
||||
exclude ties), salary, enroll_date from empsalary;
|
||||
|
||||
select first_value(salary) over(order by salary range between 1000 preceding and 1000 following),
|
||||
lead(salary) over(order by salary range between 1000 preceding and 1000 following),
|
||||
nth_value(salary, 1) over(order by salary range between 1000 preceding and 1000 following),
|
||||
salary from empsalary;
|
||||
|
||||
select last_value(salary) over(order by salary range between 1000 preceding and 1000 following),
|
||||
lag(salary) over(order by salary range between 1000 preceding and 1000 following),
|
||||
salary from empsalary;
|
||||
|
||||
select first_value(salary) over(order by salary range between 1000 following and 3000 following
|
||||
exclude current row),
|
||||
lead(salary) over(order by salary range between 1000 following and 3000 following exclude ties),
|
||||
nth_value(salary, 1) over(order by salary range between 1000 following and 3000 following
|
||||
exclude ties),
|
||||
salary from empsalary;
|
||||
|
||||
select last_value(salary) over(order by salary range between 1000 following and 3000 following
|
||||
exclude group),
|
||||
lag(salary) over(order by salary range between 1000 following and 3000 following exclude group),
|
||||
salary from empsalary;
|
||||
|
||||
select first_value(salary) over(order by enroll_date range between unbounded preceding and '1 year'::interval following
|
||||
exclude ties),
|
||||
last_value(salary) over(order by enroll_date range between unbounded preceding and '1 year'::interval following),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
select first_value(salary) over(order by enroll_date range between unbounded preceding and '1 year'::interval following
|
||||
exclude ties),
|
||||
last_value(salary) over(order by enroll_date range between unbounded preceding and '1 year'::interval following
|
||||
exclude ties),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
select first_value(salary) over(order by enroll_date range between unbounded preceding and '1 year'::interval following
|
||||
exclude group),
|
||||
last_value(salary) over(order by enroll_date range between unbounded preceding and '1 year'::interval following
|
||||
exclude group),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
select first_value(salary) over(order by enroll_date range between unbounded preceding and '1 year'::interval following
|
||||
exclude current row),
|
||||
last_value(salary) over(order by enroll_date range between unbounded preceding and '1 year'::interval following
|
||||
exclude current row),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
-- RANGE offset PRECEDING/FOLLOWING with null values
|
||||
select x, y,
|
||||
first_value(y) over w,
|
||||
last_value(y) over w
|
||||
from
|
||||
(select x, x as y from generate_series(1,5) as x
|
||||
union all select null, 42
|
||||
union all select null, 43) ss
|
||||
window w as
|
||||
(order by x asc nulls first range between 2 preceding and 2 following);
|
||||
|
||||
select x, y,
|
||||
first_value(y) over w,
|
||||
last_value(y) over w
|
||||
from
|
||||
(select x, x as y from generate_series(1,5) as x
|
||||
union all select null, 42
|
||||
union all select null, 43) ss
|
||||
window w as
|
||||
(order by x asc nulls last range between 2 preceding and 2 following);
|
||||
|
||||
select x, y,
|
||||
first_value(y) over w,
|
||||
last_value(y) over w
|
||||
from
|
||||
(select x, x as y from generate_series(1,5) as x
|
||||
union all select null, 42
|
||||
union all select null, 43) ss
|
||||
window w as
|
||||
(order by x desc nulls first range between 2 preceding and 2 following);
|
||||
|
||||
select x, y,
|
||||
first_value(y) over w,
|
||||
last_value(y) over w
|
||||
from
|
||||
(select x, x as y from generate_series(1,5) as x
|
||||
union all select null, 42
|
||||
union all select null, 43) ss
|
||||
window w as
|
||||
(order by x desc nulls last range between 2 preceding and 2 following);
|
||||
|
||||
-- Check overflow behavior for various integer sizes
|
||||
|
||||
select x, last_value(x) over (order by x::smallint range between current row and 2147450884 following)
|
||||
from generate_series(32764, 32766) x;
|
||||
|
||||
select x, last_value(x) over (order by x::smallint desc range between current row and 2147450885 following)
|
||||
from generate_series(-32766, -32764) x;
|
||||
|
||||
select x, last_value(x) over (order by x range between current row and 4 following)
|
||||
from generate_series(2147483644, 2147483646) x;
|
||||
|
||||
select x, last_value(x) over (order by x desc range between current row and 5 following)
|
||||
from generate_series(-2147483646, -2147483644) x;
|
||||
|
||||
select x, last_value(x) over (order by x range between current row and 4 following)
|
||||
from generate_series(9223372036854775804, 9223372036854775806) x;
|
||||
|
||||
select x, last_value(x) over (order by x desc range between current row and 5 following)
|
||||
from generate_series(-9223372036854775806, -9223372036854775804) x;
|
||||
|
||||
-- Test in_range for other datetime datatypes
|
||||
|
||||
create temp table datetimes(
|
||||
id int,
|
||||
f_time time,
|
||||
f_timetz timetz,
|
||||
f_interval interval,
|
||||
f_timestamptz timestamptz,
|
||||
f_timestamp timestamp
|
||||
);
|
||||
|
||||
insert into datetimes values
|
||||
(1, '11:00', '11:00 BST', '1 year', '2000-10-19 10:23:54+01', '2000-10-19 10:23:54'),
|
||||
(2, '12:00', '12:00 BST', '2 years', '2001-10-19 10:23:54+01', '2001-10-19 10:23:54'),
|
||||
(3, '13:00', '13:00 BST', '3 years', '2001-10-19 10:23:54+01', '2001-10-19 10:23:54'),
|
||||
(4, '14:00', '14:00 BST', '4 years', '2002-10-19 10:23:54+01', '2002-10-19 10:23:54'),
|
||||
(5, '15:00', '15:00 BST', '5 years', '2003-10-19 10:23:54+01', '2003-10-19 10:23:54'),
|
||||
(6, '15:00', '15:00 BST', '5 years', '2004-10-19 10:23:54+01', '2004-10-19 10:23:54'),
|
||||
(7, '17:00', '17:00 BST', '7 years', '2005-10-19 10:23:54+01', '2005-10-19 10:23:54'),
|
||||
(8, '18:00', '18:00 BST', '8 years', '2006-10-19 10:23:54+01', '2006-10-19 10:23:54'),
|
||||
(9, '19:00', '19:00 BST', '9 years', '2007-10-19 10:23:54+01', '2007-10-19 10:23:54'),
|
||||
(10, '20:00', '20:00 BST', '10 years', '2008-10-19 10:23:54+01', '2008-10-19 10:23:54');
|
||||
|
||||
select id, f_time, first_value(id) over w, last_value(id) over w
|
||||
from datetimes
|
||||
window w as (order by f_time range between
|
||||
'70 min'::interval preceding and '2 hours'::interval following);
|
||||
|
||||
select id, f_time, first_value(id) over w, last_value(id) over w
|
||||
from datetimes
|
||||
window w as (order by f_time desc range between
|
||||
'70 min' preceding and '2 hours' following);
|
||||
|
||||
select id, f_timetz, first_value(id) over w, last_value(id) over w
|
||||
from datetimes
|
||||
window w as (order by f_timetz range between
|
||||
'70 min'::interval preceding and '2 hours'::interval following);
|
||||
|
||||
select id, f_timetz, first_value(id) over w, last_value(id) over w
|
||||
from datetimes
|
||||
window w as (order by f_timetz desc range between
|
||||
'70 min' preceding and '2 hours' following);
|
||||
|
||||
select id, f_interval, first_value(id) over w, last_value(id) over w
|
||||
from datetimes
|
||||
window w as (order by f_interval range between
|
||||
'1 year'::interval preceding and '1 year'::interval following);
|
||||
|
||||
select id, f_interval, first_value(id) over w, last_value(id) over w
|
||||
from datetimes
|
||||
window w as (order by f_interval desc range between
|
||||
'1 year' preceding and '1 year' following);
|
||||
|
||||
select id, f_timestamptz, first_value(id) over w, last_value(id) over w
|
||||
from datetimes
|
||||
window w as (order by f_timestamptz range between
|
||||
'1 year'::interval preceding and '1 year'::interval following);
|
||||
|
||||
select id, f_timestamptz, first_value(id) over w, last_value(id) over w
|
||||
from datetimes
|
||||
window w as (order by f_timestamptz desc range between
|
||||
'1 year' preceding and '1 year' following);
|
||||
|
||||
select id, f_timestamp, first_value(id) over w, last_value(id) over w
|
||||
from datetimes
|
||||
window w as (order by f_timestamp range between
|
||||
'1 year'::interval preceding and '1 year'::interval following);
|
||||
|
||||
select id, f_timestamp, first_value(id) over w, last_value(id) over w
|
||||
from datetimes
|
||||
window w as (order by f_timestamp desc range between
|
||||
'1 year' preceding and '1 year' following);
|
||||
|
||||
-- RANGE offset PRECEDING/FOLLOWING error cases
|
||||
select sum(salary) over (order by enroll_date, salary range between '1 year'::interval preceding and '2 years'::interval following
|
||||
exclude ties), salary, enroll_date from empsalary;
|
||||
|
||||
select sum(salary) over (range between '1 year'::interval preceding and '2 years'::interval following
|
||||
exclude ties), salary, enroll_date from empsalary;
|
||||
|
||||
select sum(salary) over (order by depname range between '1 year'::interval preceding and '2 years'::interval following
|
||||
exclude ties), salary, enroll_date from empsalary;
|
||||
|
||||
select max(enroll_date) over (order by enroll_date range between 1 preceding and 2 following
|
||||
exclude ties), salary, enroll_date from empsalary;
|
||||
|
||||
select max(enroll_date) over (order by salary range between -1 preceding and 2 following
|
||||
exclude ties), salary, enroll_date from empsalary;
|
||||
|
||||
select max(enroll_date) over (order by salary range between 1 preceding and -2 following
|
||||
exclude ties), salary, enroll_date from empsalary;
|
||||
|
||||
select max(enroll_date) over (order by salary range between '1 year'::interval preceding and '2 years'::interval following
|
||||
exclude ties), salary, enroll_date from empsalary;
|
||||
|
||||
select max(enroll_date) over (order by enroll_date range between '1 year'::interval preceding and '-2 years'::interval following
|
||||
exclude ties), salary, enroll_date from empsalary;
|
||||
|
||||
-- GROUPS tests
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between unbounded preceding and current row),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between unbounded preceding and unbounded following),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between current row and unbounded following),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between 1 preceding and unbounded following),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between 1 following and unbounded following),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between unbounded preceding and 2 following),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between 2 preceding and 1 preceding),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between 2 preceding and 1 following),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between 0 preceding and 0 following),
|
||||
unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between 2 preceding and 1 following
|
||||
exclude current row), unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between 2 preceding and 1 following
|
||||
exclude group), unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (order by four groups between 2 preceding and 1 following
|
||||
exclude ties), unique1, four
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (partition by ten
|
||||
order by four groups between 0 preceding and 0 following),unique1, four, ten
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (partition by ten
|
||||
order by four groups between 0 preceding and 0 following exclude current row), unique1, four, ten
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (partition by ten
|
||||
order by four groups between 0 preceding and 0 following exclude group), unique1, four, ten
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
SELECT sum(unique1) over (partition by ten
|
||||
order by four groups between 0 preceding and 0 following exclude ties), unique1, four, ten
|
||||
FROM tenk1 WHERE unique1 < 10;
|
||||
|
||||
select first_value(salary) over(order by enroll_date groups between 1 preceding and 1 following),
|
||||
lead(salary) over(order by enroll_date groups between 1 preceding and 1 following),
|
||||
nth_value(salary, 1) over(order by enroll_date groups between 1 preceding and 1 following),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
select last_value(salary) over(order by enroll_date groups between 1 preceding and 1 following),
|
||||
lag(salary) over(order by enroll_date groups between 1 preceding and 1 following),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
select first_value(salary) over(order by enroll_date groups between 1 following and 3 following
|
||||
exclude current row),
|
||||
lead(salary) over(order by enroll_date groups between 1 following and 3 following exclude ties),
|
||||
nth_value(salary, 1) over(order by enroll_date groups between 1 following and 3 following
|
||||
exclude ties),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
select last_value(salary) over(order by enroll_date groups between 1 following and 3 following
|
||||
exclude group),
|
||||
lag(salary) over(order by enroll_date groups between 1 following and 3 following exclude group),
|
||||
salary, enroll_date from empsalary;
|
||||
|
||||
-- Show differences in offset interpretation between ROWS, RANGE, and GROUPS
|
||||
WITH cte (x) AS (
|
||||
SELECT * FROM generate_series(1, 35, 2)
|
||||
)
|
||||
SELECT x, (sum(x) over w)
|
||||
FROM cte
|
||||
WINDOW w AS (ORDER BY x rows between 1 preceding and 1 following);
|
||||
|
||||
WITH cte (x) AS (
|
||||
SELECT * FROM generate_series(1, 35, 2)
|
||||
)
|
||||
SELECT x, (sum(x) over w)
|
||||
FROM cte
|
||||
WINDOW w AS (ORDER BY x range between 1 preceding and 1 following);
|
||||
|
||||
WITH cte (x) AS (
|
||||
SELECT * FROM generate_series(1, 35, 2)
|
||||
)
|
||||
SELECT x, (sum(x) over w)
|
||||
FROM cte
|
||||
WINDOW w AS (ORDER BY x groups between 1 preceding and 1 following);
|
||||
|
||||
WITH cte (x) AS (
|
||||
select 1 union all select 1 union all select 1 union all
|
||||
SELECT * FROM generate_series(5, 49, 2)
|
||||
)
|
||||
SELECT x, (sum(x) over w)
|
||||
FROM cte
|
||||
WINDOW w AS (ORDER BY x rows between 1 preceding and 1 following);
|
||||
|
||||
WITH cte (x) AS (
|
||||
select 1 union all select 1 union all select 1 union all
|
||||
SELECT * FROM generate_series(5, 49, 2)
|
||||
)
|
||||
SELECT x, (sum(x) over w)
|
||||
FROM cte
|
||||
WINDOW w AS (ORDER BY x range between 1 preceding and 1 following);
|
||||
|
||||
WITH cte (x) AS (
|
||||
select 1 union all select 1 union all select 1 union all
|
||||
SELECT * FROM generate_series(5, 49, 2)
|
||||
)
|
||||
SELECT x, (sum(x) over w)
|
||||
FROM cte
|
||||
WINDOW w AS (ORDER BY x groups between 1 preceding and 1 following);
|
||||
|
||||
-- with UNION
|
||||
SELECT count(*) OVER (PARTITION BY four) FROM (SELECT * FROM tenk1 UNION ALL SELECT * FROM tenk2)s LIMIT 0;
|
||||
|
||||
|
Reference in New Issue
Block a user