Oracle表關(guān)聯(lián)更新幾種方法小結(jié)
1、測試表及數(shù)據(jù)準(zhǔn)備
create table T_update01(ID int ,infoname varchar2(32),sys_guid varchar2(36));
create table T_update02(ID int ,infoname varchar2(32),sys_guid varchar2(36));
insert into T_update01
select 1,N'1_updateName',sys_guid() from dual
union
select 2,N'2_updateName',sys_guid() from dual;
commit;
insert into T_update02
select 1,N'update_set_exists',sys_guid() from dual;
insert into T_update02
select 2,N'update_set_cursor',sys_guid() from dual;
insert into T_update02
select 3,N'3_Name',sys_guid() from dual;
commit;
-- 查詢表T_update01、T_update02
select * from T_update01;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 1_updateName 189F5A1099BF6606E0639C0AA8C0F15E
2 2_updateName 189F5A1099C06606E0639C0AA8C0F15E
select * from T_update02;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 update_set_exists 189F5A1099C46606E0639C0AA8C0F15E
2 update_set_cursor 189F5A1099C56606E0639C0AA8C0F15E
3 3_Name 189F5A1099C66606E0639C0AA8C0F15E2、update set column ... where exists
2.1、update set 單列字段
-- update set 單列字段,更新滿足關(guān)聯(lián)條件的所有數(shù)據(jù)
update T_update01 T1
set infoname=(select T2.infoname from T_update02 T2 where T2.ID=T1.ID)
where exists (select 1 from T_update02 T2 where T2.ID=T1.ID );
-- update set 單列字段 ,更新滿足特定條件ID=1的數(shù)據(jù)
update T_update01 T1
set infoname=(select T2.infoname from T_update02 T2 where T2.ID=T1.ID)
where T1.ID=1;
-- 本次執(zhí)行更新滿足特定條件T_update01表的ID=1
SCOTT@prod02> select * from T_update01;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 update_set_exists 189F5A1099BF6606E0639C0AA8C0F15E
2 2_updateName 189F5A1099C06606E0639C0AA8C0F15E2.2、update set 多列字段
-- T_update01表多插入一行數(shù)據(jù)
insert into T_update01
select 3,N'insert03',sys_guid() from dual;
commit;
select * from T_update01;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 update_set_exists 189F5A1099BF6606E0639C0AA8C0F15E
2 2_updateName 189F5A1099C06606E0639C0AA8C0F15E
3 insert03 189F5A1099C76606E0639C0AA8C0F15E
update T_update01 T1
set (sys_guid,infoname) = (select T2.sys_guid,T2.infoname from T_update02 T2 where T2.ID=T1.ID)
where exists (select 1 from T_update02 T2 where T2.ID=T1.ID );
commit;
-- 更新后檢查,sys_guid,infoname兩列的值和T_update02一樣了
select * from T_update01;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 update_set_exists 189F5A1099C46606E0639C0AA8C0F15E
2 update_set_cursor 189F5A1099C56606E0639C0AA8C0F15E
3 3_Name 189F5A1099C66606E0639C0AA8C0F15E
select * from T_update02;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 update_set_exists 189F5A1099C46606E0639C0AA8C0F15E
2 update_set_cursor 189F5A1099C56606E0639C0AA8C0F15E
3 3_Name 189F5A1099C66606E0639C0AA8C0F15E3、使用游標(biāo)
-- T_update02數(shù)據(jù)更新一下,方便使用游標(biāo)更新的結(jié)果顯示
update T_update02 set INFONAME='cursor is select' where id>=2;
commit;
select * from T_update02;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 update_set_exists 189F5A1099C46606E0639C0AA8C0F15E
2 cursor is select 189F5A1099C56606E0639C0AA8C0F15E
3 cursor is select 189F5A1099C66606E0639C0AA8C0F15E
-- 使用用游標(biāo)更新T_update01的INFONAME字段,使其和T_update02 where id>=2
declare
cursor cur_my_source is select infoname,id from T_update02;
begin
for cur_my_target in cur_my_source loop
update T_update01 set infoname=cur_my_target.infoname where id=cur_my_target.id;
end loop;
commit;
end;
/
-- 檢查查詢結(jié)果
select * from T_update01;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 update_set_exists 189F5A1099C46606E0639C0AA8C0F15E
2 cursor is select 189F5A1099C56606E0639C0AA8C0F15E
3 cursor is select 189F5A1099C66606E0639C0AA8C0F15E4、merge into子句
create table T_merg01(ID int ,infoname varchar2(32),sys_guid varchar2(36));
create table T_merg02(ID int ,infoname varchar2(32),sys_guid varchar2(36));
insert into T_merg01
select 1,N'1_Name',sys_guid() from dual
union
select 2,N'2_Name',sys_guid() from dual;
commit;
select * from T_merg01;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 1_Name 189F5A1099BB6606E0639C0AA8C0F15E
2 2_Name 189F5A1099BC6606E0639C0AA8C0F15E
insert into T_merg02
select 1,N'merge_into_Name1',sys_guid() from dual;
insert into T_merg02
select 3,N'3_Name',sys_guid() from dual;
select * from T_merg02;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 merge_into_Name1 189F5A1099BD6606E0639C0AA8C0F15E
3 3_Name 189F5A1099BE6606E0639C0AA8C0F15E
merge into T_merg01 T1
using T_merg02 T2 on (T1.id=T2.id)
when matched then update set infoname=T2.infoname
when not matched then insert (ID,infoname,sys_guid) values(T2.ID ,T2.infoname,T2.sys_guid);
commit;
select * from T_merg01;
ID INFONAME SYS_GUID
---------- ------------------------------ ------------------------------------
1 merge_into_Name1 189F5A1099BB6606E0639C0AA8C0F15E
2 2_Name 189F5A1099BC6606E0639C0AA8C0F15E
3 3_Name 189F5A1099BE6606E0639C0AA8C0F15E
-- 可以發(fā)現(xiàn)T_merg01表的ID=1的INFONAME=merge_into_Name1和T_merg02表ID=1的值一樣了
-- 可以發(fā)現(xiàn)T_merg01表多了一行數(shù)據(jù)是T_merg02表ID=3的這一行數(shù)據(jù)5、Oracle 23c/AI 新特性
不論是已發(fā)版本Oracle23c free還是最終發(fā)布的長期支持的Oracle23Ai,表關(guān)聯(lián)更新update和刪除delete語句易用且更加優(yōu)雅,類似SQLServer的關(guān)聯(lián)更新
以下操作基于的環(huán)境
SQL*Plus: Release 23.0.0.0.0 - Developer-Release on Fri May 17 11:17:54 2024
Version 23.2.0.0.0
5.1、關(guān)聯(lián)更新update
TESTUSER@FREEPDB1> create table t_emp as select EMPLOYEE_ID,DEPARTMENT_ID,SALARY from employees;
Table created.
TESTUSER@FREEPDB1> desc t_emp;
Name Null? Type
----------------------------------------- -------- ----------------------------
EMPLOYEE_ID NUMBER(6)
DEPARTMENT_ID NUMBER(4)
SALARY NUMBER(8,2)
TESTUSER@FREEPDB1> select * from t_emp where DEPARTMENT_ID=110;
EMPLOYEE_ID DEPARTMENT_ID SALARY
----------- ------------- ----------
205 110 12008
206 110 8300
TESTUSER@FREEPDB1> update t_emp set DEPARTMENT_ID=null,SALARY=null where DEPARTMENT_ID=110;
2 rows updated.
TESTUSER@FREEPDB1> commit;
Commit complete.
TESTUSER@FREEPDB1> select * from t_emp where DEPARTMENT_ID is null;
EMPLOYEE_ID DEPARTMENT_ID SALARY
----------- ------------- ----------
178 7000
205
206
-- oracle 23c SQL增強(qiáng) 表關(guān)聯(lián)更新
TESTUSER@FREEPDB1> update t_emp t1 set t1.DEPARTMENT_ID=t2.DEPARTMENT_ID,t1.SALARY=t2.SALARY from employees t2 where t2.EMPLOYEE_ID=t1.EMPLOYEE_ID and t1.DEPARTMENT_ID is null;
3 row updated.
TESTUSER@FREEPDB1> commit;
Commit complete.
TESTUSER@FREEPDB1> select t1.* from t_emp t1 where t1.DEPARTMENT_ID=110;
EMPLOYEE_ID DEPARTMENT_ID SALARY
----------- ------------- ----------
205 110 12008
206 110 8300
5.2、關(guān)聯(lián)刪除delete
TESTUSER@FREEPDB1> delete t_emp t1 from employees t2 where t2.EMPLOYEE_ID=t1.EMPLOYEE_ID and t2.DEPARTMENT_ID=110; 45 rows deleted. TESTUSER@FREEPDB1> commit; Commit complete. TESTUSER@FREEPDB1> select t1.* from t_emp t1 where t1.DEPARTMENT_ID=110; no rows selected
以上就是Oracle表關(guān)聯(lián)更新幾種方法小結(jié)的詳細(xì)內(nèi)容,更多關(guān)于Oracle表關(guān)聯(lián)更新的資料請關(guān)注腳本之家其它相關(guān)文章!
相關(guān)文章
Oracle數(shù)據(jù)庫聚合函數(shù)XMLAGG詳解(全網(wǎng)最全)
在SQL中,合函數(shù)用于對一組值進(jìn)行計算并返回單一的值,這篇文章主要給大家介紹了關(guān)于Oracle數(shù)據(jù)庫聚合函數(shù)XMLAGG的相關(guān)資料,文中通過代碼介紹的非常詳細(xì),需要的朋友可以參考下2024-06-06
VMware中l(wèi)inux環(huán)境下oracle安裝圖文教程(一)
剛剛接觸ORACLE的人來說,從那里學(xué),如何學(xué),有那些工具可以使用,應(yīng)該執(zhí)行什么操作,一定回感到無助。所以在學(xué)習(xí)使用ORACLE之前,首先來安裝一下ORACLE 10g,在來掌握其基本工具。俗話說的好:工欲善其事,必先利其器。作為一個新手,我們還是先在VMware虛擬機(jī)里安裝吧。2014-08-08
詳解Oracle在out參數(shù)中訪問光標(biāo)
這篇文章主要介紹了詳解Oracle在out參數(shù)中訪問光標(biāo)的相關(guān)資料,這里提供實例代碼幫助大家學(xué)習(xí)理解這部分內(nèi)容,希望能幫助到大家,需要的朋友可以參考下2017-08-08
Oracle數(shù)據(jù)庫中字符串截取最全方法總結(jié)
Oracle提供了多種截取字符串的操作方法,可以根據(jù)具體需求選擇合適的方法進(jìn)行操作,下面這篇文章主要給大家總結(jié)介紹了關(guān)于Oracle數(shù)據(jù)庫中字符串截取的最全方法,需要的朋友可以參考下2024-03-03
Oracle實現(xiàn)動態(tài)SQL的拼裝要領(lǐng)
這篇文章主要介紹了Oracle實現(xiàn)動態(tài)SQL的拼裝要領(lǐng),對于Oracle的進(jìn)一步學(xué)習(xí)來說非常重要,需要的朋友可以參考下2014-07-07
部署Oracle 12c企業(yè)版數(shù)據(jù)庫( 安裝及使用)
這篇文章主要介紹了部署Oracle 12c企業(yè)版數(shù)據(jù)庫( 安裝及使用),文中通過示例代碼介紹的非常詳細(xì),對大家的學(xué)習(xí)或者工作具有一定的參考學(xué)習(xí)價值,需要的朋友們下面隨著小編來一起學(xué)習(xí)學(xué)習(xí)吧2019-11-11

