24/05/2005 14:37 FP 在數據倉庫中的轉換和裝載過程中,經常會使用MERGE語句,這里簡單總結一下。
MERGE語句是Oracle9i新增的語法,用來合并UPDATE和INSERT語句。通過MERGE語句,根據一張表或子查詢的連接條件對另外一張表進行查詢,連接條件匹配上的進行UPDATE,無法匹配的執行INSERT。這個語法僅需要一次全表掃描就完成了全部工作,執行效率要高于INSERT+UPDATE。
下面看個具體的例子:
SQL> CREATE TABLE T AS SELECT ROWNUM ID, A.* FROM DBA_OBJECTS A;
表已創建。
SQL> CREATE TABLE T1 AS
2 SELECT ROWNUM ID, OWNER, TABLE_NAME, CAST('TABLE' AS VARCHAR2(100)) OBJECT_TYPE
3 FROM DBA_TABLES;
表已創建。
SQL> MERGE INTO T1 USING T
2 ON (T.OWNER = T1.OWNER AND T.OBJECT_NAME = T1.TABLE_NAME AND T.OBJECT_TYPE = T1.OBJECT_TYPE)
3 WHEN MATCHED THEN UPDATE SET T1.ID = T.ID
4 WHEN NOT MATCHED THEN INSERT VALUES (T.ID, T.OWNER, T.OBJECT_NAME, T.OBJECT_TYPE);
6165 行已合并。
SQL> SELECT ID, OWNER, OBJECT_NAME, OBJECT_TYPE FROM T
2 MINUS
3 SELECT * FROM T1;
未選定行
MERGE語法其實很簡單,下面稍微修改一下例子。
SQL> DROP TABLE T;
表已丟棄。
SQL> DROP TABLE T1;
表已丟棄。
SQL> CREATE TABLE T AS SELECT ROWNUM ID, A.* FROM DBA_OBJECTS A;
表已創建。
SQL> CREATE TABLE T1 AS SELECT ROWNUM ID, OWNER, TABLE_NAME FROM DBA_TABLES;
表已創建。
SQL> MERGE INTO T1 USING T
2 ON (T.OWNER = T1.OWNER AND T.OBJECT_NAME = T1.TABLE_NAME)
3 WHEN MATCHED THEN UPDATE SET T1.ID = T.ID
4 WHEN NOT MATCHED THEN INSERT VALUES (T.ID, T.OWNER, T.OBJECT_NAME);
MERGE INTO T1 USING T
*
ERROR 位于第 1 行:
ORA-30926: 無法在源表中獲得一組穩定的行
這個錯誤是使用MERGE最常見的錯誤,造成這個錯誤的原因是由于通過連接條件得到的T的記錄不唯一。最簡單的解決方法類似:
SQL> MERGE INTO T1
2 USING (SELECT OWNER, OBJECT_NAME, MAX(ID) ID FROM T GROUP BY OWNER, OBJECT_NAME) T
3 ON (T.OWNER = T1.OWNER AND T.OBJECT_NAME = T1.TABLE_NAME)
4 WHEN MATCHED THEN UPDATE SET T1.ID = T.ID
5 WHEN NOT MATCHED THEN INSERT VALUES (T.ID, T.OWNER, T.OBJECT_NAME);
5775 行已合并。
另外,MERGE語句的UPDATE不能修改用于連接的列,否則會報錯,詳細信息可以參考:http://blog.itpub.net/post/468/14844
===============================================================
ref: http://tomszrp.itpub.net/post/11835/263865
在Oracle 10g之前,merge語句支持匹配更新和不匹配插入2種簡單的用法,在10g中Oracle對merge語句做了增強,增加了條件選項和DELETE操作。下面我通過一個demo來簡單介紹一下10g中merge的增強和10g前merge的用法。
參考Oracle 的SQL Reference,大家可以看到Merge Statement的語法如下:
MERGE [hint] INTO [schema .] table [t_alias] USING [schema .]
{ table | view | subquery } [t_alias] ON ( condition )
WHEN MATCHED THEN merge_update_clause
WHEN NOT MATCHED THEN merge_insert_clause;
下面我在windows xp 下10.2.0.1版本上做一個測試看看
SQL> select * from v$version; BANNER ---------------------------------------------------------------- Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Prod PL/SQL Release 10.2.0.1.0 - Production CORE 10.2.0.1.0 Production TNS for 32-bit Windows: Version 10.2.0.1.0 - Production NLSRTL Version 10.2.0.1.0 - Production SQL> 一、創建測試用的表 SQL> create table subs(msid number(9), 2 ms_type char(1), 3 areacode number(3) 4 ); 表已創建。 SQL> create table acct(msid number(9), 2 bill_month number(6), 3 areacode number(3), 4 fee number(8,2) default 0.00); 表已創建。 SQL> SQL> insert into subs values(905310001,0,531); 已創建 1 行。 SQL> insert into subs values(905320001,1,532); 已創建 1 行。 SQL> insert into subs values(905330001,2,533); 已創建 1 行。 SQL> commit; 提交完成。 SQL> 二、下面先演示一下merge的基本功能 1) matched 和not matched clauses 同時使用 merge into acct a using subs b on (a.msid=b.msid) when MATCHED then update set a.areacode=b.areacode when NOT MATCHED then insert(msid,bill_month,areacode) values(b.msid,'200702',b.areacode); 2) 只有not matched clause,也就是只插入不更新 merge into acct a using subs b on (a.msid=b.msid) when NOT MATCHED then insert(msid,bill_month,areacode) values(b.msid,'200702',b.areacode); 3) 只有matched clause, 也就是只更新不插入 merge into acct a using subs b on (a.msid=b.msid) when MATCHED then update set a.areacode=b.areacode Connected to Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 Connected as study SQL> select * from subs; MSID MS_TYPE AREACODE ---------- ------- -------- 905310001 0 531 905320001 1 532 905330001 2 533 SQL> select * from acct; MSID BILL_MONTH AREACODE FEE ---------- ---------- -------- ---------- SQL> SQL> merge into acct a 2 using subs b on (a.msid=b.msid) 3 when MATCHED then 4 update set a.areacode=b.areacode 5 when NOT MATCHED then 6 insert(msid,bill_month,areacode) 7 values(b.msid,'200702',b.areacode); Done SQL> select * from acct; MSID BILL_MONTH AREACODE FEE ---------- ---------- -------- ---------- 905320001 200702 532 0.00 905330001 200702 533 0.00 905310001 200702 531 0.00 SQL> insert into subs values(905340001,3,534); 1 row inserted SQL> select * from subs; MSID MS_TYPE AREACODE ---------- ------- -------- 905340001 3 534 905310001 0 531 905320001 1 532 905330001 2 533 SQL> SQL> merge into acct a 2 using subs b on (a.msid=b.msid) 3 when NOT MATCHED then 4 insert(msid,bill_month,areacode) 5 values(b.msid,'200702',b.areacode); Done SQL> select * from acct; MSID BILL_MONTH AREACODE FEE ---------- ---------- -------- ---------- 905320001 200702 532 0.00 905330001 200702 533 0.00 905310001 200702 531 0.00 905340001 200702 534 0.00 SQL> update subs set areacode=999; 4 rows updated SQL> select * from subs; MSID MS_TYPE AREACODE ---------- ------- -------- 905340001 3 999 905310001 0 999 905320001 1 999 905330001 2 999 SQL> select * from acct; MSID BILL_MONTH AREACODE FEE ---------- ---------- -------- ---------- 905320001 200702 532 0.00 905330001 200702 533 0.00 905310001 200702 531 0.00 905340001 200702 534 0.00 SQL> SQL> merge into acct a 2 using subs b on (a.msid=b.msid) 3 when MATCHED then 4 update set a.areacode=b.areacode; Done SQL> select * from acct; MSID BILL_MONTH AREACODE FEE ---------- ---------- -------- ---------- 905320001 200702 999 0.00 905330001 200702 999 0.00 905310001 200702 999 0.00 905340001 200702 999 0.00 SQL> 三、10g中增強一:條件操作 1) matched 和not matched clauses 同時使用 merge into acct a using subs b on (a.msid=b.msid) when MATCHED then update set a.areacode=b.areacode where b.ms_type=0 when NOT MATCHED then insert(msid,bill_month,areacode) values(b.msid,'200702',b.areacode) where b.ms_type=0; 2) 只有not matched clause,也就是只插入不更新 merge into acct a using subs b on (a.msid=b.msid) when NOT MATCHED then insert(msid,bill_month,areacode) values(b.msid,'200702',b.areacode) where b.ms_type=0; 3) 只有matched clause, 也就是只更新不插入 merge into acct a using subs b on (a.msid=b.msid) when MATCHED then update set a.areacode=b.areacode where b.ms_type=0; Connected to Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 Connected as study SQL> select * from subs; MSID MS_TYPE AREACODE ---------- ------- -------- 905310001 0 531 905320001 1 532 905330001 2 533 SQL> select * from acct; MSID BILL_MONTH AREACODE FEE ---------- ---------- -------- ---------- SQL> SQL> merge into acct a 2 using subs b on (a.msid=b.msid) 3 when MATCHED then 4 update set a.areacode=b.areacode 5 where b.ms_type=0 6 when NOT MATCHED then 7 insert(msid,bill_month,areacode) 8 values(b.msid,'200702',b.areacode) 9 where b.ms_type=0; Done SQL> select * from acct; MSID BILL_MONTH AREACODE FEE ---------- ---------- -------- ---------- 905310001 200702 531 0.00 SQL> insert into subs values(905360001,0,536); 1 row inserted SQL> select * from subs; MSID MS_TYPE AREACODE ---------- ------- -------- 905360001 0 536 905310001 0 531 905320001 1 532 905330001 2 533 SQL> SQL> merge into acct a 2 using subs b on (a.msid=b.msid) 3 when NOT MATCHED then 4 insert(msid,bill_month,areacode) 5 values(b.msid,'200702',b.areacode) 6 where b.ms_type=0; Done SQL> select * from acct; MSID BILL_MONTH AREACODE FEE ---------- ---------- -------- ---------- 905310001 200702 531 0.00 905360001 200702 536 0.00 SQL> update subs set areacode=888 where ms_type=0; 2 rows updated SQL> select * from subs; MSID MS_TYPE AREACODE ---------- ------- -------- 905360001 0 888 905310001 0 888 905320001 1 532 905330001 2 533 SQL> select * from acct; MSID BILL_MONTH AREACODE FEE ---------- ---------- -------- ---------- 905310001 200702 531 0.00 905360001 200702 536 0.00 SQL> SQL> merge into acct a 2 using subs b on (a.msid=b.msid) 3 when MATCHED then 4 update set a.areacode=b.areacode 5 where b.ms_type=0; Done SQL> select * from acct; MSID BILL_MONTH AREACODE FEE ---------- ---------- -------- ---------- 905310001 200702 888 0.00 905360001 200702 888 0.00 SQL> 四、10g中增強二:刪除操作 An optional DELETE WHERE clause can be used to clean up after a merge operation. Only those rows which match both the ON clause and the DELETE WHERE clause are deleted. merge into acct a using subs b on (a.msid=b.msid) when MATCHED then update set a.areacode=b.areacode delete where (b.ms_type!=0); SQL> select * from subs; MSID MS_TYPE AREACODE ---------- ------- -------- 905310001 0 531 905320001 1 532 905330001 2 533 SQL> select * from acct; MSID MS_TYPE AREACODE ---------- ------- -------- 905310001 0 531 905320001 1 532 905330001 2 533 SQL> SQL> merge into acct a 2 using subs b on (a.msid=b.msid) 3 when MATCHED then 4 update set a.areacode=b.areacode 5 delete where (b.ms_type!=0); Done SQL> select * from acct; MSID MS_TYPE AREACODE ---------- ------- -------- 905310001 0 531 SQL> 更為詳盡的語法,請參考Oracle SQL Reference手冊!