-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathmerge-statement.sql
187 lines (175 loc) · 4.64 KB
/
merge-statement.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
USE WideWorldImporters
GO
-- Let's create an empty copy of the OrderLines table
SELECT * INTO dbo.OrderLinesCopy FROM Sales.OrderLines WHERE 1 = 2;
-- Table is empty
SELECT * FROM dbo.OrderLinesCopy
-- A simple example of how to use the MERGE statement
MERGE INTO dbo.OrderLinesCopy AS tgt
USING Sales.OrderLines AS src
ON src.OrderLineID = tgt.OrderLineID
WHEN MATCHED AND (src.Quantity < 20) THEN -- We want to see only those who have less than 20 items
UPDATE
SET tgt.TaxRate = (src.TaxRate * 1.1) -- We're increasing the tax by 10 percent
, tgt.PickingCompletedWhen = GETDATE()
, tgt.LastEditedBy = 11
, tgt.LastEditedWhen = GETDATE()
WHEN NOT MATCHED THEN
INSERT
VALUES
(
src.OrderLineID
, src.OrderID
, src.StockItemID
, src.Description
, src.PackageTypeID
, src.Quantity
, src.UnitPrice
, src.TaxRate
, src.PickedQuantity
, src.PickingCompletedWhen
, src.LastEditedBy
, src.LastEditedWhen
);
-- Compare OrderLine vs OrdeLinesCopy table
SELECT COUNT(*) AS TotalOrderLines FROM dbo.OrderLinesCopy;
SELECT COUNT(*) AS TotalOrderLines FROM Sales.OrderLines;
-- Execute again to only update those order that have less than 20 items
MERGE INTO dbo.OrderLinesCopy AS tgt
USING Sales.OrderLines AS src
ON src.OrderLineID = tgt.OrderLineID
WHEN MATCHED AND (src.Quantity < 20) THEN
UPDATE
SET tgt.TaxRate = (src.TaxRate * 1.1) -- We're increasing the tax by 10 percent
, tgt.PickingCompletedWhen = GETDATE()
, tgt.LastEditedBy = 11
, tgt.LastEditedWhen = GETDATE()
WHEN NOT MATCHED THEN
INSERT
VALUES
(
src.OrderLineID
, src.OrderID
, src.StockItemID
, src.Description
, src.PackageTypeID
, src.Quantity
, src.UnitPrice
, src.TaxRate
, src.PickedQuantity
, src.PickingCompletedWhen
, src.LastEditedBy
, src.LastEditedWhen
);
-- Check if was updated only the orders we wanted
SELECT
*
FROM
dbo.OrderLinesCopy
WHERE
Quantity < 20;
-- What if we need to compare all columns?
MERGE INTO dbo.OrderLinesCopy AS tgt
USING Sales.OrderLines AS src
ON src.OrderLineID = tgt.OrderLineID
WHEN MATCHED AND
(
src.StockItemID <> tgt.StockItemID
AND src.Description <> tgt.Description
AND src.Quantity <> tgt.Quantity
AND src.UnitPrice <> tgt.UnitPrice
AND src.TaxRate <> tgt.TaxRate
) THEN
UPDATE
SET tgt.TaxRate = (src.TaxRate * 1.1) -- We're increasing the tax by 10 percent
, tgt.PickingCompletedWhen = GETDATE()
, tgt.LastEditedBy = 11
, tgt.LastEditedWhen = GETDATE()
WHEN NOT MATCHED THEN
INSERT
VALUES
(
src.OrderLineID
, src.OrderID
, src.StockItemID
, src.Description
, src.PackageTypeID
, src.Quantity
, src.UnitPrice
, src.TaxRate
, src.PickedQuantity
, src.PickingCompletedWhen
, src.LastEditedBy
, src.LastEditedWhen
);
-- Use the EXISTS predicate + EXCEPT operator
MERGE INTO dbo.OrderLinesCopy AS tgt
USING Sales.OrderLines AS src
ON src.OrderLineID = tgt.OrderLineID
WHEN MATCHED AND EXISTS
(
SELECT src.StockItemID, src.Description, src.Quantity, src.UnitPrice, src.TaxRate
EXCEPT
SELECT tgt.StockItemID, tgt.Description, tgt.Quantity, tgt.UnitPrice, tgt.TaxRate
) THEN
UPDATE
SET tgt.TaxRate = (src.TaxRate * 1.1)
, tgt.PickingCompletedWhen = GETDATE()
, tgt.LastEditedBy = 11
, tgt.LastEditedWhen = GETDATE()
WHEN NOT MATCHED THEN
INSERT
VALUES
(
src.OrderLineID
, src.OrderID
, src.StockItemID
, src.Description
, src.PackageTypeID
, src.Quantity
, src.UnitPrice
, src.TaxRate
, src.PickedQuantity
, src.PickingCompletedWhen
, src.LastEditedBy
, src.LastEditedWhen
)
OUTPUT
$action AS the_action,
inserted.TaxRate, deleted.TaxRate AS old_TaxRate
, inserted.PickingCompletedWhen, deleted.PickingCompletedWhen AS old_PickingCompletedWhen
, inserted.LastEditedBy, deleted.LastEditedBy AS old_LastEditedBy
, inserted.LastEditedWhen, deleted.LastEditedWhen AS old_LastEditedWhen;
-- Use the EXISTS predicate + EXCEPT operator, for all columns
MERGE INTO dbo.OrderLinesCopy AS tgt
USING Sales.OrderLines AS src
ON src.OrderLineID = tgt.OrderLineID
WHEN MATCHED AND EXISTS (SELECT src.* EXCEPT SELECT tgt.*) THEN
UPDATE
SET tgt.TaxRate = (src.TaxRate * 1.1)
, tgt.PickingCompletedWhen = GETDATE()
, tgt.LastEditedBy = 11
, tgt.LastEditedWhen = GETDATE()
WHEN NOT MATCHED THEN
INSERT
VALUES
(
src.OrderLineID
, src.OrderID
, src.StockItemID
, src.Description
, src.PackageTypeID
, src.Quantity
, src.UnitPrice
, src.TaxRate
, src.PickedQuantity
, src.PickingCompletedWhen
, src.LastEditedBy
, src.LastEditedWhen
)
OUTPUT
$action AS the_action,
inserted.TaxRate, deleted.TaxRate AS old_TaxRate
, inserted.PickingCompletedWhen, deleted.PickingCompletedWhen AS old_PickingCompletedWhen
, inserted.LastEditedBy, deleted.LastEditedBy AS old_LastEditedBy
, inserted.LastEditedWhen, deleted.LastEditedWhen AS old_LastEditedWhen;