About me:Oracle ACE pro,optimistic,passionate and harmonious. Focus on ORACLE,MySQL and other database programming,peformance tuning,db design, j2ee,Linux/AIX,Architecture tech,etc
全部博文(169)
分类: Oracle
2022-04-12 08:38:53
dingjun123@ORADB> SELECT * FROM t; ID VAL CATE ---------- ---------- ---------- 1 VAL1 CATE0 2 CATE0 3 CATE0 4 CATE0 5 CATE0 6 VAL6 CATE1 7 CATE1 8 CATE1 9 CATE1 9 rows selected. |
dingjun123@ORADB> SELECT ID, 2 last_value(val IGNORE NULLS) over(ORDER BY ID) val, 3 cate 4 FROM t; ID VAL CATE ---------- ---------- ---------- 1 VAL1 CATE0 2 VAL1 CATE0 3 VAL1 CATE0 4 VAL1 CATE0 5 VAL1 CATE0 6 VAL6 CATE1 7 VAL6 CATE1 8 VAL6 CATE1 9 VAL6 CATE1 9 rows selected. |
dingjun123@ORADB> SELECT ID, 2 nvl(val,lag(val IGNORE NULLS) over(ORDER BY ID)) val, 3 cate 4 FROM t; ID VAL CATE ---------- ---------- ---------- 1 VAL1 CATE0 2 VAL1 CATE0 3 VAL1 CATE0 4 VAL1 CATE0 5 VAL1 CATE0 6 VAL6 CATE1 7 VAL6 CATE1 8 VAL6 CATE1 9 VAL6 CATE1 9 rows selected. |
dingjun123@ORADB> select id,val,cate from t; ID VAL CATE ---------- ---------- ---------- 1 CATE0 2 CATE0 3 VAL3 CATE0 4 CATE0 5 CATE0 6 VAL6 CATE1 7 CATE1 8 CATE1 9 CATE1 9 rows selected. |
dingjun123@ORADB> SELECT ID, 2 nvl(last_value(val IGNORE NULLS) over(ORDER BY ID), 3 last_value(val IGNORE NULLS) over(ORDER BY ID DESC)) val, 4 cate 5 FROM t 6 ORDER BY ID; ID VAL CATE ---------- ---------- ---------- 1 VAL3 CATE0 2 VAL3 CATE0 3 VAL3 CATE0 4 VAL3 CATE0 5 VAL3 CATE0 6 VAL6 CATE1 7 VAL6 CATE1 8 VAL6 CATE1 9 VAL6 CATE1 9 rows selected. |
dingjun123@ORADB> SELECT ID, 2 nvl(val,nvl(lag(val IGNORE NULLS) over(ORDER BY ID),lag(val IGNORE NULLS) over(ORDER BY ID DESC))) val, 3 cate 4 FROM t 5 ORDER BY ID; ID VAL CATE ---------- ---------- ---------- 1 VAL3 CATE0 2 VAL3 CATE0 3 VAL3 CATE0 4 VAL3 CATE0 5 VAL3 CATE0 6 VAL6 CATE1 7 VAL6 CATE1 8 VAL6 CATE1 9 VAL6 CATE1 9 rows selected. dingjun123@ORADB> SELECT ID, 2 nvl(val,nvl(lag(val IGNORE NULLS) over(ORDER BY ID),lead(val IGNORE NULLS) over(ORDER BY ID))) val, 3 cate 4 FROM t 5 ORDER BY ID; ID VAL CATE ---------- ---------- ---------- 1 VAL3 CATE0 2 VAL3 CATE0 3 VAL3 CATE0 4 VAL3 CATE0 5 VAL3 CATE0 6 VAL6 CATE1 7 VAL6 CATE1 8 VAL6 CATE1 9 VAL6 CATE1 9 rows selected. |
ID | VAL | CATE | 说明 |
1 | CATE0 |
使用LAG+ORDER BY ID DESC(忽略NULL,并且是找当前行之前的最近不为NULL的行), 则可以找到ID=3对应的行, 使用LEAD+ORDER BY ID,也可以找到ID=3的行(忽略NULL,找当前行之后最近不为NULL的行) |
|
2 | CATE0 | ||
3 | VAL3 | CATE0 | |
4 | CATE0 | ||
5 | CATE0 | ||
6 | VAL6 | CATE1 | |
7 | CATE1 | ||
8 | CATE1 | ||
9 | CATE1 |
ID | VAL | CATE | 说明 |
1 | CATE0 |
使用LAST_VALUE+ORDER BY ID DESC(忽略NULL,找离当前行最近的ID对应的VAL值,包括当前行,正确), 则可以找到ID=3对应的行, 使用FIRST_VALUE+ORDER BY ID,(忽略NULL,找直到当前行的,因为ID=1的前面没有,所以必然还是NULL,ID=2的类似,当然可以+WINDOW窗口搞定) |
|
2 | CATE0 | ||
3 | VAL3 | CATE0 | |
4 | CATE0 | ||
5 | CATE0 | ||
6 | VAL6 | CATE1 | |
7 | CATE1 | ||
8 | CATE1 | ||
9 | CATE1 |
--不加WINDOW窗口,不正确 dingjun123@ORADB> SELECT ID, 2 nvl(last_value(val IGNORE NULLS) over(ORDER BY ID), 3 first_value(val IGNORE NULLS) over(ORDER BY ID)) val, 4 cate 5 FROM t 6 ORDER BY ID; ID VAL CATE ---------- ---------- ---------- 1 CATE0 2 CATE0 3 VAL3 CATE0 4 VAL3 CATE0 5 VAL3 CATE0 6 VAL6 CATE1 7 VAL6 CATE1 8 VAL6 CATE1 9 VAL6 CATE1 9 rows selected. --加WINDOW窗口的FIRST_VALUE,正确 dingjun123@ORADB> SELECT ID, 2 nvl(last_value(val IGNORE NULLS) over(ORDER BY ID), 3 first_value(val IGNORE NULLS) over(ORDER BY ID ROWS BETWEEN unbounded preceding AND unbounded following)) val, 4 cate 5 FROM t 6 ORDER BY ID; ID VAL CATE ---------- ---------- ---------- 1 VAL3 CATE0 2 VAL3 CATE0 3 VAL3 CATE0 4 VAL3 CATE0 5 VAL3 CATE0 6 VAL6 CATE1 7 VAL6 CATE1 8 VAL6 CATE1 9 VAL6 CATE1 9 rows selected. |
dingjun123@ORADB> select id,val,cate from t; ID VAL CATE ---------- ---------- ---------- 1 CATE0 2 CATE0 3 VAL3 CATE0 4 CATE0 5 CATE0 6 CATE1 7 VAL7 CATE1 8 CATE1 9 CATE1 9 rows selected. |
dingjun123@ORADB> SELECT ID, 2 nvl(last_value(val IGNORE NULLS) over(PARTITION BY cate ORDER BY ID), 3 last_value(val IGNORE NULLS) over( PARTITION BY cate ORDER BY ID DESC)) val, 4 cate 5 FROM t 6 ORDER BY ID; ID VAL CATE ---------- ---------- ---------- 1 VAL3 CATE0 2 VAL3 CATE0 3 VAL3 CATE0 4 VAL3 CATE0 5 VAL3 CATE0 6 VAL7 CATE1 7 VAL7 CATE1 8 VAL7 CATE1 9 VAL7 CATE1 9 rows selected. SELECT ID, nvl(val,nvl(lag(val IGNORE NULLS) over(PARTITION BY cate ORDER BY ID), lead(val IGNORE NULLS) over(PARTITION BY cate ORDER BY ID))) val, cate FROM t ORDER BY ID; --结果一样,省略 |
dingjun123@ORADB> SELECT ID,val, 2 nvl(val,last_value(val IGNORE NULLS) over(ORDER BY ID ROWS BETWEEN unbounded preceding AND 2 following)) new_val, 3 cate 4 FROM t; ID VAL NEW_VAL CATE ---------- ---------- ------------------------------------------- ---------- 1 VAL1 VAL1 CATE0 2 VAL1 CATE0 3 VAL1 CATE0 4 VAL6 CATE0 5 VAL6 CATE0 6 VAL6 VAL6 CATE1 7 VAL6 CATE1 8 VAL6 CATE1 9 VAL6 CATE1 9 rows selected. |
dingjun123@ORADB> DROP TABLE t; Table dropped. dingjun123@ORADB> CREATE TABLE t AS SELECT LEVEL ID,decode(MOD(LEVEL,5),1,'VAL'||LEVEL) val, 2 'CATE'||(trunc((LEVEL-1)/5)) cate FROM dual CONNECT BY LEVEL<10000; Table created. dingjun123@ORADB> select count(*) cnt,count(val) cnt_val from t; CNT CNT_VAL ---------- ---------- 9999 2000 1 row selected. |
dingjun123@ORADB> SELECT ID, 2 nvl(val,last_value(val IGNORE NULLS) over(ORDER BY ID)) val, 3 cate 4 FROM t; 9999 rows selected. Elapsed: 00:00:00.13 Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 31 consistent gets 0 physical reads 0 redo size 207607 bytes sent via SQL*Net to client 7741 bytes received via SQL*Net from client 668 SQL*Net roundtrips to/from client 1 sorts (memory) 0 sorts (disk) 9999 rows processed dingjun123@ORADB> SELECT ID, 2 nvl(val,lag(val IGNORE NULLS) over(ORDER BY ID)) val, 3 cate 4 FROM t; 9999 rows selected. Elapsed: 00:00:22.49 Statistics -------------------------------------------------------- 0 recursive calls 0 db block gets 31 consistent gets 0 physical reads 0 redo size 207607 bytes sent via SQL*Net to client 7741 bytes received via SQL*Net from client 668 SQL*Net roundtrips to/from client 1 sorts (memory) 0 sorts (disk) 9999 rows processed |
SELECT ID, nvl(val,lag(val IGNORE NULLS) over(ORDER BY ID)) val, cate FROM t call count cpu elapsed disk query current rows ------- ------ -------- ---------- ---------- ---------- ---------- ---------- Parse 1 0.00 0.02 0 1 0 0 Execute 1 0.00 0.00 0 0 0 0 Fetch 668 21.98 22.08 0 31 0 9999 ------- ------ -------- ---------- ---------- ---------- ---------- ---------- total 670 21.98 22.11 0 32 0 9999 |