should be it
This commit is contained in:
117
external/duckdb/test/sql/merge/merge_into.test
vendored
Normal file
117
external/duckdb/test/sql/merge/merge_into.test
vendored
Normal file
@@ -0,0 +1,117 @@
|
||||
# name: test/sql/merge/merge_into.test
|
||||
# description: Test MERGE INTO
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Stock(item_id int, balance int);
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Buy(item_id int, volume int);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Buy values(10, 1000);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Buy values(30, 300);
|
||||
|
||||
# insert using merge into with a CTE
|
||||
query I
|
||||
WITH initial_stocks(item_id, balance) AS (VALUES (10, 2200), (20, 1900))
|
||||
MERGE INTO Stock USING initial_stocks ON FALSE
|
||||
WHEN MATCHED THEN DO NOTHING
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (initial_stocks.item_id, initial_stocks.balance)
|
||||
----
|
||||
2
|
||||
|
||||
# DO NOTHING is the default - this is a nop
|
||||
query I
|
||||
WITH initial_stocks(item_id, balance) AS (VALUES (10, 2200), (20, 1900))
|
||||
MERGE INTO Stock USING initial_stocks USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (item_id, initial_stocks.balance)
|
||||
----
|
||||
0
|
||||
|
||||
query II
|
||||
FROM Stock ORDER BY item_id
|
||||
----
|
||||
10 2200
|
||||
20 1900
|
||||
|
||||
# update and insert
|
||||
query I
|
||||
MERGE INTO Stock AS s USING Buy AS b ON s.item_id = b.item_id
|
||||
WHEN MATCHED THEN UPDATE SET balance = balance + b.volume
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (b.item_id, b.volume)
|
||||
----
|
||||
2
|
||||
|
||||
query II
|
||||
FROM Stock ORDER BY item_id
|
||||
----
|
||||
10 3200
|
||||
20 1900
|
||||
30 300
|
||||
|
||||
# sell - deleting all rows that are fully sold
|
||||
statement ok
|
||||
CREATE TABLE Sale(item_id int, volume int);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Sale VALUES (10, 2200);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Sale VALUES (20, 1900);
|
||||
|
||||
query I
|
||||
MERGE INTO Stock USING Sale ON Stock.item_id = Sale.item_id
|
||||
WHEN MATCHED AND Sale.volume > balance THEN ERROR
|
||||
WHEN MATCHED AND Sale.volume = balance THEN DELETE
|
||||
WHEN MATCHED AND TRUE THEN UPDATE SET balance = balance - Sale.volume
|
||||
WHEN MATCHED THEN ERROR
|
||||
WHEN NOT MATCHED THEN ERROR
|
||||
----
|
||||
2
|
||||
|
||||
query II
|
||||
FROM Stock ORDER BY item_id
|
||||
----
|
||||
10 1000
|
||||
30 300
|
||||
|
||||
# abort - row does not exist
|
||||
statement error
|
||||
MERGE INTO Stock USING Sale ON Stock.item_id = Sale.item_id
|
||||
WHEN MATCHED AND Sale.volume >= balance THEN DELETE
|
||||
WHEN MATCHED THEN UPDATE SET balance = balance - Sale.volume
|
||||
WHEN NOT MATCHED THEN ERROR CONCAT('Sale item with item id ', Sale.item_id, ' not found');
|
||||
----
|
||||
Sale item with item id 20 not found
|
||||
|
||||
# we need to specify at least one match action
|
||||
statement error
|
||||
WITH initial_stocks(item_id, balance) AS (VALUES (10, 2200), (20, 1900))
|
||||
MERGE INTO Stock USING initial_stocks ON (Stock.item_id = initial_stocks.item_id)
|
||||
----
|
||||
Parser
|
||||
|
||||
# we cannot specify an unconditional WHEN NOT MATCHED clause
|
||||
statement error
|
||||
WITH initial_stocks(item_id, balance) AS (VALUES (10, 2200), (20, 1900))
|
||||
MERGE INTO Stock USING initial_stocks ON (Stock.item_id = initial_stocks.item_id)
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (initial_stocks.item_id, initial_stocks.balance)
|
||||
WHEN NOT MATCHED THEN ERROR;
|
||||
----
|
||||
only one unconditional WHEN NOT MATCHED clause
|
||||
|
||||
# we cannot merge into views
|
||||
statement ok
|
||||
CREATE VIEW my_view AS SELECT 42 item_id
|
||||
|
||||
statement error
|
||||
MERGE INTO my_view USING Sale ON my_view.item_id = Sale.item_id
|
||||
WHEN NOT MATCHED THEN INSERT
|
||||
----
|
||||
base tables
|
||||
42
external/duckdb/test/sql/merge/merge_into_by_source.test
vendored
Normal file
42
external/duckdb/test/sql/merge/merge_into_by_source.test
vendored
Normal file
@@ -0,0 +1,42 @@
|
||||
# name: test/sql/merge/merge_into_by_source.test
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Stock(item_id int, balance int);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Stock VALUES (5, 10), (10, 20), (20, 30);
|
||||
|
||||
# WHEN NOT MATCHED BY SOURCE
|
||||
# basically, this turns "Stock" into "new_accounts"
|
||||
# -> if we have a match we update to the new value
|
||||
# -> if we have a row in new_accounts that does not exist in Stock, insert it
|
||||
# -> if we have a row in Stock that does not exist in new_accounts, delete it
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (5, 20), (10, 30)) new_accounts(item_id, balance) USING (item_id)
|
||||
WHEN MATCHED THEN UPDATE
|
||||
WHEN NOT MATCHED BY TARGET THEN INSERT
|
||||
WHEN NOT MATCHED BY SOURCE THEN DELETE
|
||||
----
|
||||
3
|
||||
|
||||
query II
|
||||
FROM Stock ORDER BY ALL
|
||||
----
|
||||
5 20
|
||||
10 30
|
||||
|
||||
# WHEN NOT MATCHED BY SOURCE only
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (10)) new_accounts(item_id) USING (item_id)
|
||||
WHEN NOT MATCHED BY SOURCE THEN DELETE
|
||||
----
|
||||
1
|
||||
|
||||
query II
|
||||
FROM Stock ORDER BY ALL
|
||||
----
|
||||
10 30
|
||||
48
external/duckdb/test/sql/merge/merge_into_constraint.test
vendored
Normal file
48
external/duckdb/test/sql/merge/merge_into_constraint.test
vendored
Normal file
@@ -0,0 +1,48 @@
|
||||
# name: test/sql/merge/merge_into_constraint.test
|
||||
# description: Test MERGE INTO with constraints
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Stock(item_id int NOT NULL, balance int, CHECK (balance>0));
|
||||
|
||||
statement error
|
||||
MERGE INTO Stock USING (VALUES (NULL, NULL)) new_accounts(item_id, balance) USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (new_accounts.item_id, new_accounts.balance)
|
||||
----
|
||||
NOT NULL constraint
|
||||
|
||||
statement ok
|
||||
MERGE INTO Stock USING (VALUES (1, 10)) new_accounts(item_id, balance) USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (new_accounts.item_id, new_accounts.balance)
|
||||
|
||||
# trying to delete too much
|
||||
statement error
|
||||
MERGE INTO Stock USING (VALUES (1, 15)) sales(item_id, volume) USING (item_id)
|
||||
WHEN MATCHED THEN UPDATE SET balance = balance - volume
|
||||
----
|
||||
CHECK constraint
|
||||
|
||||
# binding with check constraints
|
||||
statement ok
|
||||
CREATE TABLE Items(item_id int NOT NULL, total_cost INTEGER, base_cost INTEGER, tax_cost INTEGER, CHECK (total_cost = base_cost + tax_cost));
|
||||
|
||||
statement ok
|
||||
INSERT INTO Items VALUES (1, 10, 8, 2);
|
||||
|
||||
statement error
|
||||
MERGE INTO Items USING (VALUES (1, 15)) new_prices(item_id, total_cost) USING (item_id)
|
||||
WHEN MATCHED THEN UPDATE SET total_cost = new_prices.total_cost
|
||||
----
|
||||
CHECK constraint
|
||||
|
||||
statement ok
|
||||
MERGE INTO Items USING (VALUES (1, 15)) new_prices(item_id, total_cost) USING (item_id)
|
||||
WHEN MATCHED THEN UPDATE SET total_cost = new_prices.total_cost, base_cost = new_prices.total_cost - 2
|
||||
|
||||
query IIII
|
||||
FROM Items
|
||||
----
|
||||
1 15 13 2
|
||||
55
external/duckdb/test/sql/merge/merge_into_default.test
vendored
Normal file
55
external/duckdb/test/sql/merge/merge_into_default.test
vendored
Normal file
@@ -0,0 +1,55 @@
|
||||
# name: test/sql/merge/merge_into_default.test
|
||||
# description: Test MERGE INTO with default values
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Stock(item_id int, balance int DEFAULT 0);
|
||||
|
||||
# explicit default
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (10)) new_accounts(item_id) USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (new_accounts.item_id, DEFAULT)
|
||||
----
|
||||
1
|
||||
|
||||
# column list
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (20)) new_accounts(item_id) USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT (item_id) VALUES (new_accounts.item_id)
|
||||
----
|
||||
1
|
||||
|
||||
# default values
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (30)) new_accounts(item_id) USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT DEFAULT VALUES
|
||||
----
|
||||
1
|
||||
|
||||
query II
|
||||
FROM Stock
|
||||
----
|
||||
10 0
|
||||
20 0
|
||||
NULL 0
|
||||
|
||||
statement ok
|
||||
UPDATE Stock SET balance=100
|
||||
|
||||
# update default
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (10)) reset_accounts(item_id) USING (item_id)
|
||||
WHEN MATCHED THEN UPDATE SET balance=DEFAULT
|
||||
WHEN NOT MATCHED THEN ERROR
|
||||
----
|
||||
1
|
||||
|
||||
query II
|
||||
FROM Stock
|
||||
----
|
||||
10 0
|
||||
20 100
|
||||
NULL 100
|
||||
30
external/duckdb/test/sql/merge/merge_into_error.test
vendored
Normal file
30
external/duckdb/test/sql/merge/merge_into_error.test
vendored
Normal file
@@ -0,0 +1,30 @@
|
||||
# name: test/sql/merge/merge_into_error.test
|
||||
# description: Test MERGE INTO with error in condition
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Stock(item_id int, balance int);
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Buys(item_id int, volume int);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Buys VALUES (42, 100);
|
||||
|
||||
query I
|
||||
MERGE INTO Stock USING Buys USING (item_id)
|
||||
WHEN NOT MATCHED AND true THEN INSERT
|
||||
WHEN NOT MATCHED AND error('this should not be executed') THEN INSERT
|
||||
WHEN NOT MATCHED THEN ERROR
|
||||
----
|
||||
1
|
||||
|
||||
query I
|
||||
SELECT COUNT(*) FROM Stock
|
||||
----
|
||||
1
|
||||
|
||||
query II
|
||||
FROM Stock
|
||||
----
|
||||
42 100
|
||||
26
external/duckdb/test/sql/merge/merge_into_index.test
vendored
Normal file
26
external/duckdb/test/sql/merge/merge_into_index.test
vendored
Normal file
@@ -0,0 +1,26 @@
|
||||
# name: test/sql/merge/merge_into_index.test
|
||||
# description: Test MERGE INTO with an index
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Accounts(id INTEGER, username VARCHAR PRIMARY KEY, favorite_numbers INT[]);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Accounts VALUES (1, 'user1', NULL)
|
||||
|
||||
query I
|
||||
MERGE INTO Accounts USING (
|
||||
VALUES (1, 'user2', [1, 2, 3])
|
||||
) new_account(id) USING (id)
|
||||
WHEN MATCHED THEN UPDATE
|
||||
WHEN NOT MATCHED THEN INSERT
|
||||
----
|
||||
1
|
||||
|
||||
query III
|
||||
FROM Accounts WHERE username='user2'
|
||||
----
|
||||
1 user2 [1, 2, 3]
|
||||
49
external/duckdb/test/sql/merge/merge_into_insert_star.test
vendored
Normal file
49
external/duckdb/test/sql/merge/merge_into_insert_star.test
vendored
Normal file
@@ -0,0 +1,49 @@
|
||||
# name: test/sql/merge/merge_into_insert_star.test
|
||||
# description: Test MERGE INTO INSERT *
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Stock(item_id int, balance int DEFAULT 0);
|
||||
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (5, 10)) new_accounts(item_id, balance) USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT *
|
||||
----
|
||||
1
|
||||
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (6, 12)) new_accounts(item_id, balance) USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT
|
||||
----
|
||||
1
|
||||
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (0, 7)) new_accounts(balance, item_id) USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT BY NAME
|
||||
----
|
||||
1
|
||||
|
||||
# name mismatch
|
||||
statement error
|
||||
MERGE INTO Stock USING (VALUES (0, 7)) new_accounts(balanc, item_id) USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT BY NAME
|
||||
----
|
||||
balance
|
||||
|
||||
# missing column
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (12)) new_accounts(item_id) USING (item_id)
|
||||
WHEN NOT MATCHED THEN INSERT BY NAME
|
||||
----
|
||||
1
|
||||
|
||||
query II
|
||||
FROM Stock
|
||||
----
|
||||
5 10
|
||||
6 12
|
||||
7 0
|
||||
12 0
|
||||
34
external/duckdb/test/sql/merge/merge_into_multiple_inserts.test_slow
vendored
Normal file
34
external/duckdb/test/sql/merge/merge_into_multiple_inserts.test_slow
vendored
Normal file
@@ -0,0 +1,34 @@
|
||||
# name: test/sql/merge/merge_into_multiple_inserts.test_slow
|
||||
# description: Test MERGE INTO with multiple inserts
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Stock(item_id int, balance int);
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Buys(item_id int, volume int);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Buys SELECT i, (random() * 100)::INT FROM range(1000000) t(i);
|
||||
|
||||
query I
|
||||
MERGE INTO Stock USING Buys USING (item_id)
|
||||
WHEN MATCHED THEN ERROR
|
||||
WHEN NOT MATCHED BY TARGET AND random() < 0.3 THEN INSERT
|
||||
WHEN NOT MATCHED BY TARGET AND random() < 0.3 THEN INSERT
|
||||
WHEN NOT MATCHED BY TARGET THEN INSERT
|
||||
----
|
||||
1000000
|
||||
|
||||
query I
|
||||
SELECT COUNT(*) FROM Stock
|
||||
----
|
||||
1000000
|
||||
|
||||
query II
|
||||
FROM Buys EXCEPT FROM Stock
|
||||
----
|
||||
|
||||
query II
|
||||
FROM Stock EXCEPT FROM Buys
|
||||
----
|
||||
46
external/duckdb/test/sql/merge/merge_into_multiple_updates.test
vendored
Normal file
46
external/duckdb/test/sql/merge/merge_into_multiple_updates.test
vendored
Normal file
@@ -0,0 +1,46 @@
|
||||
# name: test/sql/merge/merge_into_multiple_updates.test
|
||||
# description: Test MERGE INTO with multiple different update clauses
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Entry(type varchar, number int, text varchar, country VARCHAR, date DATE);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Entry VALUES
|
||||
('number', 50, NULL, NULL, NULL),
|
||||
('text', NULL, 'Hello', NULL, NULL),
|
||||
('country', NULL, NULL, 'Netherlands', NULL),
|
||||
('date', NULL, NULL, NULL, DATE '2000-01-01');
|
||||
|
||||
|
||||
statement ok
|
||||
CREATE TABLE NewEntry(type varchar, number int, text varchar, country VARCHAR, date DATE);
|
||||
|
||||
statement ok
|
||||
INSERT INTO NewEntry VALUES
|
||||
('number', 100, NULL, NULL, NULL),
|
||||
('text', NULL, 'World', NULL, NULL),
|
||||
('country', NULL, NULL, 'Germany', NULL),
|
||||
('date', NULL, NULL, NULL, DATE '2010-01-01');
|
||||
|
||||
|
||||
query I
|
||||
MERGE INTO Entry USING NewEntry ON Entry.type=NewEntry.type
|
||||
WHEN MATCHED AND Entry.type='number' THEN UPDATE SET number=NewEntry.number
|
||||
WHEN MATCHED AND Entry.type='text' THEN UPDATE SET text=NewEntry.text
|
||||
WHEN MATCHED AND Entry.type='country' THEN UPDATE SET country=NewEntry.country
|
||||
WHEN MATCHED AND Entry.type='date' THEN UPDATE SET date=NewEntry.date
|
||||
WHEN MATCHED THEN ERROR
|
||||
----
|
||||
4
|
||||
|
||||
query IIIII
|
||||
FROM Entry ORDER BY type
|
||||
----
|
||||
country NULL NULL Germany NULL
|
||||
date NULL NULL NULL 2010-01-01
|
||||
number 100 NULL NULL NULL
|
||||
text NULL World NULL NULL
|
||||
37
external/duckdb/test/sql/merge/merge_into_parenthesis_bug.test
vendored
Normal file
37
external/duckdb/test/sql/merge/merge_into_parenthesis_bug.test
vendored
Normal file
@@ -0,0 +1,37 @@
|
||||
# name: test/sql/merge/merge_into_parenthesis_bug.test
|
||||
# description: Test MERGE issue when condition is in parenthesis
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE my_timeseries (ts TIMESTAMP, x DOUBLE PRECISION, y DOUBLE PRECISION);
|
||||
|
||||
statement ok
|
||||
insert into my_timeseries VALUES ('2025-09-15', 43, 39)
|
||||
|
||||
statement ok
|
||||
CREATE TABLE my_timeseries_new (ts TIMESTAMP, x DOUBLE PRECISION, y DOUBLE PRECISION);
|
||||
|
||||
statement ok
|
||||
insert into my_timeseries_new VALUES ('2025-09-15', 43, 39)
|
||||
|
||||
statement ok
|
||||
MERGE INTO my_timeseries old
|
||||
USING my_timeseries_new new
|
||||
ON (
|
||||
old.x = new.x AND
|
||||
( old.ts != new.ts
|
||||
OR old.x = 1
|
||||
)
|
||||
)
|
||||
WHEN MATCHED THEN UPDATE;
|
||||
|
||||
statement ok
|
||||
MERGE INTO my_timeseries old
|
||||
USING my_timeseries_new new
|
||||
USING(ts)
|
||||
WHEN MATCHED AND (
|
||||
old.x IS DISTINCT FROM new.y
|
||||
) THEN UPDATE;
|
||||
77
external/duckdb/test/sql/merge/merge_into_returning.test
vendored
Normal file
77
external/duckdb/test/sql/merge/merge_into_returning.test
vendored
Normal file
@@ -0,0 +1,77 @@
|
||||
# name: test/sql/merge/merge_into_returning.test
|
||||
# description: Test MERGE INTO with RETURNING
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Stock(item_id int, balance int);
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Buy(item_id int, volume int);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Buy values(10, 1000);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Buy values(30, 300);
|
||||
|
||||
# basic returning
|
||||
query III
|
||||
WITH initial_stocks(item_id, balance) AS (VALUES (10, 2200), (20, 1900))
|
||||
MERGE INTO Stock USING initial_stocks ON FALSE
|
||||
WHEN MATCHED THEN DO NOTHING
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (initial_stocks.item_id, initial_stocks.balance)
|
||||
RETURNING merge_action, *
|
||||
----
|
||||
INSERT 10 2200
|
||||
INSERT 20 1900
|
||||
|
||||
# do nothing returns nothing
|
||||
query II
|
||||
WITH initial_stocks(item_id, balance) AS (VALUES (10, 2200), (20, 1900))
|
||||
MERGE INTO Stock USING initial_stocks ON (Stock.item_id = initial_stocks.item_id)
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (initial_stocks.item_id, initial_stocks.balance)
|
||||
RETURNING *
|
||||
----
|
||||
|
||||
# update and insert
|
||||
query III
|
||||
MERGE INTO Stock AS s USING Buy AS b ON s.item_id = b.item_id
|
||||
WHEN MATCHED THEN UPDATE SET balance = balance + b.volume
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (b.item_id, b.volume)
|
||||
RETURNING *, merge_action;
|
||||
----
|
||||
10 3200 UPDATE
|
||||
30 300 INSERT
|
||||
|
||||
# sell - deleting all rows that are fully sold
|
||||
statement ok
|
||||
CREATE TABLE Sale(item_id int, volume int);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Sale VALUES (10, 2200);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Sale VALUES (20, 1900);
|
||||
|
||||
query III
|
||||
MERGE INTO Stock USING Sale ON Stock.item_id = Sale.item_id
|
||||
WHEN MATCHED AND Sale.volume > balance THEN ERROR
|
||||
WHEN MATCHED AND Sale.volume = balance THEN DELETE
|
||||
WHEN MATCHED AND TRUE THEN UPDATE SET balance = balance - Sale.volume
|
||||
WHEN MATCHED THEN ERROR
|
||||
WHEN NOT MATCHED THEN ERROR
|
||||
RETURNING Stock.item_id, merge_action, Stock.balance
|
||||
----
|
||||
20 DELETE 1900
|
||||
10 UPDATE 1000
|
||||
|
||||
query III
|
||||
WITH deleted_stocks(item_id) AS (VALUES (30))
|
||||
MERGE INTO Stock USING deleted_stocks ON Stock.item_id = deleted_stocks.item_id
|
||||
WHEN MATCHED THEN DELETE
|
||||
RETURNING *, merge_action;
|
||||
----
|
||||
30 300 DELETE
|
||||
45
external/duckdb/test/sql/merge/merge_into_subquery.test
vendored
Normal file
45
external/duckdb/test/sql/merge/merge_into_subquery.test
vendored
Normal file
@@ -0,0 +1,45 @@
|
||||
# name: test/sql/merge/merge_into_subquery.test
|
||||
# description: Test MERGE INTO with subqueries
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Totals(item_id int, balance int);
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Buy(item_id int, volume int);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Buy values(10, 1000), (30, 300), (20, 2000);
|
||||
|
||||
query I
|
||||
MERGE INTO Totals USING (VALUES (10), (30)) Updates(item_id) ON Totals.item_id = Updates.item_id
|
||||
WHEN MATCHED THEN UPDATE SET balance = (SELECT SUM(volume) FROM Buy WHERE item_id=Totals.item_id)
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (Updates.item_id, (SELECT SUM(volume) FROM Buy WHERE item_id=Updates.item_id));
|
||||
----
|
||||
2
|
||||
|
||||
query II
|
||||
FROM Totals ORDER BY ALL
|
||||
----
|
||||
10 1000
|
||||
30 300
|
||||
|
||||
statement ok
|
||||
INSERT INTO Buy values(10, 2000)
|
||||
|
||||
query I
|
||||
MERGE INTO Totals USING (VALUES (10), (20)) Updates(item_id) ON Totals.item_id = Updates.item_id
|
||||
WHEN MATCHED THEN UPDATE SET balance = (SELECT SUM(volume) FROM Buy WHERE item_id=Totals.item_id)
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (Updates.item_id, (SELECT SUM(volume) FROM Buy WHERE item_id=Updates.item_id));
|
||||
----
|
||||
2
|
||||
|
||||
query II
|
||||
FROM Totals ORDER BY ALL
|
||||
----
|
||||
10 3000
|
||||
20 2000
|
||||
30 300
|
||||
21
external/duckdb/test/sql/merge/merge_into_too_few_columns.test
vendored
Normal file
21
external/duckdb/test/sql/merge/merge_into_too_few_columns.test
vendored
Normal file
@@ -0,0 +1,21 @@
|
||||
# name: test/sql/merge/merge_into_too_few_columns.test
|
||||
# description: Test MERGE INTO with too few columns
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
CREATE TABLE people (id INTEGER, name VARCHAR, salary FLOAT);
|
||||
|
||||
statement ok
|
||||
INSERT INTO people VALUES (1, 'John', 92_000.0), (2, 'Anna', 100_000.0);
|
||||
|
||||
statement error
|
||||
MERGE INTO people
|
||||
USING (
|
||||
SELECT
|
||||
3 AS id,
|
||||
89_000.0 AS salary
|
||||
) AS upserts
|
||||
ON (upserts.id = people.id)
|
||||
WHEN NOT MATCHED THEN INSERT;
|
||||
----
|
||||
has 3 columns but 2 values were supplied
|
||||
55
external/duckdb/test/sql/merge/merge_into_tpch.test_slow
vendored
Normal file
55
external/duckdb/test/sql/merge/merge_into_tpch.test_slow
vendored
Normal file
@@ -0,0 +1,55 @@
|
||||
# name: test/sql/merge/merge_into_tpch.test_slow
|
||||
# description: Test merge into with TPC-H SF1
|
||||
# group: [merge]
|
||||
|
||||
require tpch
|
||||
|
||||
statement ok
|
||||
CALL dbgen(sf=1);
|
||||
|
||||
foreach it no_index index
|
||||
|
||||
statement ok
|
||||
CREATE TABLE random_lineitem AS FROM lineitem LIMIT 0
|
||||
|
||||
onlyif it=index
|
||||
statement ok
|
||||
ALTER TABLE random_lineitem ADD PRIMARY KEY (l_orderkey, l_linenumber);
|
||||
|
||||
# create lineitem but with a random subset of the rows
|
||||
statement ok
|
||||
MERGE INTO random_lineitem USING lineitem USING (l_orderkey, l_linenumber)
|
||||
WHEN NOT MATCHED AND random() < 0.2 THEN INSERT
|
||||
|
||||
# insert a bunch of rows with unchanged values
|
||||
statement ok
|
||||
MERGE INTO random_lineitem USING (SELECT * REPLACE (l_orderkey + 10000000 AS l_orderkey) FROM lineitem) USING (l_orderkey, l_linenumber)
|
||||
WHEN MATCHED THEN ERROR
|
||||
WHEN NOT MATCHED AND random() < 0.2 THEN INSERT
|
||||
|
||||
# randomly update a bunch of rows
|
||||
statement ok
|
||||
MERGE INTO random_lineitem USING lineitem USING (l_orderkey, l_linenumber)
|
||||
WHEN MATCHED AND random() < 0.1 THEN UPDATE SET l_discount = random()
|
||||
WHEN MATCHED AND random() < 0.1 THEN UPDATE SET l_tax = random()
|
||||
|
||||
# run a merge that should fully equalize the tables
|
||||
statement ok
|
||||
MERGE INTO random_lineitem USING lineitem USING (l_orderkey, l_linenumber)
|
||||
WHEN MATCHED THEN UPDATE
|
||||
WHEN NOT MATCHED BY TARGET THEN INSERT
|
||||
WHEN NOT MATCHED BY SOURCE THEN DELETE
|
||||
|
||||
# both tables should now be identical - despite all the random stuff we did
|
||||
query IIIIIIIIIIIIIIII
|
||||
FROM lineitem EXCEPT FROM random_lineitem
|
||||
----
|
||||
|
||||
query IIIIIIIIIIIIIIII
|
||||
FROM random_lineitem EXCEPT FROM lineitem
|
||||
----
|
||||
|
||||
statement ok
|
||||
DROP TABLE random_lineitem
|
||||
|
||||
endloop
|
||||
60
external/duckdb/test/sql/merge/merge_into_tpch_by_name.test_slow
vendored
Normal file
60
external/duckdb/test/sql/merge/merge_into_tpch_by_name.test_slow
vendored
Normal file
@@ -0,0 +1,60 @@
|
||||
# name: test/sql/merge/merge_into_tpch_by_name.test_slow
|
||||
# description: Test merge into by name TPC-H SF1
|
||||
# group: [merge]
|
||||
|
||||
require tpch
|
||||
|
||||
statement ok
|
||||
CALL dbgen(sf=0.1);
|
||||
|
||||
foreach it index no_index
|
||||
|
||||
# create random_lineitem with columns in random order
|
||||
statement ok
|
||||
CREATE TABLE random_lineitem AS SELECT l_tax, l_returnflag, l_partkey, l_shipmode, l_discount, l_quantity, l_shipdate, l_extendedprice, l_receiptdate, l_suppkey, l_comment, l_linenumber, l_commitdate, l_orderkey, l_linestatus, l_shipinstruct
|
||||
FROM lineitem LIMIT 0
|
||||
|
||||
onlyif it=index
|
||||
statement ok
|
||||
ALTER TABLE random_lineitem ADD PRIMARY KEY (l_orderkey, l_linenumber);
|
||||
|
||||
# create lineitem but with a random subset of the rows
|
||||
statement ok
|
||||
MERGE INTO random_lineitem USING lineitem USING (l_orderkey, l_linenumber)
|
||||
WHEN NOT MATCHED AND random() < 0.2 THEN INSERT BY NAME
|
||||
|
||||
# insert a bunch of rows with unchanged values
|
||||
statement ok
|
||||
MERGE INTO random_lineitem USING (SELECT * REPLACE (l_orderkey + 10000000 AS l_orderkey) FROM lineitem) USING (l_orderkey, l_linenumber)
|
||||
WHEN MATCHED THEN ERROR
|
||||
WHEN NOT MATCHED AND random() < 0.2 THEN INSERT BY NAME
|
||||
|
||||
# randomly update a bunch of rows
|
||||
statement ok
|
||||
MERGE INTO random_lineitem USING lineitem USING (l_orderkey, l_linenumber)
|
||||
WHEN MATCHED AND random() < 0.1 THEN UPDATE SET l_discount = random()
|
||||
WHEN MATCHED AND random() < 0.1 THEN UPDATE SET l_tax = random()
|
||||
|
||||
# run a merge that should fully equalize the tables
|
||||
statement ok
|
||||
MERGE INTO random_lineitem USING lineitem USING (l_orderkey, l_linenumber)
|
||||
WHEN MATCHED THEN UPDATE BY NAME
|
||||
WHEN NOT MATCHED BY TARGET THEN INSERT BY NAME
|
||||
WHEN NOT MATCHED BY SOURCE THEN DELETE
|
||||
|
||||
# both tables should now be identical - despite all the random stuff we did
|
||||
query IIIIIIIIIIIIIIII
|
||||
FROM lineitem
|
||||
EXCEPT
|
||||
SELECT l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment FROM random_lineitem
|
||||
----
|
||||
|
||||
query IIIIIIIIIIIIIIII
|
||||
SELECT l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment FROM random_lineitem
|
||||
EXCEPT FROM lineitem
|
||||
----
|
||||
|
||||
statement ok
|
||||
DROP TABLE random_lineitem
|
||||
|
||||
endloop
|
||||
51
external/duckdb/test/sql/merge/merge_into_update_star.test
vendored
Normal file
51
external/duckdb/test/sql/merge/merge_into_update_star.test
vendored
Normal file
@@ -0,0 +1,51 @@
|
||||
# name: test/sql/merge/merge_into_update_star.test
|
||||
# description: Test MERGE INTO UPDATE *
|
||||
# group: [merge]
|
||||
|
||||
statement ok
|
||||
PRAGMA enable_verification
|
||||
|
||||
statement ok
|
||||
CREATE TABLE Stock(item_id int, balance int DEFAULT 0);
|
||||
|
||||
statement ok
|
||||
INSERT INTO Stock (item_id) VALUES (5), (10), (20);
|
||||
|
||||
# UPDATE star
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (5, 10)) new_accounts(item_id) USING (item_id)
|
||||
WHEN MATCHED THEN UPDATE
|
||||
----
|
||||
1
|
||||
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (10, 30)) new_accounts(item_id, balance) USING (item_id)
|
||||
WHEN MATCHED THEN UPDATE SET *
|
||||
----
|
||||
1
|
||||
|
||||
query I
|
||||
MERGE INTO Stock USING (VALUES (100, 20)) new_accounts(balance, item_id) USING (item_id)
|
||||
WHEN MATCHED THEN UPDATE BY NAME
|
||||
----
|
||||
1
|
||||
|
||||
query II
|
||||
FROM Stock
|
||||
----
|
||||
5 10
|
||||
10 30
|
||||
20 100
|
||||
|
||||
# column mismatches
|
||||
statement error
|
||||
MERGE INTO Stock USING (VALUES (10)) new_accounts(item_id) USING (item_id)
|
||||
WHEN MATCHED THEN UPDATE SET *
|
||||
----
|
||||
not match column count
|
||||
|
||||
statement error
|
||||
MERGE INTO Stock USING (VALUES (10, 20)) new_accounts(item_id, balanc) USING (item_id)
|
||||
WHEN MATCHED THEN UPDATE BY NAME
|
||||
----
|
||||
balance
|
||||
Reference in New Issue
Block a user