Skip to content

Commit 4068215

Browse files
Merge pull request #45 from oracle-sql-features/issue-41
add row_limiting_clause with examples
2 parents ef61d73 + 48f20db commit 4068215

File tree

1 file changed

+267
-0
lines changed

1 file changed

+267
-0
lines changed
Lines changed: 267 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,267 @@
1+
= Native SQL Support for Query Row Limits and Row Offsets
2+
:database-version: 12.1.0.1
3+
:database-category: SQL
4+
5+
[[feature_summary]]
6+
7+
Many SQL queries benefit from limiting the result set to the top-_n_, or first _n_ rows.
8+
9+
Before Oracle 12c Release 1 limiting the result set required the use of sub-selects and the rownum pseudo-column and inline views as you can see in the first examples. When Oracle Database 12c introduced support for the https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/SELECT.html#GUID-CFA006CA-6FF1-4972-821E-6996142A51C6__BABBADDD[row limiting clause] selecting the first _n_ rows from a result set, or paging through a result set were significantly improved.
10+
11+
[source,sql]
12+
[subs="verbatim"]
13+
----
14+
/*
15+
Displaying the top 10 customers by sales using the pre-
16+
Oracle Database 12c syntax
17+
*/
18+
SELECT
19+
*
20+
FROM
21+
(
22+
SELECT
23+
SUM(quantity_sold * amount_sold) AS revenue,
24+
cust_id
25+
FROM
26+
sales
27+
GROUP BY
28+
cust_id
29+
ORDER BY
30+
SUM(quantity_sold * amount_sold) DESC
31+
)
32+
WHERE
33+
ROWNUM < 11;
34+
35+
/*
36+
Iterating over the result set, displaying 10 customers each using the pre-
37+
Oracle Database 12c syntax. You typically find this type of query in reports
38+
where batches of rows are displayed on screen. The following query retrieves
39+
rows n to m (say, 10 to 20) from the result set.
40+
*/
41+
VAR n NUMBER
42+
VAR m NUMBER
43+
BEGIN
44+
:n := 10;
45+
:m := 20;
46+
END;
47+
/
48+
49+
SELECT
50+
*
51+
FROM
52+
(
53+
SELECT
54+
a.*,
55+
ROWNUM rn
56+
FROM
57+
(
58+
SELECT
59+
SUM(quantity_sold * amount_sold) AS revenue,
60+
cust_id
61+
FROM
62+
sales
63+
GROUP BY
64+
cust_id
65+
ORDER BY
66+
SUM(quantity_sold * amount_sold) DESC
67+
) a
68+
WHERE
69+
ROWNUM <= :m
70+
)
71+
WHERE
72+
rn >= :n;
73+
74+
/*
75+
The same queries, however this time using the new syntax, available from
76+
Oracle Database 12c Release 1 onwards
77+
*/
78+
SELECT
79+
SUM(quantity_sold * amount_sold) AS revenue,
80+
cust_id
81+
FROM
82+
sales
83+
GROUP BY
84+
cust_id
85+
ORDER BY
86+
SUM(quantity_sold * amount_sold) DESC
87+
FETCH FIRST 10 ROWS ONLY;
88+
89+
SELECT
90+
SUM(quantity_sold * amount_sold) AS revenue,
91+
cust_id
92+
FROM
93+
sales
94+
GROUP BY
95+
cust_id
96+
ORDER BY
97+
SUM(quantity_sold * amount_sold) DESC
98+
OFFSET 9 ROWS FETCH NEXT 11 ROWS ONLY;
99+
100+
----
101+
102+
.Result
103+
[source,sql]
104+
[subs="verbatim"]
105+
----
106+
SQL> /*
107+
SQL> Displaying the top 10 customers by sales using the pre-
108+
SQL> Oracle Database 12c syntax
109+
SQL>*/
110+
SQL> SELECT
111+
2 *
112+
3 FROM
113+
4 (
114+
5 SELECT
115+
6 SUM(quantity_sold * amount_sold) AS revenue,
116+
7 cust_id
117+
8 FROM
118+
9 sales
119+
10 GROUP BY
120+
11 cust_id
121+
12 ORDER BY
122+
13 SUM(quantity_sold * amount_sold) DESC
123+
14 )
124+
15 WHERE
125+
16 ROWNUM < 11;
126+
127+
REVENUE CUST_ID
128+
____________ __________
129+
103412,66 11407
130+
99578,09 10747
131+
98585,96 42167
132+
98006,16 4974
133+
97573,55 12783
134+
97010,48 6395
135+
94862,61 2994
136+
94819,41 429
137+
94786,13 1743
138+
93644,32 4759
139+
140+
10 rows selected.
141+
142+
SQL> /*
143+
SQL> Iterating over the result set, displaying 10 customers each using the pre-
144+
SQL> Oracle Database 12c syntax. You typically find this type of query in reports
145+
SQL> where batches of rows are displayed on screen. The following query retrieves
146+
SQL> rows n to m (say, 10 to 20) from the result set.
147+
SQL>*/
148+
SQL> VAR n NUMBER
149+
SQL> VAR m NUMBER
150+
SQL> BEGIN
151+
2 :n := 10;
152+
3 :m := 20;
153+
4 END;
154+
5 /
155+
156+
PL/SQL procedure successfully completed.
157+
158+
SQL> SELECT
159+
2 *
160+
3 FROM
161+
4 (
162+
5 SELECT
163+
6 a.*,
164+
7 ROWNUM rn
165+
8 FROM
166+
9 (
167+
10 SELECT
168+
11 SUM(quantity_sold * amount_sold) AS revenue,
169+
12 cust_id
170+
13 FROM
171+
14 sales
172+
15 GROUP BY
173+
16 cust_id
174+
17 ORDER BY
175+
18 SUM(quantity_sold * amount_sold) DESC
176+
19 ) a
177+
20 WHERE
178+
21 ROWNUM <= :m
179+
22 )
180+
23 WHERE
181+
24 rn >= :n;
182+
183+
REVENUE CUST_ID RN
184+
___________ __________ _____
185+
93644,32 4759 10
186+
92671,18 9038 11
187+
90908,24 4090 12
188+
89018,86 7178 13
189+
86440,63 6279 14
190+
85278,17 11702 15
191+
85200,78 6265 16
192+
84261,92 25939 17
193+
83833,3 7994 18
194+
83461,16 20966 19
195+
81970,44 3453 20
196+
197+
11 rows selected.
198+
199+
SQL> /*
200+
SQL> The same queries, however this time using the new syntax, available from
201+
SQL> Oracle Database 12c Release 1 onwards
202+
SQL>*/
203+
SQL> SELECT
204+
2 SUM(quantity_sold * amount_sold) AS revenue,
205+
3 cust_id
206+
4 FROM
207+
5 sales
208+
6 GROUP BY
209+
7 cust_id
210+
8 ORDER BY
211+
9 SUM(quantity_sold * amount_sold) DESC
212+
10 FETCH FIRST 10 ROWS ONLY;
213+
214+
REVENUE CUST_ID
215+
____________ __________
216+
103412,66 11407
217+
99578,09 10747
218+
98585,96 42167
219+
98006,16 4974
220+
97573,55 12783
221+
97010,48 6395
222+
94862,61 2994
223+
94819,41 429
224+
94786,13 1743
225+
93644,32 4759
226+
227+
10 rows selected.
228+
229+
SQL> SELECT
230+
2 SUM(quantity_sold * amount_sold) AS revenue,
231+
3 cust_id
232+
4 FROM
233+
5 sales
234+
6 GROUP BY
235+
7 cust_id
236+
8 ORDER BY
237+
9 SUM(quantity_sold * amount_sold) DESC
238+
10 OFFSET 9 ROWS FETCH NEXT 11 ROWS ONLY;
239+
240+
REVENUE CUST_ID
241+
___________ __________
242+
93644,32 4759
243+
92671,18 9038
244+
90908,24 4090
245+
89018,86 7178
246+
86440,63 6279
247+
85278,17 11702
248+
85200,78 6265
249+
84261,92 25939
250+
83833,3 7994
251+
83461,16 20966
252+
81970,44 3453
253+
254+
11 rows selected.
255+
----
256+
257+
== Benefits
258+
259+
The FETCH FIRST and OFFSET clauses provides native SQL language support to limit the number of rows returned and to specify a starting row for the return set.
260+
261+
Many queries need to limit the number of rows returned or offset the starting row of the results. For example, top-N queries sort their result set and then return only the first n rows. FETCH FIRST and OFFSET simplify syntax and comply with the ANSI SQL standard.
262+
263+
== Further information
264+
265+
* Availability: All Offerings
266+
* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/SELECT.html#GUID-CFA006CA-6FF1-4972-821E-6996142A51C6__BABBADDD[SQL Language Reference]
267+
* https://blogs.oracle.com/sql/post/how-to-select-the-top-n-rows-per-group-with-sql-in-oracle-database[Blog post with additional examples] covering many aspects of top-_n_ queries, including analytic functions

0 commit comments

Comments
 (0)