Skip to content

Commit d869b6b

Browse files
21c window function enhancements (#47)
1 parent 4068215 commit d869b6b

File tree

4 files changed

+259
-0
lines changed

4 files changed

+259
-0
lines changed

features/_versions/21.3.adoc

Lines changed: 12 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,12 @@
1+
= 21.3
2+
3+
Oracle Database 21c was first released in August 2021.
4+
5+
== Marquee Features
6+
7+
* JSON Data Type
8+
* Blockchain Tables
9+
* SQL Macros
10+
* Enhanced Analytic Functions
11+
12+
For more information about all the new features in this release, see link:https://docs.oracle.com/en/database/oracle/oracle-database/21/nfcon/introduction.html[Oracle Database 21c New Features].

features/window-clause.adoc

Lines changed: 92 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,92 @@
1+
= WINDOW clause
2+
:database-version: 21.3
3+
:database-category: sql
4+
5+
[[feature_summary]]
6+
7+
The `WINDOW` clause enables you to define `PARTITION BY`, `ORDER BY`, and window frames for analytic functions. You can use these named windows in the `OVER` clause of functions in the `SELECT` clause.
8+
9+
[source,sql]
10+
[subs="verbatim"]
11+
----
12+
alter session set nls_date_format = 'DD-MON-YYYY';
13+
14+
select employee_id,
15+
department_id, salary,
16+
-- these calculate totals per department
17+
count (*) over ( dept_w ) emps_per_dept,
18+
sum ( salary ) over ( dept_w ) wages_per_dept,
19+
hire_date,
20+
-- this gets the running total of salaries/dept in order they were hired
21+
sum ( salary ) over ( hired_w ) cumul_sal,
22+
-- this gets the moving average of salaries for the last four hires/dept
23+
round ( avg ( salary ) over last_four ) rolling_mean
24+
from hr.employees
25+
where department_id < 50
26+
window dept_w as (
27+
-- split by department
28+
partition by department_id
29+
), hired_w as (
30+
-- sort by date hired
31+
dept_w order by hire_date
32+
), last_four as (
33+
-- include the previous three rows & current
34+
hired_w rows 3 preceding
35+
);
36+
----
37+
38+
.Result
39+
[source,sql]
40+
[subs="verbatim"]
41+
----
42+
SQL> alter session set nls_date_format = 'DD-MON-YYYY';
43+
44+
Session altered.
45+
46+
SQL> select employee_id,
47+
2 department_id, salary,
48+
3 -- these calculate totals per department
49+
4 count (*) over ( dept_w ) emps_per_dept,
50+
5 sum ( salary ) over ( dept_w ) wages_per_dept,
51+
6 hire_date,
52+
7 -- this gets the running total of salaries/dept in order they were hired
53+
8 sum ( salary ) over ( hired_w ) cumul_sal,
54+
9 -- this gets the moving average of salaries for the last four hires/dept
55+
10 round ( avg ( salary ) over last_four ) rolling_mean
56+
11 from hr.employees
57+
12 where department_id < 50
58+
13 window dept_w as (
59+
14 -- split by department
60+
15 partition by department_id
61+
16 ), hired_w as (
62+
17 -- sort by date hired
63+
18 dept_w order by hire_date
64+
19 ), last_four as (
65+
20 -- include the previous three rows & current
66+
21 hired_w rows 3 preceding
67+
22 );
68+
69+
EMPLOYEE_ID DEPARTMENT_ID SALARY EMPS_PER_DEPT WAGES_PER_DEPT HIRE_DATE CUMUL_SAL ROLLING_MEAN
70+
----------- ------------- ---------- ------------- -------------- ----------- ---------- ------------
71+
200 10 4400 1 4400 17-SEP-2013 4400 4400
72+
201 20 13000 2 19000 17-FEB-2014 13000 13000
73+
202 20 6000 2 19000 17-AUG-2015 19000 9500
74+
114 30 11000 6 24900 07-DEC-2012 11000 11000
75+
115 30 3100 6 24900 18-MAY-2013 14100 7050
76+
117 30 2800 6 24900 24-JUL-2015 16900 5633
77+
116 30 2900 6 24900 24-DEC-2015 19800 4950
78+
118 30 2600 6 24900 15-NOV-2016 22400 2850
79+
119 30 2500 6 24900 10-AUG-2017 24900 2700
80+
203 40 6500 1 6500 07-JUN-2012 6500 6500
81+
82+
10 rows selected.
83+
----
84+
85+
== Benefits
86+
87+
The `WINDOW` clause enables you to define common windows once and reuse them in a statement. This makes queries easier to maintain.
88+
89+
== Further information
90+
91+
* Availability: All Offerings
92+
* https://docs.oracle.com/en/database/oracle/oracle-database/21/dwhsg/sql-analysis-reporting-data-warehouses.html#GUID-2877E1A5-9F11-47F1-A5ED-D7D5C7DED90A[Documentation]
Lines changed: 88 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,88 @@
1+
= Window functions frame exclusion
2+
:database-version: 21.3
3+
:database-category: sql
4+
5+
[[feature_summary]]
6+
7+
Use frame exclusion to omit rows from the calculation in window functions. This has four options:
8+
9+
* `EXCLUDE CURRENT ROW` - remove the row being processed from the calculation.
10+
* `EXCLUDE GROUP` - omit all rows with the same value for the window's `ORDER BY` columns as the current row
11+
* `EXCLUDE TIES` - omit all other rows with the same value for the window's `ORDER BY` columns from the total as the current row, but include the current row
12+
* `EXCLUDE NO OTHERS` - Include all rows in the window in the calculation. This is the default.
13+
14+
[source,sql]
15+
[subs="verbatim"]
16+
----
17+
alter session set nls_date_format = 'DD-MON-YYYY';
18+
19+
select hire_date
20+
, count(*) over (
21+
-- include all previous rows; default
22+
hire_w rows unbounded preceding exclude no others
23+
) include_all
24+
, count(*) over (
25+
-- omit this row from the count
26+
hire_w rows unbounded preceding exclude current row
27+
) omit_current
28+
, count(*) over (
29+
-- omit all rows with the same value for hire_date as this
30+
hire_w rows unbounded preceding exclude group
31+
) omit_group
32+
, count(*) over (
33+
-- omit other rows with the same value for hire_date as this
34+
hire_w rows unbounded preceding exclude ties
35+
) omit_ties
36+
from hr.employees
37+
where hire_date >= date'2015-03-03'
38+
window hire_w as ( order by hire_date )
39+
fetch first 5 rows only;
40+
----
41+
42+
.Result
43+
[source,sql]
44+
[subs="verbatim"]
45+
----
46+
SQL> alter session set nls_date_format = 'DD-MON-YYYY';
47+
48+
Session altered.
49+
50+
SQL> select hire_date
51+
2 , count(*) over (
52+
3 -- include all previous rows; default
53+
4 hire_w rows unbounded preceding exclude no others
54+
5 ) include_all
55+
6 , count(*) over (
56+
7 -- omit this row from the count
57+
8 hire_w rows unbounded preceding exclude current row
58+
9 ) omit_current
59+
10 , count(*) over (
60+
11 -- omit all rows with the same value for hire_date as this
61+
12 hire_w rows unbounded preceding exclude group
62+
13 ) omit_group
63+
14 , count(*) over (
64+
15 -- omit other rows with the same value for hire_date as this
65+
16 hire_w rows unbounded preceding exclude ties
66+
17 ) omit_ties
67+
18 from hr.employees
68+
19 where hire_date >= date'2015-03-03'
69+
20 window hire_w as ( order by hire_date )
70+
21 fetch first 5 rows only;
71+
72+
HIRE_DATE INCLUDE_ALL OMIT_CURRENT OMIT_GROUP OMIT_TIES
73+
----------- ----------- ------------ ---------- ----------
74+
03-MAR-2015 1 0 0 1
75+
10-MAR-2015 2 1 1 2
76+
10-MAR-2015 3 2 1 2
77+
11-MAR-2015 4 3 3 4
78+
19-MAR-2015 5 4 4 5
79+
----
80+
81+
== Benefits
82+
83+
Frame exclusion simplifies SQL statements that need to remove rows from running total and moving window calculations
84+
85+
== Further information
86+
87+
* Availability: All Offerings
88+
* https://docs.oracle.com/en/database/oracle/oracle-database/21/dwhsg/sql-analysis-reporting-data-warehouses.html#GUID-2877E1A5-9F11-47F1-A5ED-D7D5C7DED90A[Documentation]
Lines changed: 67 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,67 @@
1+
= Window functions GROUPS frame
2+
:database-version: 21.3
3+
:database-category: sql
4+
5+
[[feature_summary]]
6+
7+
The `GROUPS` frame enables you to get running totals over the previous N sort values in window functions.
8+
9+
This in addition to the existing `ROWS` and `RANGE` frames. The differences between these are:
10+
11+
* `ROWS :N PRECEDING` - include the current row and up to N rows before it
12+
* `RANGE :N PRECEDING` - include all rows between _current_ - N and _current_; _current_ is the value of the `ORDER BY` column for the row the function is processing
13+
* `GROUPS :N PRECEDING` - include all rows with the same value and previous N unique values for the columns in the window's `ORDER BY`
14+
15+
[source,sql]
16+
[subs="verbatim"]
17+
----
18+
alter session set nls_date_format = 'DD-MON-YYYY';
19+
20+
select hire_date
21+
-- include current & three previous rows
22+
, count(*) over ( order by hire_date rows 3 preceding ) prev3_rows
23+
-- include all rows between hire_date - 3 and hire_date for the current row
24+
, count(*) over ( order by hire_date range 3 preceding ) prev3_days
25+
-- include all rows with the any of the previous three and current hire_dates
26+
, count(*) over ( order by hire_date groups 3 preceding ) prev3_values
27+
from hr.employees
28+
where hire_date >= date'2015-03-03'
29+
fetch first 5 rows only;
30+
----
31+
32+
.Result
33+
[source,sql]
34+
[subs="verbatim"]
35+
----
36+
SQL> alter session set nls_date_format = 'DD-MON-YYYY';
37+
38+
Session altered.
39+
40+
SQL> select hire_date
41+
2 -- include current & three previous rows
42+
3 , count(*) over ( order by hire_date rows 3 preceding ) prev3_rows
43+
4 -- include all rows between hire_date - 3 and hire_date for the current row
44+
5 , count(*) over ( order by hire_date range 3 preceding ) prev3_days
45+
6 -- include all rows with the any of the previous three and current hire_dates
46+
7 , count(*) over ( order by hire_date groups 3 preceding ) prev3_values
47+
8 from hr.employees
48+
9 where hire_date >= date'2015-03-03'
49+
10 fetch first 5 rows only;
50+
51+
HIRE_DATE PREV3_ROWS PREV3_DAYS PREV3_VALUES
52+
----------- ---------- ---------- ------------
53+
03-MAR-2015 1 1 1
54+
10-MAR-2015 2 2 3
55+
10-MAR-2015 3 2 3
56+
11-MAR-2015 4 3 4
57+
19-MAR-2015 4 1 5
58+
----
59+
60+
== Benefits
61+
62+
The `GROUPS` frame simplifies SQL statements that need to calculate running totals over the previous N unique values.
63+
64+
== Further information
65+
66+
* Availability: All Offerings
67+
* https://docs.oracle.com/en/database/oracle/oracle-database/21/dwhsg/sql-analysis-reporting-data-warehouses.html#GUID-2877E1A5-9F11-47F1-A5ED-D7D5C7DED90A[Documentation]

0 commit comments

Comments
 (0)