pull/7675/merge
Cédric Villemain 2025-07-09 11:56:57 +00:00 committed by GitHub
commit c25eed36f0
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
11 changed files with 946 additions and 0 deletions

View File

@ -1715,3 +1715,122 @@ RoleSpecString(RoleSpec *spec, bool withQuoteIdentifier)
} }
} }
} }
/*
* Recursively search an expression for a Param and return its paramid
* Intended for indirection management: UPDATE SET () = (SELECT )
* Does not cover all options but those supported by Citus.
*/
static int
GetParamId(Node *expr)
{
int paramid = 0;
if (expr == NULL)
{
return paramid;
}
/* If it's a Param, return its attnum */
if (IsA(expr, Param))
{
Param *param = (Param *) expr;
paramid = param->paramid;
}
/* If it's a FuncExpr, search in arguments */
else if (IsA(expr, FuncExpr))
{
FuncExpr *func = (FuncExpr *) expr;
ListCell *lc;
foreach(lc, func->args)
{
paramid = GetParamId((Node *) lfirst(lc));
if (paramid != 0)
{
break; /* Stop at the first valid paramid */
}
}
}
return paramid;
}
/*
* list_sort comparator to sort target list by paramid (in MULTIEXPR)
* Intended for indirection management: UPDATE SET () = (SELECT )
*/
static int
target_list_cmp(const ListCell *a, const ListCell *b)
{
TargetEntry *tleA = lfirst(a);
TargetEntry *tleB = lfirst(b);
/*
* Deal with resjunk entries; sublinks are marked resjunk and
* are placed at the end of the target list so this logic
* ensures they stay grouped at the end of the target list:
*/
if (tleA->resjunk || tleB->resjunk)
{
return tleA->resjunk - tleB->resjunk;
}
int la = GetParamId((Node *) tleA->expr);
int lb = GetParamId((Node *) tleB->expr);
/*
* Should be looking at legitimate param ids
*/
Assert(la > 0);
Assert(lb > 0);
/*
* Return -1, 0 or 1 depending on if la is less than,
* equal to or greater than lb
*/
return (la > lb) - (la < lb);
}
/*
* Used by get_update_query_targetlist_def() (in ruleutils) to reorder the target
* list on the left side of the update:
* SET () = (SELECT )
* Reordering the SELECT side only does not work, consider a case like:
* SET (col_1, col3) = (SELECT 1, 3), (col_2) = (SELECT 2)
* Without ensure_update_targetlist_in_param_order(), this will lead to an incorrect
* deparsed query:
* SET (col_1, col2) = (SELECT 1, 3), (col_3) = (SELECT 2)
*/
void
ensure_update_targetlist_in_param_order(List *targetList)
{
bool need_to_sort_target_list = false;
int previous_paramid = 0;
ListCell *l;
foreach(l, targetList)
{
TargetEntry *tle = (TargetEntry *) lfirst(l);
if (!tle->resjunk)
{
int paramid = GetParamId((Node *) tle->expr);
if (paramid < previous_paramid)
{
need_to_sort_target_list = true;
break;
}
previous_paramid = paramid;
}
}
if (need_to_sort_target_list)
{
list_sort(targetList, target_list_cmp);
}
}

View File

@ -3532,6 +3532,8 @@ get_update_query_targetlist_def(Query *query, List *targetList,
} }
} }
} }
ensure_update_targetlist_in_param_order(targetList);
} }
next_ma_cell = list_head(ma_sublinks); next_ma_cell = list_head(ma_sublinks);
cur_ma_sublink = NULL; cur_ma_sublink = NULL;

View File

@ -3548,6 +3548,8 @@ get_update_query_targetlist_def(Query *query, List *targetList,
} }
} }
} }
ensure_update_targetlist_in_param_order(targetList);
} }
next_ma_cell = list_head(ma_sublinks); next_ma_cell = list_head(ma_sublinks);
cur_ma_sublink = NULL; cur_ma_sublink = NULL;

View File

@ -3565,6 +3565,8 @@ get_update_query_targetlist_def(Query *query, List *targetList,
} }
} }
} }
ensure_update_targetlist_in_param_order(targetList);
} }
next_ma_cell = list_head(ma_sublinks); next_ma_cell = list_head(ma_sublinks);
cur_ma_sublink = NULL; cur_ma_sublink = NULL;

View File

@ -60,5 +60,6 @@ extern char * generate_operator_name(Oid operid, Oid arg1, Oid arg2);
extern List * getOwnedSequences_internal(Oid relid, AttrNumber attnum, char deptype); extern List * getOwnedSequences_internal(Oid relid, AttrNumber attnum, char deptype);
extern void AppendOptionListToString(StringInfo stringData, List *options); extern void AppendOptionListToString(StringInfo stringData, List *options);
extern void ensure_update_targetlist_in_param_order(List *targetList);
#endif /* CITUS_RULEUTILS_H */ #endif /* CITUS_RULEUTILS_H */

View File

@ -147,6 +147,7 @@ DEPS = {
"multi_mx_modifying_xacts": TestDeps(None, ["multi_mx_create_table"]), "multi_mx_modifying_xacts": TestDeps(None, ["multi_mx_create_table"]),
"multi_mx_router_planner": TestDeps(None, ["multi_mx_create_table"]), "multi_mx_router_planner": TestDeps(None, ["multi_mx_create_table"]),
"multi_mx_copy_data": TestDeps(None, ["multi_mx_create_table"]), "multi_mx_copy_data": TestDeps(None, ["multi_mx_create_table"]),
"multi_mx_modifications": TestDeps(None, ["multi_mx_create_table"]),
"multi_mx_schema_support": TestDeps(None, ["multi_mx_copy_data"]), "multi_mx_schema_support": TestDeps(None, ["multi_mx_copy_data"]),
"multi_simple_queries": TestDeps("base_schedule"), "multi_simple_queries": TestDeps("base_schedule"),
"create_single_shard_table": TestDeps("minimal_schedule"), "create_single_shard_table": TestDeps("minimal_schedule"),

View File

@ -330,6 +330,12 @@ UPDATE limit_orders SET (kind, limit_price) = ('buy', 999) WHERE id = 246 RETURN
246 | GM | 30 | Mon Jul 02 16:32:15 2007 | buy | 999 246 | GM | 30 | Mon Jul 02 16:32:15 2007 | buy | 999
(1 row) (1 row)
UPDATE limit_orders SET (kind, limit_price) = (SELECT 'buy'::order_side, 999) WHERE id = 246 RETURNING *;
id | symbol | bidder_id | placed_at | kind | limit_price
---------------------------------------------------------------------
246 | GM | 30 | Mon Jul 02 16:32:15 2007 | buy | 999
(1 row)
-- Test that on unique contraint violations, we fail fast -- Test that on unique contraint violations, we fail fast
\set VERBOSITY terse \set VERBOSITY terse
INSERT INTO limit_orders VALUES (275, 'ADR', 140, '2007-07-02 16:32:15', 'sell', 43.67); INSERT INTO limit_orders VALUES (275, 'ADR', 140, '2007-07-02 16:32:15', 'sell', 43.67);
@ -435,6 +441,8 @@ UPDATE limit_orders SET limit_price = 0.00 FROM bidders
-- should succeed with a CTE -- should succeed with a CTE
WITH deleted_orders AS (INSERT INTO limit_orders VALUES (399, 'PDR', 14, '2017-07-02 16:32:15', 'sell', 43)) WITH deleted_orders AS (INSERT INTO limit_orders VALUES (399, 'PDR', 14, '2017-07-02 16:32:15', 'sell', 43))
UPDATE limit_orders SET symbol = 'GM'; UPDATE limit_orders SET symbol = 'GM';
WITH deleted_orders AS (INSERT INTO limit_orders SELECT 400, 'PDR', 14, '2017-07-02 16:32:15', 'sell', 43)
UPDATE limit_orders SET symbol = 'GM';
SELECT symbol, bidder_id FROM limit_orders WHERE id = 246; SELECT symbol, bidder_id FROM limit_orders WHERE id = 246;
symbol | bidder_id symbol | bidder_id
--------------------------------------------------------------------- ---------------------------------------------------------------------
@ -927,6 +935,17 @@ SELECT * FROM summary_table ORDER BY id;
2 | 400 | 450.0000000000000000 | | 2 | 400 | 450.0000000000000000 | |
(2 rows) (2 rows)
-- try different order of update targets
UPDATE summary_table SET (average_value, min_value) =
(SELECT avg(value), min(value) FROM raw_table WHERE id = 2)
WHERE id = 2;
SELECT * FROM summary_table ORDER BY id;
id | min_value | average_value | count | uniques
---------------------------------------------------------------------
1 | | 200.0000000000000000 | |
2 | 400 | 450.0000000000000000 | |
(2 rows)
UPDATE summary_table SET min_value = 100 UPDATE summary_table SET min_value = 100
WHERE id IN (SELECT id FROM raw_table WHERE id = 1 and value > 100) AND id = 1; WHERE id IN (SELECT id FROM raw_table WHERE id = 1 and value > 100) AND id = 1;
SELECT * FROM summary_table ORDER BY id; SELECT * FROM summary_table ORDER BY id;
@ -1103,6 +1122,16 @@ SELECT * FROM reference_summary_table ORDER BY id;
2 | 400 | 450.0000000000000000 | | 2 | 400 | 450.0000000000000000 | |
(2 rows) (2 rows)
UPDATE reference_summary_table SET (average_value, min_value) =
(SELECT avg(value), min(value) FROM reference_raw_table WHERE id = 2)
WHERE id = 2;
SELECT * FROM reference_summary_table ORDER BY id;
id | min_value | average_value | count | uniques
---------------------------------------------------------------------
1 | | 200.0000000000000000 | |
2 | 400 | 450.0000000000000000 | |
(2 rows)
-- no need partition colum equalities on reference tables -- no need partition colum equalities on reference tables
UPDATE reference_summary_table SET (count) = UPDATE reference_summary_table SET (count) =
(SELECT id AS inner_id FROM reference_raw_table WHERE value = 500) (SELECT id AS inner_id FROM reference_raw_table WHERE value = 500)
@ -1329,5 +1358,14 @@ DROP TABLE raw_table;
DROP TABLE summary_table; DROP TABLE summary_table;
DROP TABLE reference_raw_table; DROP TABLE reference_raw_table;
DROP TABLE reference_summary_table; DROP TABLE reference_summary_table;
DROP TABLE limit_orders;
DROP TABLE multiple_hash;
DROP TABLE range_partitioned;
DROP TABLE append_partitioned;
DROP TABLE bidders;
DROP FUNCTION stable_append;
DROP FUNCTION immutable_append;
DROP FUNCTION temp_strict_func;
DROP TYPE order_side;
DROP SCHEMA multi_modifications CASCADE; DROP SCHEMA multi_modifications CASCADE;
NOTICE: drop cascades to table multi_modifications.local NOTICE: drop cascades to table multi_modifications.local

View File

@ -0,0 +1,505 @@
CREATE SCHEMA multi_update_select;
SET search_path TO multi_update_select;
SET citus.next_shard_id TO 751000;
-- specific tests related to get_update_query_targetlist_def
-- we test only queries with sublinks, like:
-- ( ... SET (...) = (SELECT ...))
-- Reference tables
CREATE TABLE test_ref_indirection (
id bigint primary key
, col_bool bool , col_date date , col_int integer , col_text text
);
SELECT create_reference_table('test_ref_indirection');
create_reference_table
---------------------------------------------------------------------
(1 row)
CREATE TABLE test_ref_indirection_new (
id bigint primary key
, col_bool bool , col_date date , col_int integer , col_text text
);
SELECT create_reference_table('test_ref_indirection_new');
create_reference_table
---------------------------------------------------------------------
(1 row)
-- Distributed tables
CREATE TABLE test_dist_indirection (
id bigint primary key
, col_bool bool , col_date date , col_int integer , col_text text
);
SELECT create_distributed_table('test_dist_indirection', 'id');
create_distributed_table
---------------------------------------------------------------------
(1 row)
CREATE TABLE test_dist_indirection_new (
id bigint primary key
, col_bool bool , col_date date , col_int integer , col_text text
);
SELECT create_distributed_table('test_dist_indirection_new', 'id');
create_distributed_table
---------------------------------------------------------------------
(1 row)
-- those should work:
INSERT INTO test_ref_indirection (id, col_bool, col_date, col_int, col_text)
SELECT 1, true, '1970-01-01'::date, 1, 'one';
INSERT INTO test_dist_indirection (id, col_bool, col_date, col_int, col_text)
SELECT 1, true, '1970-01-01'::date, 1, 'one';
INSERT INTO test_ref_indirection (id, col_text, col_bool, col_date, col_int)
SELECT 2, 'two', false, '1970-01-01'::date, 2;
INSERT INTO test_dist_indirection (id, col_text, col_bool, col_date, col_int)
SELECT 2, 'two', false, '1970-01-01'::date, 2;
INSERT INTO test_ref_indirection SELECT 3, false, '1970-01-01'::date, 0, 'empty';
INSERT INTO test_dist_indirection SELECT 3, false, '1970-01-01'::date, 0, 'empty';
INSERT INTO test_ref_indirection SELECT 4, false, '1970-01-01'::date, 0, 'empty';
INSERT INTO test_dist_indirection SELECT 4, false, '1970-01-01'::date, 0, 'empty';
INSERT INTO test_ref_indirection_new SELECT * FROM test_ref_indirection;
INSERT INTO test_dist_indirection_new SELECT * FROM test_dist_indirection;
SELECT * FROM test_ref_indirection ORDER BY id;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1970 | 1 | one
2 | f | 01-01-1970 | 2 | two
3 | f | 01-01-1970 | 0 | empty
4 | f | 01-01-1970 | 0 | empty
(4 rows)
SELECT * FROM test_dist_indirection ORDER BY id;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1970 | 1 | one
2 | f | 01-01-1970 | 2 | two
3 | f | 01-01-1970 | 0 | empty
4 | f | 01-01-1970 | 0 | empty
(4 rows)
SELECT * FROM test_ref_indirection_new ORDER BY id;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1970 | 1 | one
2 | f | 01-01-1970 | 2 | two
3 | f | 01-01-1970 | 0 | empty
4 | f | 01-01-1970 | 0 | empty
(4 rows)
SELECT * FROM test_dist_indirection_new ORDER BY id;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1970 | 1 | one
2 | f | 01-01-1970 | 2 | two
3 | f | 01-01-1970 | 0 | empty
4 | f | 01-01-1970 | 0 | empty
(4 rows)
-- now UPDATEs
UPDATE test_ref_indirection
SET (col_bool, col_date, col_int, col_text)
= (SELECT true, '1970-01-01'::date, 1, 'ok')
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1970 | 1 | ok
2 | t | 01-01-1970 | 1 | ok
3 | t | 01-01-1970 | 1 | ok
4 | t | 01-01-1970 | 1 | ok
(4 rows)
UPDATE test_dist_indirection
SET (col_bool, col_date, col_int, col_text)
= (SELECT true, '1970-01-01'::date, 1, 'ok')
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1970 | 1 | ok
2 | t | 01-01-1970 | 1 | ok
3 | t | 01-01-1970 | 1 | ok
4 | t | 01-01-1970 | 1 | ok
(4 rows)
UPDATE test_ref_indirection
SET (col_bool, col_date) = (select false, '1971-01-01'::date)
, (col_int, col_text) = (select 2, '2 ok')
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | f | 01-01-1971 | 2 | 2 ok
2 | f | 01-01-1971 | 2 | 2 ok
3 | f | 01-01-1971 | 2 | 2 ok
4 | f | 01-01-1971 | 2 | 2 ok
(4 rows)
UPDATE test_dist_indirection
SET (col_bool, col_date) = (select false, '1971-01-01'::date)
, (col_int, col_text) = (select 2, '2 ok')
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | f | 01-01-1971 | 2 | 2 ok
2 | f | 01-01-1971 | 2 | 2 ok
3 | f | 01-01-1971 | 2 | 2 ok
4 | f | 01-01-1971 | 2 | 2 ok
(4 rows)
UPDATE test_ref_indirection
SET (col_bool, col_int) = (select true, 3)
, (col_text) = (select '3 ok')
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1971 | 3 | 3 ok
2 | t | 01-01-1971 | 3 | 3 ok
3 | t | 01-01-1971 | 3 | 3 ok
4 | t | 01-01-1971 | 3 | 3 ok
(4 rows)
UPDATE test_dist_indirection
SET (col_bool, col_int) = (select true, 3)
, (col_text) = (select '3 ok')
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1971 | 3 | 3 ok
2 | t | 01-01-1971 | 3 | 3 ok
3 | t | 01-01-1971 | 3 | 3 ok
4 | t | 01-01-1971 | 3 | 3 ok
(4 rows)
-- but those should work since 13.X
UPDATE test_ref_indirection
SET (col_date, col_text, col_int, col_bool)
= (SELECT '1972-01-01'::date, '4 ok', 4, false)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | f | 01-01-1972 | 4 | 4 ok
2 | f | 01-01-1972 | 4 | 4 ok
3 | f | 01-01-1972 | 4 | 4 ok
4 | f | 01-01-1972 | 4 | 4 ok
(4 rows)
UPDATE test_dist_indirection
SET (col_date, col_text, col_int, col_bool)
= (SELECT '1972-01-01'::date, '4 ok', 4, false)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | f | 01-01-1972 | 4 | 4 ok
2 | f | 01-01-1972 | 4 | 4 ok
3 | f | 01-01-1972 | 4 | 4 ok
4 | f | 01-01-1972 | 4 | 4 ok
(4 rows)
UPDATE test_ref_indirection
SET (col_int, col_text) = (select 5, '5 ok')
, (col_bool) = (select true)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1972 | 5 | 5 ok
2 | t | 01-01-1972 | 5 | 5 ok
3 | t | 01-01-1972 | 5 | 5 ok
4 | t | 01-01-1972 | 5 | 5 ok
(4 rows)
UPDATE test_dist_indirection
SET (col_int, col_text) = (select 5, '5 ok')
, (col_bool) = (select true)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1972 | 5 | 5 ok
2 | t | 01-01-1972 | 5 | 5 ok
3 | t | 01-01-1972 | 5 | 5 ok
4 | t | 01-01-1972 | 5 | 5 ok
(4 rows)
UPDATE test_ref_indirection
SET (col_int, col_date) = (select 6, '1973-01-01'::date)
, (col_text, col_bool) = (select '6 ok', false)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | f | 01-01-1973 | 6 | 6 ok
2 | f | 01-01-1973 | 6 | 6 ok
3 | f | 01-01-1973 | 6 | 6 ok
4 | f | 01-01-1973 | 6 | 6 ok
(4 rows)
UPDATE test_dist_indirection
SET (col_int, col_date) = (select 6, '1973-01-01'::date)
, (col_text, col_bool) = (select '6 ok', false)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | f | 01-01-1973 | 6 | 6 ok
2 | f | 01-01-1973 | 6 | 6 ok
3 | f | 01-01-1973 | 6 | 6 ok
4 | f | 01-01-1973 | 6 | 6 ok
(4 rows)
UPDATE test_ref_indirection
SET (col_int, col_date, col_text) = (select 7, '1974-01-01'::date, '7 ok')
, (col_bool) = (select true)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1974 | 7 | 7 ok
2 | t | 01-01-1974 | 7 | 7 ok
3 | t | 01-01-1974 | 7 | 7 ok
4 | t | 01-01-1974 | 7 | 7 ok
(4 rows)
UPDATE test_dist_indirection
SET (col_int, col_date, col_text) = (select 7, '1974-01-01'::date, '7 ok')
, (col_bool) = (select true)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1974 | 7 | 7 ok
2 | t | 01-01-1974 | 7 | 7 ok
3 | t | 01-01-1974 | 7 | 7 ok
4 | t | 01-01-1974 | 7 | 7 ok
(4 rows)
UPDATE test_ref_indirection
SET (col_date, col_text) = (select '1975-01-01'::date, '8 ok')
, (col_int) = (select 8)
, (col_bool) = (select false)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | f | 01-01-1975 | 8 | 8 ok
2 | f | 01-01-1975 | 8 | 8 ok
3 | f | 01-01-1975 | 8 | 8 ok
4 | f | 01-01-1975 | 8 | 8 ok
(4 rows)
UPDATE test_dist_indirection
SET (col_date, col_text) = (select '1975-01-01'::date, '8 ok')
, (col_int) = (select 8)
, (col_bool) = (select false)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | f | 01-01-1975 | 8 | 8 ok
2 | f | 01-01-1975 | 8 | 8 ok
3 | f | 01-01-1975 | 8 | 8 ok
4 | f | 01-01-1975 | 8 | 8 ok
(4 rows)
--
-- more restrictive ones, just in case we miss a wrong value
--
-- those should work
UPDATE test_ref_indirection
SET (col_bool, col_text) = (SELECT true, '9 ok')
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1975 | 8 | 9 ok
2 | t | 01-01-1975 | 8 | 9 ok
3 | t | 01-01-1975 | 8 | 9 ok
4 | t | 01-01-1975 | 8 | 9 ok
(4 rows)
UPDATE test_dist_indirection
SET (col_bool, col_text) = (SELECT true, '9 ok')
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1975 | 8 | 9 ok
2 | t | 01-01-1975 | 8 | 9 ok
3 | t | 01-01-1975 | 8 | 9 ok
4 | t | 01-01-1975 | 8 | 9 ok
(4 rows)
UPDATE test_ref_indirection
SET (col_bool, col_text) = (SELECT false, '10 ok')
WHERE id = 1
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | f | 01-01-1975 | 8 | 10 ok
(1 row)
UPDATE test_dist_indirection
SET (col_bool, col_text) = (SELECT false, '10 ok')
WHERE id = 1
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | f | 01-01-1975 | 8 | 10 ok
(1 row)
UPDATE test_ref_indirection
SET (col_text, col_bool) = (SELECT '11 ok', true)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1975 | 8 | 11 ok
2 | t | 01-01-1975 | 8 | 11 ok
3 | t | 01-01-1975 | 8 | 11 ok
4 | t | 01-01-1975 | 8 | 11 ok
(4 rows)
UPDATE test_dist_indirection
SET (col_text, col_bool) = (SELECT '11 ok', true)
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
1 | t | 01-01-1975 | 8 | 11 ok
2 | t | 01-01-1975 | 8 | 11 ok
3 | t | 01-01-1975 | 8 | 11 ok
4 | t | 01-01-1975 | 8 | 11 ok
(4 rows)
UPDATE test_ref_indirection
SET (col_text, col_bool) = (SELECT '12 ok', false)
WHERE id = 2
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
2 | f | 01-01-1975 | 8 | 12 ok
(1 row)
UPDATE test_dist_indirection
SET (col_text, col_bool) = (SELECT '12 ok', false)
WHERE id = 2
RETURNING *;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
2 | f | 01-01-1975 | 8 | 12 ok
(1 row)
-- several updates in CTE shoult not work
with qq3 as (
update test_ref_indirection
SET (col_text, col_bool)
= (SELECT '13', true)
where id = 3
returning *
),
qq4 as (
update test_ref_indirection
SET (col_text, col_bool)
= (SELECT '14', false)
where id = 4
returning *
)
select * from qq3 union all select * from qq4;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
3 | t | 01-01-1975 | 8 | 13
4 | f | 01-01-1975 | 8 | 14
(2 rows)
with qq3 as (
update test_dist_indirection
SET (col_text, col_bool)
= (SELECT '13', true)
where id = 3
returning *
),
qq4 as (
update test_dist_indirection
SET (col_text, col_bool)
= (SELECT '14', false)
where id = 4
returning *
)
select * from qq3 union all select * from qq4;
id | col_bool | col_date | col_int | col_text
---------------------------------------------------------------------
3 | t | 01-01-1975 | 8 | 13
4 | f | 01-01-1975 | 8 | 14
(2 rows)
DROP TABLE test_dist_indirection;
DROP TABLE test_dist_indirection_new;
DROP TABLE test_ref_indirection;
DROP TABLE test_ref_indirection_new;
-- https://github.com/citusdata/citus/issues/4092
CREATE TABLE update_test (
a INT DEFAULT 10,
b INT,
c TEXT
);
SELECT create_reference_table('update_test');
create_reference_table
---------------------------------------------------------------------
(1 row)
INSERT INTO update_test VALUES (11, 41, 'car');
INSERT INTO update_test VALUES (100, 20, 'bike');
INSERT INTO update_test VALUES (100, 20, 'tractor');
SELECT * FROM update_test;
a | b | c
---------------------------------------------------------------------
11 | 41 | car
100 | 20 | bike
100 | 20 | tractor
(3 rows)
UPDATE update_test
SET (b,a) = (select a,b from update_test where b = 41 and c = 'car')
WHERE a = 100 AND b = 20
RETURNING *;
a | b | c
---------------------------------------------------------------------
41 | 11 | bike
41 | 11 | tractor
(2 rows)
-- Test that multiple out of order columns and multiple sublinks are handled correctly.
CREATE TABLE upd2_test (a1 int, b1 int, c1 int, d1 int, e1 int, f1 int, g1 int);
SELECT create_reference_table('upd2_test');
create_reference_table
---------------------------------------------------------------------
(1 row)
INSERT INTO upd2_test SELECT 1, 1, 1, 1, 1, 1, 1 FROM generate_series(1,5) c(i);
UPDATE upd2_test set (b1, a1) = (SELECT 200, 100), (g1, f1, e1) = (SELECT 700, 600, 500), (d1, c1) = (SELECT 400, 300);
SELECT * FROM upd2_test;
a1 | b1 | c1 | d1 | e1 | f1 | g1
---------------------------------------------------------------------
100 | 200 | 300 | 400 | 500 | 600 | 700
100 | 200 | 300 | 400 | 500 | 600 | 700
100 | 200 | 300 | 400 | 500 | 600 | 700
100 | 200 | 300 | 400 | 500 | 600 | 700
100 | 200 | 300 | 400 | 500 | 600 | 700
(5 rows)
UPDATE upd2_test set (g1, a1) = (SELECT 77, 11), (f1, b1) = (SELECT 66, 22), (e1, c1) = (SELECT 55, 33), (d1) = (SELECT 44);
SELECT * FROM upd2_test;
a1 | b1 | c1 | d1 | e1 | f1 | g1
---------------------------------------------------------------------
11 | 22 | 33 | 44 | 55 | 66 | 77
11 | 22 | 33 | 44 | 55 | 66 | 77
11 | 22 | 33 | 44 | 55 | 66 | 77
11 | 22 | 33 | 44 | 55 | 66 | 77
11 | 22 | 33 | 44 | 55 | 66 | 77
(5 rows)
UPDATE upd2_test set (g1, a1) = (SELECT 7, 1), (f1) = (SELECT 6), (c1, e1) = (SELECT 3, 5), (b1) = (SELECT 2), (d1) = (SELECT 4);
SELECT * FROM upd2_test;
a1 | b1 | c1 | d1 | e1 | f1 | g1
---------------------------------------------------------------------
1 | 2 | 3 | 4 | 5 | 6 | 7
1 | 2 | 3 | 4 | 5 | 6 | 7
1 | 2 | 3 | 4 | 5 | 6 | 7
1 | 2 | 3 | 4 | 5 | 6 | 7
1 | 2 | 3 | 4 | 5 | 6 | 7
(5 rows)
-- suppress cascade messages
SET client_min_messages to ERROR;
DROP SCHEMA multi_update_select CASCADE;
RESET client_min_messages;

View File

@ -210,6 +210,7 @@ test: multi_outer_join
# --- # ---
test: multi_complex_count_distinct multi_select_distinct test: multi_complex_count_distinct multi_select_distinct
test: multi_modifications test: multi_modifications
test: multi_update_select
test: multi_distribution_metadata test: multi_distribution_metadata
test: multi_prune_shard_list test: multi_prune_shard_list
test: multi_upsert multi_simple_queries multi_data_types test: multi_upsert multi_simple_queries multi_data_types

View File

@ -234,6 +234,7 @@ SELECT kind, limit_price FROM limit_orders WHERE id = 246;
-- multi-column UPDATE with RETURNING -- multi-column UPDATE with RETURNING
UPDATE limit_orders SET (kind, limit_price) = ('buy', 999) WHERE id = 246 RETURNING *; UPDATE limit_orders SET (kind, limit_price) = ('buy', 999) WHERE id = 246 RETURNING *;
UPDATE limit_orders SET (kind, limit_price) = (SELECT 'buy'::order_side, 999) WHERE id = 246 RETURNING *;
-- Test that on unique contraint violations, we fail fast -- Test that on unique contraint violations, we fail fast
\set VERBOSITY terse \set VERBOSITY terse
@ -337,6 +338,9 @@ UPDATE limit_orders SET limit_price = 0.00 FROM bidders
WITH deleted_orders AS (INSERT INTO limit_orders VALUES (399, 'PDR', 14, '2017-07-02 16:32:15', 'sell', 43)) WITH deleted_orders AS (INSERT INTO limit_orders VALUES (399, 'PDR', 14, '2017-07-02 16:32:15', 'sell', 43))
UPDATE limit_orders SET symbol = 'GM'; UPDATE limit_orders SET symbol = 'GM';
WITH deleted_orders AS (INSERT INTO limit_orders SELECT 400, 'PDR', 14, '2017-07-02 16:32:15', 'sell', 43)
UPDATE limit_orders SET symbol = 'GM';
SELECT symbol, bidder_id FROM limit_orders WHERE id = 246; SELECT symbol, bidder_id FROM limit_orders WHERE id = 246;
-- updates referencing just a var are supported -- updates referencing just a var are supported
@ -584,6 +588,13 @@ WHERE id = 2;
SELECT * FROM summary_table ORDER BY id; SELECT * FROM summary_table ORDER BY id;
-- try different order of update targets
UPDATE summary_table SET (average_value, min_value) =
(SELECT avg(value), min(value) FROM raw_table WHERE id = 2)
WHERE id = 2;
SELECT * FROM summary_table ORDER BY id;
UPDATE summary_table SET min_value = 100 UPDATE summary_table SET min_value = 100
WHERE id IN (SELECT id FROM raw_table WHERE id = 1 and value > 100) AND id = 1; WHERE id IN (SELECT id FROM raw_table WHERE id = 1 and value > 100) AND id = 1;
@ -712,6 +723,12 @@ WHERE id = 2;
SELECT * FROM reference_summary_table ORDER BY id; SELECT * FROM reference_summary_table ORDER BY id;
UPDATE reference_summary_table SET (average_value, min_value) =
(SELECT avg(value), min(value) FROM reference_raw_table WHERE id = 2)
WHERE id = 2;
SELECT * FROM reference_summary_table ORDER BY id;
-- no need partition colum equalities on reference tables -- no need partition colum equalities on reference tables
UPDATE reference_summary_table SET (count) = UPDATE reference_summary_table SET (count) =
(SELECT id AS inner_id FROM reference_raw_table WHERE value = 500) (SELECT id AS inner_id FROM reference_raw_table WHERE value = 500)
@ -902,4 +919,15 @@ DROP TABLE raw_table;
DROP TABLE summary_table; DROP TABLE summary_table;
DROP TABLE reference_raw_table; DROP TABLE reference_raw_table;
DROP TABLE reference_summary_table; DROP TABLE reference_summary_table;
DROP TABLE limit_orders;
DROP TABLE multiple_hash;
DROP TABLE range_partitioned;
DROP TABLE append_partitioned;
DROP TABLE bidders;
DROP FUNCTION stable_append;
DROP FUNCTION immutable_append;
DROP FUNCTION temp_strict_func;
DROP TYPE order_side;
DROP SCHEMA multi_modifications CASCADE; DROP SCHEMA multi_modifications CASCADE;

View File

@ -0,0 +1,247 @@
CREATE SCHEMA multi_update_select;
SET search_path TO multi_update_select;
SET citus.next_shard_id TO 751000;
-- specific tests related to get_update_query_targetlist_def
-- we test only queries with sublinks, like:
-- ( ... SET (...) = (SELECT ...))
-- Reference tables
CREATE TABLE test_ref_indirection (
id bigint primary key
, col_bool bool , col_date date , col_int integer , col_text text
);
SELECT create_reference_table('test_ref_indirection');
CREATE TABLE test_ref_indirection_new (
id bigint primary key
, col_bool bool , col_date date , col_int integer , col_text text
);
SELECT create_reference_table('test_ref_indirection_new');
-- Distributed tables
CREATE TABLE test_dist_indirection (
id bigint primary key
, col_bool bool , col_date date , col_int integer , col_text text
);
SELECT create_distributed_table('test_dist_indirection', 'id');
CREATE TABLE test_dist_indirection_new (
id bigint primary key
, col_bool bool , col_date date , col_int integer , col_text text
);
SELECT create_distributed_table('test_dist_indirection_new', 'id');
-- those should work:
INSERT INTO test_ref_indirection (id, col_bool, col_date, col_int, col_text)
SELECT 1, true, '1970-01-01'::date, 1, 'one';
INSERT INTO test_dist_indirection (id, col_bool, col_date, col_int, col_text)
SELECT 1, true, '1970-01-01'::date, 1, 'one';
INSERT INTO test_ref_indirection (id, col_text, col_bool, col_date, col_int)
SELECT 2, 'two', false, '1970-01-01'::date, 2;
INSERT INTO test_dist_indirection (id, col_text, col_bool, col_date, col_int)
SELECT 2, 'two', false, '1970-01-01'::date, 2;
INSERT INTO test_ref_indirection SELECT 3, false, '1970-01-01'::date, 0, 'empty';
INSERT INTO test_dist_indirection SELECT 3, false, '1970-01-01'::date, 0, 'empty';
INSERT INTO test_ref_indirection SELECT 4, false, '1970-01-01'::date, 0, 'empty';
INSERT INTO test_dist_indirection SELECT 4, false, '1970-01-01'::date, 0, 'empty';
INSERT INTO test_ref_indirection_new SELECT * FROM test_ref_indirection;
INSERT INTO test_dist_indirection_new SELECT * FROM test_dist_indirection;
SELECT * FROM test_ref_indirection ORDER BY id;
SELECT * FROM test_dist_indirection ORDER BY id;
SELECT * FROM test_ref_indirection_new ORDER BY id;
SELECT * FROM test_dist_indirection_new ORDER BY id;
-- now UPDATEs
UPDATE test_ref_indirection
SET (col_bool, col_date, col_int, col_text)
= (SELECT true, '1970-01-01'::date, 1, 'ok')
RETURNING *;
UPDATE test_dist_indirection
SET (col_bool, col_date, col_int, col_text)
= (SELECT true, '1970-01-01'::date, 1, 'ok')
RETURNING *;
UPDATE test_ref_indirection
SET (col_bool, col_date) = (select false, '1971-01-01'::date)
, (col_int, col_text) = (select 2, '2 ok')
RETURNING *;
UPDATE test_dist_indirection
SET (col_bool, col_date) = (select false, '1971-01-01'::date)
, (col_int, col_text) = (select 2, '2 ok')
RETURNING *;
UPDATE test_ref_indirection
SET (col_bool, col_int) = (select true, 3)
, (col_text) = (select '3 ok')
RETURNING *;
UPDATE test_dist_indirection
SET (col_bool, col_int) = (select true, 3)
, (col_text) = (select '3 ok')
RETURNING *;
-- but those should work since 13.X
UPDATE test_ref_indirection
SET (col_date, col_text, col_int, col_bool)
= (SELECT '1972-01-01'::date, '4 ok', 4, false)
RETURNING *;
UPDATE test_dist_indirection
SET (col_date, col_text, col_int, col_bool)
= (SELECT '1972-01-01'::date, '4 ok', 4, false)
RETURNING *;
UPDATE test_ref_indirection
SET (col_int, col_text) = (select 5, '5 ok')
, (col_bool) = (select true)
RETURNING *;
UPDATE test_dist_indirection
SET (col_int, col_text) = (select 5, '5 ok')
, (col_bool) = (select true)
RETURNING *;
UPDATE test_ref_indirection
SET (col_int, col_date) = (select 6, '1973-01-01'::date)
, (col_text, col_bool) = (select '6 ok', false)
RETURNING *;
UPDATE test_dist_indirection
SET (col_int, col_date) = (select 6, '1973-01-01'::date)
, (col_text, col_bool) = (select '6 ok', false)
RETURNING *;
UPDATE test_ref_indirection
SET (col_int, col_date, col_text) = (select 7, '1974-01-01'::date, '7 ok')
, (col_bool) = (select true)
RETURNING *;
UPDATE test_dist_indirection
SET (col_int, col_date, col_text) = (select 7, '1974-01-01'::date, '7 ok')
, (col_bool) = (select true)
RETURNING *;
UPDATE test_ref_indirection
SET (col_date, col_text) = (select '1975-01-01'::date, '8 ok')
, (col_int) = (select 8)
, (col_bool) = (select false)
RETURNING *;
UPDATE test_dist_indirection
SET (col_date, col_text) = (select '1975-01-01'::date, '8 ok')
, (col_int) = (select 8)
, (col_bool) = (select false)
RETURNING *;
--
-- more restrictive ones, just in case we miss a wrong value
--
-- those should work
UPDATE test_ref_indirection
SET (col_bool, col_text) = (SELECT true, '9 ok')
RETURNING *;
UPDATE test_dist_indirection
SET (col_bool, col_text) = (SELECT true, '9 ok')
RETURNING *;
UPDATE test_ref_indirection
SET (col_bool, col_text) = (SELECT false, '10 ok')
WHERE id = 1
RETURNING *;
UPDATE test_dist_indirection
SET (col_bool, col_text) = (SELECT false, '10 ok')
WHERE id = 1
RETURNING *;
UPDATE test_ref_indirection
SET (col_text, col_bool) = (SELECT '11 ok', true)
RETURNING *;
UPDATE test_dist_indirection
SET (col_text, col_bool) = (SELECT '11 ok', true)
RETURNING *;
UPDATE test_ref_indirection
SET (col_text, col_bool) = (SELECT '12 ok', false)
WHERE id = 2
RETURNING *;
UPDATE test_dist_indirection
SET (col_text, col_bool) = (SELECT '12 ok', false)
WHERE id = 2
RETURNING *;
-- several updates in CTE shoult not work
with qq3 as (
update test_ref_indirection
SET (col_text, col_bool)
= (SELECT '13', true)
where id = 3
returning *
),
qq4 as (
update test_ref_indirection
SET (col_text, col_bool)
= (SELECT '14', false)
where id = 4
returning *
)
select * from qq3 union all select * from qq4;
with qq3 as (
update test_dist_indirection
SET (col_text, col_bool)
= (SELECT '13', true)
where id = 3
returning *
),
qq4 as (
update test_dist_indirection
SET (col_text, col_bool)
= (SELECT '14', false)
where id = 4
returning *
)
select * from qq3 union all select * from qq4;
DROP TABLE test_dist_indirection;
DROP TABLE test_dist_indirection_new;
DROP TABLE test_ref_indirection;
DROP TABLE test_ref_indirection_new;
-- https://github.com/citusdata/citus/issues/4092
CREATE TABLE update_test (
a INT DEFAULT 10,
b INT,
c TEXT
);
SELECT create_reference_table('update_test');
INSERT INTO update_test VALUES (11, 41, 'car');
INSERT INTO update_test VALUES (100, 20, 'bike');
INSERT INTO update_test VALUES (100, 20, 'tractor');
SELECT * FROM update_test;
UPDATE update_test
SET (b,a) = (select a,b from update_test where b = 41 and c = 'car')
WHERE a = 100 AND b = 20
RETURNING *;
-- Test that multiple out of order columns and multiple sublinks are handled correctly.
CREATE TABLE upd2_test (a1 int, b1 int, c1 int, d1 int, e1 int, f1 int, g1 int);
SELECT create_reference_table('upd2_test');
INSERT INTO upd2_test SELECT 1, 1, 1, 1, 1, 1, 1 FROM generate_series(1,5) c(i);
UPDATE upd2_test set (b1, a1) = (SELECT 200, 100), (g1, f1, e1) = (SELECT 700, 600, 500), (d1, c1) = (SELECT 400, 300);
SELECT * FROM upd2_test;
UPDATE upd2_test set (g1, a1) = (SELECT 77, 11), (f1, b1) = (SELECT 66, 22), (e1, c1) = (SELECT 55, 33), (d1) = (SELECT 44);
SELECT * FROM upd2_test;
UPDATE upd2_test set (g1, a1) = (SELECT 7, 1), (f1) = (SELECT 6), (c1, e1) = (SELECT 3, 5), (b1) = (SELECT 2), (d1) = (SELECT 4);
SELECT * FROM upd2_test;
-- suppress cascade messages
SET client_min_messages to ERROR;
DROP SCHEMA multi_update_select CASCADE;
RESET client_min_messages;