Skip to content

Commit 0a10329

Browse files
authored
UPDATE and DELETE via joins (#18)
Signed-off-by: Gerald Venzl <gerald.venzl@oracle.com>
1 parent d25a92a commit 0a10329

File tree

1 file changed

+177
-0
lines changed

1 file changed

+177
-0
lines changed
Lines changed: 177 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,177 @@
1+
= UPDATE/DELETE via JOIN
2+
:database-version: 23.2.0
3+
:database-category: sql
4+
5+
[[feature_summary]]
6+
7+
`UPDATE` and `DELETE` statements can leverage join conditions on other tables
8+
to determine which rows to modify or delete in the source table.
9+
10+
[source,sql]
11+
[subs="verbatim"]
12+
----
13+
-- Get current salary for all employees in the IT department
14+
SELECT e.first_name, e.last_name, e.salary
15+
FROM employees e, departments d
16+
WHERE e.department_id=d.department_id
17+
AND d.department_name = 'IT';
18+
19+
-- Increase salary by 50% for all employees in the IT department
20+
UPDATE employees e SET e.salary=e.salary*1.5
21+
FROM departments d
22+
WHERE e.department_id=d.department_id
23+
AND d.department_name = 'IT';
24+
25+
-- Verify changes
26+
SELECT e.first_name, e.last_name, e.salary
27+
FROM employees e, departments d
28+
WHERE e.department_id=d.department_id
29+
AND d.department_name = 'IT';
30+
31+
-- Commit changes
32+
COMMIT;
33+
34+
-- Get all Sales Reps who were hired before the 1st of January 2016
35+
SELECT e.first_name, e.last_name, e.hire_date
36+
FROM employees e, departments d, jobs j
37+
WHERE e.department_id=d.department_id
38+
AND d.department_name = 'Sales'
39+
AND e.job_id=j.job_id
40+
AND j.job_title = 'Sales Representative'
41+
AND e.hire_date < TO_DATE('01-JAN-16','DD-MON-YY');
42+
43+
-- Delete all Sales Reps who were hired before the 1st of January 2016
44+
DELETE FROM employees e
45+
FROM departments d, jobs j
46+
WHERE e.department_id=d.department_id
47+
AND d.department_name = 'Sales'
48+
AND e.job_id=j.job_id
49+
AND j.job_title = 'Sales Representative'
50+
AND e.hire_date < TO_DATE('01-JAN-16','DD-MON-YY');
51+
52+
-- Verify changes
53+
SELECT e.first_name, e.last_name, e.hire_date
54+
FROM employees e, departments d, jobs j
55+
WHERE e.department_id=d.department_id
56+
AND d.department_name = 'Sales'
57+
AND e.job_id=j.job_id
58+
AND j.job_title = 'Sales Representative'
59+
AND e.hire_date < TO_DATE('01-JAN-16','DD-MON-YY');
60+
61+
-- Commit changes
62+
COMMIT;
63+
----
64+
65+
.Result
66+
[source,sql]
67+
[subs="verbatim"]
68+
----
69+
SQL> -- Get current salary for all employees in the IT department
70+
SQL> SELECT e.first_name, e.last_name, e.salary
71+
2 FROM employees e, departments d
72+
3 WHERE e.department_id=d.department_id
73+
4* AND d.department_name = 'IT';
74+
75+
FIRST_NAME LAST_NAME SALARY
76+
_____________ ____________ _________
77+
Alexander James 9000
78+
Bruce Miller 6000
79+
David Williams 4800
80+
Valli Jackson 4800
81+
Diana Nguyen 4200
82+
83+
SQL>
84+
SQL> -- Increase salary by 50% for all employees in the IT department
85+
SQL> UPDATE employees e SET e.salary=e.salary*1.5
86+
2 FROM departments d
87+
3 WHERE e.department_id=d.department_id
88+
4* AND d.department_name = 'IT';
89+
90+
5 rows updated.
91+
92+
SQL>
93+
SQL> -- Verify changes
94+
SQL> SELECT e.first_name, e.last_name, e.salary
95+
2 FROM employees e, departments d
96+
3 WHERE e.department_id=d.department_id
97+
4* AND d.department_name = 'IT';
98+
99+
FIRST_NAME LAST_NAME SALARY
100+
_____________ ____________ _________
101+
Alexander James 13500
102+
Bruce Miller 9000
103+
David Williams 7200
104+
Valli Jackson 7200
105+
Diana Nguyen 6300
106+
107+
SQL>
108+
SQL> -- Commit changes
109+
SQL> COMMIT;
110+
111+
Commit complete.
112+
113+
SQL> -- Get all Sales Reps who were hired before the 1st of January 2016
114+
SQL> SELECT e.first_name, e.last_name, e.hire_date
115+
2 FROM employees e, departments d, jobs j
116+
3 WHERE e.department_id=d.department_id
117+
4 AND d.department_name = 'Sales'
118+
5 AND e.job_id=j.job_id
119+
6 AND j.job_title = 'Sales Representative'
120+
7* AND e.hire_date < TO_DATE('01-JAN-16','DD-MON-YY');
121+
122+
FIRST_NAME LAST_NAME HIRE_DATE
123+
_____________ ____________ ____________
124+
Sean Tucker 30-JAN-15
125+
David Bernstein 24-MAR-15
126+
Peter Hall 20-AUG-15
127+
Janette King 30-JAN-14
128+
Patrick Sully 04-MAR-14
129+
Allan McEwen 01-AUG-14
130+
Lindsey Smith 10-MAR-15
131+
Louise Doran 15-DEC-15
132+
Clara Vishney 11-NOV-15
133+
Lisa Ozer 11-MAR-15
134+
Ellen Abel 11-MAY-14
135+
Alyssa Hutton 19-MAR-15
136+
137+
12 rows selected.
138+
139+
SQL>
140+
SQL> -- Delete all Sales Reps who were hired before the 1st of January 2016
141+
SQL> DELETE FROM employees e
142+
2 FROM departments d, jobs j
143+
3 WHERE e.department_id=d.department_id
144+
4 AND d.department_name = 'Sales'
145+
5 AND e.job_id=j.job_id
146+
6 AND j.job_title = 'Sales Representative'
147+
7* AND e.hire_date < TO_DATE('01-JAN-16','DD-MON-YY');
148+
149+
12 rows deleted.
150+
151+
SQL>
152+
SQL> -- Verify changes
153+
SQL> SELECT e.first_name, e.last_name, e.hire_date
154+
2 FROM employees e, departments d, jobs j
155+
3 WHERE e.department_id=d.department_id
156+
4 AND d.department_name = 'Sales'
157+
5 AND e.job_id=j.job_id
158+
6 AND j.job_title = 'Sales Representative'
159+
7* AND e.hire_date < TO_DATE('01-JAN-16','DD-MON-YY');
160+
161+
no rows selected
162+
SQL>
163+
SQL> -- Commit changes
164+
SQL> COMMIT;
165+
166+
Commit complete.
167+
----
168+
169+
== Benefits
170+
171+
Leveraging joins as part of `UPDATE` and `DELETE` statements
172+
makes writing, executing and reading data manipulation statements easier.
173+
174+
== Further information
175+
176+
* Availability: All Offerings
177+
* link:https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/UPDATE.html[UPDATE statement] and link:https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/DELETE.html[DELETE statement]

0 commit comments

Comments
 (0)