ROWNUM是一種偽列,它會根據返回記錄生成一個序列化的數字。利用ROWNUM,我們可以生產一些原先難以實現的結果輸出,但因為它是偽列的這個特殊性,我們在使用時也需要注意一些事項,不要掉入“陷阱”。下面就介紹一下它的使用技巧及注意事項。
1 特殊結果輸出
利用ROWNUM,我們可以做到一些特殊方式的輸出。
1.1 Top N結果輸出
我們如果希望取輸出結果的前面幾條數據,通過ROWNUM可以輕松實現:
sql> select * from t_test4
2 where rownum <= 5;
USERNAME USER_ID CREATED
------------------------------ ---------- ---------
WOW 71 26-APR-07
CS2 70 15-JAN-07
3 69 01-NOV-06
DMP 68 12-OCT-06
PROFILER 67 05-SEP-06
但是,如果你希望對一個排序結果取Top N數據的話,使用ROWNUM存在一些“陷阱”,我們后面部分會介紹這些“陷阱”并且說明如何避免。
1.2 分頁查詢
利用ROWNUM對結果進行分頁,下面返回結果中的第6到第10條記錄:
sql> select * from
2 (
3 select a.*, rownum as rn from css_bl_view a
4 where capture_phone_num = '(1) 925-4604800'
5 ) b
6 where b.rn between 6 and 10;
6 rows selected.
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=2770 Card=2183 Bytes =7166789)
1 0 VIEW (Cost=2770 Card=2183 Bytes=7166789)
2 1 COUNT
3 2 table ACCESS (FULL) OF 'CSS_BL_VIEW' (Cost=2770 Card=2183 Bytes=1305434)
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
29346 consistent gets
29190 physical reads
0 redo size
7328 bytes sent via sql*Net to client
234 bytes received via sql*Net from client
4 sql*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
5 rows processed
另外一種實現方式:
sql> select * from css_bl_view a
2 where capture_phone_num = '(1) 925-4604800'
3 and rownum <= 10
4 minus
5 select * from css_bl_view a
6 where capture_phone_num = '(1) 925-4604800'
7 and rownum <= 5
8 ;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=5920 Card=10 Bytes=8970)
1 0 MINUS
2 1 SORT (UNIQUE) (Cost=2960 Card=10 Bytes=5980)
3 2 COUNT (STOPKEY)
4 3 TABLE ACCESS (FULL) OF 'CSS_BL_VIEW' (Cost=2770 Card=2183 Bytes=1305434)
5 1 SORT (UNIQUE) (Cost=2960 Card=5 Bytes=2990)
6 5 COUNT (STOPKEY)
7 6 table ACCESS (FULL) OF 'CSS_BL_VIEW' (Cost=2770 Card=2183 Bytes=1305434)
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
62 consistent gets
50 physical reads
0 redo size
7232 bytes sent via sql*Net to client
234 bytes received via sql*Net from client
4 sql*Net roundtrips to/from client
2 sorts (memory)
0 sorts (disk)
5 rows processed
第三種實現方式:
sql> select * from
2 (
3 select a.*, rownum as rn from css_bl_view a
4 where capture_phone_num = '(1) 925-4604800'
5 and rownum <= 10
6 ) b
7 where b.rn > 5;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=2770 Card=10 Bytes=32830)
1 0 VIEW (Cost=2770 Card=10 Bytes=32830)
2 1 COUNT (STOPKEY)
3 2 table ACCESS (FULL) OF 'CSS_BL_VIEW' (Cost=2770 Card=2183 Bytes=1305434)
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
35 consistent gets
30 physical reads
0 redo size
7271 bytes sent via sql*Net to client
234 bytes received via sql*Net from client
4 sql*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
5 rows processed
這里特地將三種實現方式的查詢計劃及統計數據打印出來,大家可以比較一下3中方式的性能。
1.3 利用ROWNUM做分組子排序
對于以下表T_TEST4的內容:
OWNER NAME
------------------------------------------------------
STRMADMIN STREAMS_QUEUE
APARKMAN JOB_QUEUE
SYS AQ$_AQ_SRVNTFN_TABLE_E
SYS AQ$_KUPC$DATAPUMP_QUETAB_E
APARKMAN AQ$_JMS_TEXT_E
STRMADMIN AQ$_STREAMS_QUEUE_TABLE_E
SYS AQ$_SCHEDULER$_EVENT_QTAB_E
…
如果我們希望結果按照OWNER進行分組后,再對每組中成員進行編號,結果類似如下:
OWNER NO NAME
------------------------------------------------------
APARKMAN 1 JOB_QUEUE
2 AQ$_JMS_TEXT_E
STRMADMIN 1 STREAMS_QUEUE
2 AQ$_STREAMS_QUEUE_TABLE_E
SYS 1 AQ$_AQ_SRVNTFN_TABLE_E
2 AQ$_KUPC$DATAPUMP_QUETAB_E
3 AQ$_SCHEDULER$_EVENT_QTAB_E
…
在沒有ROWNUM時要實現這樣的功能會很復雜,但通過ROWNUM我們可以輕松實現:
sql> SELECT DECODE(ROWNUM-min_sno,0,a.owner,NULL) owner,DECODE(ROWNUM-min_sno,0,1,rownum+1-min_sno) sno, a.name
2 FROM (SELECT *
3 FROM t_test8
4 ORDER BY owner, name ) a,
5 (SELECT owner, MIN(rownum) min_sno
6 FROM( SELECT *
7 FROM t_test8
8 ORDER BY owner, name)
9 GROUP BY owner) b
10 WHERE a.owner=b.owner;
OWNER SNO NAME
------------------------------ ---------- ------------------------------
APARKMAN 1 JOB_QUEUE
2 AQ$_JMS_TEXT_E
STRMADMIN 1 STREAMS_QUEUE
2 AQ$_STREAMS_QUEUE_TABLE_E
SYS 1 AQ$_AQ_SRVNTFN_TABLE_E
2 AQ$_KUPC$DATAPUMP_QUETAB_E
3 AQ$_SCHEDULER$_EVENT_QTAB_E
4 AQ$_SCHEDULER$_JOBQTAB_E
5 AQ$_STREAMS_QUEUE_TABLE_E
6 AQ$_SYS$SERVICE_METRICS_TAB_E
7 AQ$_AQ_EVENT_TABLE_E
8 AQ$_AQ$_MEM_MC_E
9 AQ$_ALERT_QT_E
10 ALERT_QUE
11 AQ_EVENT_TABLE_Q
12 SYS$SERVICE_METRICS
13 STREAMS_QUEUE
14 SRVQUEUE
15 SCHEDULER$_JOBQ
16 SCHEDULER$_EVENT_QUEUE
17 AQ_SRVNTFN_TABLE_Q
SYSMAN 1 AQ$_MGMT_NOTIFY_QTABLE_E
2 MGMT_NOTIFY_Q
system 1 DEF$_AQERROR
2 DEF$_AQCALL
3 AQ$_DEF$_AQERROR_E
4 AQ$_DEF$_AQCALL_E
WMSYS 1 AQ$_WM$EVENT_QUEUE_TABLE_E
2 WM$EVENT_QUEUE
29 rows selected.
2 性能
我們很多程序員在確認某個表中是否有相應數據時,喜歡加上ROWNUM=1,其思路就是只要存在一條數據就說明有相應數據,查詢就可以直接返回了,這樣就能提高性能了。但是在10G之前,使用ROWNUM=1是不能達到預期的性能效果的,而是需要通過<2或<=1作為過濾條件才能達到預期效果,看以下查詢計劃:
sql> select * from t_test1
2 where object_id <100
3 and rownum = 1;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=37 Card=1 Bytes=86)
1 0 COUNT (STOPKEY)
2 1 table ACCESS (BY INDEX ROWID) OF 'T_TEST1' (Cost=37 Card=89 Bytes=7654)
3 2 INDEX (RANGE SCAN) OF 'T_TEST1_PK' (UNIQUE) (Cost=2 Card=89)
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
62 consistent gets
0 physical reads
0 redo size
654 bytes sent via sql*Net to client
234 bytes received via sql*Net from client
4 sql*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed
sql> select * from t_test1
2 where object_id <100
3 and rownum <= 1;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=37 Card=1 Bytes=86)
1 0 COUNT (STOPKEY)
2 1 table ACCESS (BY INDEX ROWID) OF 'T_TEST1' (Cost=37 Card=89 Bytes=7654)
3 2 INDEX (RANGE SCAN) OF 'T_TEST1_PK' (UNIQUE) (Cost=2 Card=89)
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
3 consistent gets
0 physical reads
0 redo size
654 bytes sent via sql*Net to client
234 bytes received via sql*Net from client
4 sql*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed
sql> /
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=37 Card=1 Bytes=86)
1 0 COUNT (STOPKEY)
2 1 table ACCESS (BY INDEX ROWID) OF 'T_TEST1' (Cost=37 Card=89 Bytes=7654)
3 2 INDEX (RANGE SCAN) OF 'T_TEST1_PK' (UNIQUE) (Cost=2 Card=89)
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
3 consistent gets
0 physical reads
0 redo size
654 bytes sent via sql*Net to client
234 bytes received via sql*Net from client
4 sql*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed
10G以后,這個問題就被修正了:
sql> select * from t_test1
2 where rownum = 1;
Execution Plan
----------------------------------------------------------
Plan hash value: 536364188
------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 86 | 2 (0)| 00:00:01 |
|* 1 | COUNT STOPKEY | | | | | |
| 2 | table ACCESS FULL| T_TEST1 | 1 | 86 | 2 (0)| 00:00:01 |
------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter(ROWNUM=1)
Statistics
----------------------------------------------------------
1 recursive calls
0 db block gets
4 consistent gets
1 physical reads
0 redo size
1201 bytes sent via sql*Net to client
385 bytes received via sql*Net from client
2 sql*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed
sql> select * from t_test1
2 where rownum <= 1;
Execution Plan
----------------------------------------------------------
Plan hash value: 536364188
------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 86 | 2 (0)| 00:00:01 |
|* 1 | COUNT STOPKEY | | | | | |
| 2 | table ACCESS FULL| T_TEST1 | 1 | 86 | 2 (0)| 00:00:01 |
------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter(ROWNUM<=1)
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
4 consistent gets
0 physical reads
0 redo size
1201 bytes sent via sql*Net to client
385 bytes received via sql*Net from client
2 sql*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed
3 ROWNUM的使用“陷阱”
由于ROWNUM是一個偽列,只有有結果記錄時,ROWNUM才有相應數據,因此對它的使用不能向普通列那樣使用,否則就會陷入一些“陷阱”當中。
3.1 對ROWNUM進行>、>=、=操作
不能對ROWNUM使用>(大于1的數值)、>=(大于或等于1的數值)、=(大于或等于1的數值),否則無結果
sql> select count(*) from css_bl_view a where rownum>0;
COUNT(*)
----------
361928
sql> select count(*) from css_bl_view a
2 where rownum > 1;
COUNT(*)
----------
0
這是因為:
1、ROWNUM是偽列,必須要要有返回結果后,每條返回記錄就會對應產生一個ROWNUM數值;
2、返回結果記錄的ROWNUM是從1開始排序的,因此第一條始終是1;
這樣,當查詢到第一條記錄時,該記錄的ROWNUM為1,但條件要求ROWNUM>1,因此不符合,繼續查詢下一條;因為前面沒有符合要求的記錄,因此下一條記錄過來后,其ROWNUM還是為1,如此循環,就不會產生結果。上述查詢可以通過子查詢來替代:
sql> select count(*)
2 from
3 (select BL_REF_CDE, rownum rn from css_bl_view)
4 where rn > 1;
COUNT(*)
----------
361927
我們可以通過以下方式來實現對ROWNUM的>、=的查詢:
查詢ROWNUM=5的數據:
sql> select object_id,object_name
2 from (select object_id,object_name, rownum as rn from t_test1)
3 where rn = 5;
OBJECT_ID OBJECT_NAME
---------- ------------------------------
29 C_COBJ#
查詢ROWNUM > 25的數據:
sql> select * from t_test4
2 minus
3 select * from t_test4
4 where rownum <= 25;
USERNAME USER_ID CREATED
------------------------------ ---------- ---------
DIP 19 21-NOV-05
OUTLN 11 21-NOV-05
PUBLIC 99999 18-JUL-07
SYS 0 21-NOV-05
SYSMAN 32 21-NOV-05
system 5 21-NOV-05
6 rows selected.
3.2 ROWNUM和Order BY
要注意的是:在使用ROWNUM時,只有當Order By的字段是主鍵時,查詢結果才會先排序再計算ROWNUM,下面OBJECT_ID是表T_TEST1的主鍵字段:
sql> select object_id,object_name from t_test1
2 where rownum <= 5
3 order by object_id;
OBJECT_ID OBJECT_NAME
---------- ------------------------------
2 C_OBJ#
3 I_OBJ#
4 TAB$
5 CLU$
6 C_TS#
但是,對非主鍵字段OBJECT_NAME進行排序時,結果就混亂了:
sql> select object_id,object_name from t_test1
2 where rownum <= 5
3 order by object_name;
OBJECT_ID OBJECT_NAME
---------- ------------------------------
28 CON$
29 C_COBJ#
20 ICOL$
44 I_USER1
15 UNDO$
sql> select count(*) from t_test1
2 where object_name < 'CON$';
COUNT(*)
----------
21645
出現這種混亂的原因是:oracle先按物理存儲位置(rowid)順序取出滿足rownum條件的記錄,即物理位置上的前5條數據,然后在對這些數據按照Order By的字段進行排序,而不是我們所期望的先排序、再取特定記錄數。
如果需要對非主鍵字段排序再去前n條數據,我們可以以以下方式實現:
sql> select object_id,object_name
2 from (select object_id,object_name from t_test1
3 order by object_name)
4 where rownum <= 5;
OBJECT_ID OBJECT_NAME
---------- ------------------------------
35489 /1000e8d1_LinkedHashMapValueIt
35490 /1000e8d1_LinkedHashMapValueIt
21801 /1005bd30_LnkdConstant
21802 /1005bd30_LnkdConstant
17205 /10076b23_OraCustomDatumClosur
3.3 排序分頁
當對存在重復值的字段排序后再分頁輸出,我們很容易會陷入到另外一個“陷阱”。
請看以下例子,我們希望對T_TEST1的OWNER字段排序后,以每頁輸出10個結果的方式分頁輸出:
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select owner, object_name from t_test1 order by owner) a
4 where rownum <= 10)
5 where rn >= 1;
OWNER OBJECT_NAME
------------------------------ ------------------------------
AFWOWNER AFWADAPTER
AFWOWNER AFWADAPTERCONFIGURATION
AFWOWNER AFWADAPTERCONFIGURATION_IDX1
AFWOWNER AFWADAPTERFQN_PK
AFWOWNER AFWADAPTERCONFIGURATION_PK
AFWOWNER AFWADAPTERCONFIGURATION_IDX2
AFWOWNER AFWSERVERCODE_PK
AFWOWNER AFWSERVER
AFWOWNER AFWADAPTERLOOKUP_IDX1
AFWOWNER AFWADAPTERLOOKUP
10 rows selected.
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select owner, object_name from t_test1 order by owner) a
4 where rownum <= 20)
5 where rn >= 11;
OWNER OBJECT_NAME
------------------------------ ------------------------------
AFWOWNER AFWTOKENSTATUSCODE_PK
AFWOWNER AFWTOKENSTATUS
AFWOWNER AFWTOKENADMIN_IDX1
AFWOWNER AFWTOKENADMINCODE_PK
AFWOWNER AFWTOKENADMIN
AFWOWNER AFWTOKEN
AFWOWNER AFWSERVERCONFIGURATION_PK
AFWOWNER AFWSERVERCONFIGURATION
AFWOWNER AFWSERVER
AFWOWNER AFWADAPTERLOOKUP
10 rows selected.
仔細比較結果,你會發現“AFWSERVER”、“AFWADAPTERLOOKUP”在兩次分頁結果中都出現了。但是OBJECT_NAME在每個OWNER中的值是唯一的,說明這個輸出結果是錯誤的,我們又陷入了一個“陷阱”。這是怎么回事呢,請先看下上述語句的查詢計劃:
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select owner, object_name from t_test1 order by owner) a
4 where rownum <= 20)
5 where rn >= 11;
10 rows selected.
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=205 Card=20 Bytes=94
0)
1 0 VIEW (Cost=205 Card=20 Bytes=940)
2 1 COUNT (STOPKEY)
3 2 VIEW (Cost=205 Card=30670 Bytes=1042780)
4 3 SORT (ORDER BY STOPKEY) (Cost=205 Card=30670 Bytes=858760)
5 4 table ACCESS (FULL) OF 'T_TEST1' (Cost=42 Card=30670 Bytes=858760)
看下這個“陷阱”是怎么形成的。從查詢計劃上,我們可以注意到,對于子查詢
select a.*, rownum as rn from
(select owner, object_name from t_test1 order by owner) a
where rownum <= 20
優化器采用了“SORT (ORDER BY STOPKEY)”。
“SORT (ORDER BY STOPKEY)”不需要對所有數據進行排序,而是只要找出結果集中的按特定順序的最前N條記錄,一旦找出了這N條記錄,就無需再對剩下的數據進行排序,而直接返回結果。這種算法我們可以視為是“快速排序”算法的變種。快速排序算法的基本思想是:先將數據分2組集合,保證第一集合中的每個數據都大于第二個集合中每個數據,然后再按這個原則對每個集合進行遞歸分組,直到集合的單位最小。在進行“SORT (ORDER BY STOPKEY)”時,首先找出N條數據(這些數據并沒有做排序)放在第一組,保證第一組的數據都大于第二組的數據,然后只對第一組數據進行遞歸。
可以看到,基于這樣的算法基礎上,如果N的數值不同,數據的分組也不同(如N=20時,第一次分組比例為12:8,然后繼續遞歸;當N=10時,第一次分組比例為3:7 … …),這樣,在數據的排序字段值都相等時,輸出結果的順序就會因為N值不同而不同。
知道原因后,我們可以通過以下幾種方法來避免這個“陷阱”。
1、讓查詢計劃避免“SORT (ORDER BY STOPKEY)”,采用“SORT (ORDER BY)”,使數據排序不受ROWNUM的影響。但這樣會使所有數據都做排序:
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select owner, object_name, rowid from t_test1 order by owner) a)
4 where rn <= 10
5 and rn >= 1;
OWNER OBJECT_NAME
------------------------------ ------------------------------
AFWOWNER AFWADAPTER
AFWOWNER AFWADAPTERCONFIGURATION
AFWOWNER AFWADAPTERCONFIGURATION_IDX2
AFWOWNER AFWADAPTERCONFIGURATION_PK
AFWOWNER AFWADAPTERCONFIGURATION_IDX1
AFWOWNER AFWADAPTERFQN_PK
AFWOWNER AFWADAPTERLOOKUP_IDX1
AFWOWNER AFWSERVERCODE_PK
AFWOWNER AFWSERVERCONFIGURATION_IDX1
AFWOWNER AFWTOKENTYPECODE_PK
10 rows selected.
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select owner, object_name, rowid from t_test1 order by owner) a)
4 where rn <= 20
5 and rn >= 11;
OWNER OBJECT_NAME
------------------------------ ------------------------------
AFWOWNER AFWTOKENTYPE
AFWOWNER AFWTOKENSTATUSCODE_PK
AFWOWNER AFWTOKENSTATUS
AFWOWNER AFWTOKENADMIN_IDX1
AFWOWNER AFWTOKENADMINCODE_PK
AFWOWNER AFWTOKENADMIN
AFWOWNER AFWTOKEN
AFWOWNER AFWSERVERCONFIGURATION_PK
AFWOWNER AFWTOKEN_PK
AFWOWNER AFWTOKEN_IDX6
10 rows selected.
sql> set autot trace
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select owner, object_name, rowid from t_test1 order by owner) a)
4 where rn <= 20
5 and rn >= 11;
10 rows selected.
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=237 Card=30670 Bytes=1441490)
1 0 VIEW (Cost=237 Card=30670 Bytes=1441490)
2 1 COUNT
3 2 VIEW (Cost=237 Card=30670 Bytes=1042780)
4 3 SORT (ORDER BY) (Cost=237 Card=30670 Bytes=1073450)
5 4 table ACCESS (FULL) OF 'T_TEST1' (Cost=42 Card=30670 Bytes=1073450)
2、在排序時,加上一個或多個字段(如主鍵字段、ROWID),使排序結果具有唯一性:
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select owner, object_name, rowid from t_test1 order by owner, object_id) a
4 where rownum <= 10)
5 where rn >= 1;
OWNER OBJECT_NAME
------------------------------ ------------------------------
AFWOWNER AFWADAPTER
AFWOWNER AFWADAPTERFQN_PK
AFWOWNER AFWADAPTERCONFIGURATION
AFWOWNER AFWADAPTERCONFIGURATION_PK
AFWOWNER AFWADAPTERCONFIGURATION_IDX1
AFWOWNER AFWADAPTERCONFIGURATION_IDX2
AFWOWNER AFWADAPTERLOOKUP
AFWOWNER AFWADAPTERLOOKUP_IDX1
AFWOWNER AFWSERVER
AFWOWNER AFWSERVERCODE_PK
10 rows selected.
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select owner, object_name, rowid from t_test1 order by owner, object_id) a
4 where rownum <= 20)
5 where rn >= 11;
OWNER OBJECT_NAME
------------------------------ ------------------------------
AFWOWNER AFWSERVERCONFIGURATION
AFWOWNER AFWSERVERCONFIGURATION_PK
AFWOWNER AFWSERVERCONFIGURATION_IDX1
AFWOWNER AFWTOKEN
AFWOWNER AFWTOKEN_PK
AFWOWNER AFWTOKEN_IDX1
AFWOWNER AFWTOKEN_IDX2
AFWOWNER AFWTOKEN_IDX3
AFWOWNER AFWTOKEN_IDX4
AFWOWNER AFWTOKEN_IDX5
10 rows selected.
sql> set autot trace
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select owner, object_name, rowid from t_test1 order by owner, object_id) a
4 where rownum <= 20)
5 where rn >= 11;
10 rows selected.
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=253 Card=20 Bytes=940)
1 0 VIEW (Cost=253 Card=20 Bytes=940)
2 1 COUNT (STOPKEY)
3 2 VIEW (Cost=253 Card=30670 Bytes=1042780)
4 3 SORT (ORDER BY STOPKEY) (Cost=253 Card=30670 Bytes=1196130)
5 4 table ACCESS (FULL) OF 'T_TEST1' (Cost=42 Card=306
70 Bytes=1196130)
3、對排序字段建立索引,并強制使用索引。這樣就能利用索引已經建立好的排序結果:
sql> create index t_test1_idx1 on t_test1(owner);
Index created.
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select /*+index(t T_TEST1_IDX1)*/owner, object_name from t_test1 t order by owner) a
4 where rownum <= 10)
5 where rn >= 1
6 ;
OWNER OBJECT_NAME
------------------------------ ------------------------------
AFWOWNER AFWADAPTER
AFWOWNER AFWADAPTERCONFIGURATION
AFWOWNER AFWADAPTERCONFIGURATION_IDX1
AFWOWNER AFWADAPTERCONFIGURATION_IDX2
AFWOWNER AFWADAPTERCONFIGURATION_PK
AFWOWNER AFWADAPTERFQN_PK
AFWOWNER AFWADAPTERLOOKUP
AFWOWNER AFWADAPTERLOOKUP_IDX1
AFWOWNER AFWSERVER
AFWOWNER AFWSERVERCODE_PK
10 rows selected.
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select /*+index(t T_TEST1_IDX1)*/owner, object_name from t_test1 t order by owner) a
4 where rownum <= 20)
5 where rn >= 11;
OWNER OBJECT_NAME
------------------------------ ------------------------------
AFWOWNER AFWSERVERCONFIGURATION
AFWOWNER AFWSERVERCONFIGURATION_IDX1
AFWOWNER AFWSERVERCONFIGURATION_PK
AFWOWNER AFWTOKEN
AFWOWNER AFWTOKENADMIN
AFWOWNER AFWTOKENADMINCODE_PK
AFWOWNER AFWTOKENADMIN_IDX1
AFWOWNER AFWTOKENSTATUS
AFWOWNER AFWTOKENSTATUSCODE_PK
AFWOWNER AFWTOKENTYPE
10 rows selected.
sql> set autot trace
sql> select owner, object_name from
2 (select a.*, rownum as rn from
3 (select /*+index(t T_TEST1_IDX1)*/owner, object_name from t_test1 t order by owner) a
4 where rownum <= 20)
5 where rn >= 11;
10 rows selected.
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=414 Card=20 Bytes=940)
1 0 VIEW (Cost=414 Card=20 Bytes=940)
2 1 COUNT (STOPKEY)
3 2 VIEW (Cost=414 Card=30670 Bytes=1042780)
4 3 table ACCESS (BY INDEX ROWID) OF 'T_TEST1' (Cost=414Card=30670 Bytes=858760)
5 4 INDEX (FULL SCAN) OF 'T_TEST1_IDX1' (NON-UNIQUE) (
Cost=26 Card=30670)
以上就是ROWNUM的使用技巧及其注意事項,希望編程成員正確使用ROWNUM,也希望DBA遇到相關問題能迅速定位。