Fix UPDATE stmts with indirection & array/jsonb subscripting with more than 1 field (#7675)

DESCRIPTION: Fixes problematic UPDATE statements with indirection and array/jsonb subscripting with more than one field.

Fixes #4092, #7674 and #5621. Issues #7674 and #4092 involve an UPDATE with out of order columns and a sublink (SELECT) in the source, e.g. `UPDATE T SET (col3, col1, col4) = (SELECT 3, 1, 4)` where an incorrect value could get written to a column because query deparsing generated an incorrect SQL statement. To address this the fix adds an additional
check to `ruleutils` to ensure that the target list of an UPDATE statement is in an order so that deparsing can be done safely. It is needed when the source of the UPDATE has a sublink, because Postgres `rewrite` will have put the target list in attribute order, but for deparsing to produce a correct SQL text the target list needs to be in order of the references (or `paramids`) to the target list of the sublink(s). Issue #5621 involves an UPDATE with array/jsonb subscripting that can behave incorrectly with more than one field, again because Citus query deparsing is receiving a post-`rewrite` query tree. The fix also adds a
check to `ruleutils` to enable correct query deparsing of the UPDATE.

---------

Co-authored-by: Ibrahim Halatci <ihalatci@gmail.com>
Co-authored-by: Colm McHugh <colm.mchugh@gmail.com>
pull/8069/head
Cédric Villemain 2025-07-22 18:49:26 +02:00 committed by GitHub
parent 245a62df3e
commit 0c1b31cdb5
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
14 changed files with 1667 additions and 0 deletions

View File

@ -82,6 +82,7 @@ static void AppendStorageParametersToString(StringInfo stringBuffer,
List *optionList); List *optionList);
static const char * convert_aclright_to_string(int aclright); static const char * convert_aclright_to_string(int aclright);
static void simple_quote_literal(StringInfo buf, const char *val); static void simple_quote_literal(StringInfo buf, const char *val);
static SubscriptingRef * TargetEntryExprFindSubsRef(Expr *expr);
static void AddVacuumParams(ReindexStmt *reindexStmt, StringInfo buffer); static void AddVacuumParams(ReindexStmt *reindexStmt, StringInfo buffer);
static void process_acl_items(Acl *acl, const char *relationName, static void process_acl_items(Acl *acl, const char *relationName,
const char *attributeName, List **defs); const char *attributeName, List **defs);
@ -1715,3 +1716,255 @@ 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);
}
}
/*
* ExpandMergedSubscriptingRefEntries takes a list of target entries and expands
* each one that references a SubscriptingRef node that indicates multiple (field)
* updates on the same attribute, which is applicable for array/json types atm.
*/
List *
ExpandMergedSubscriptingRefEntries(List *targetEntryList)
{
List *newTargetEntryList = NIL;
ListCell *tgtCell = NULL;
foreach(tgtCell, targetEntryList)
{
TargetEntry *targetEntry = (TargetEntry *) lfirst(tgtCell);
List *expandedTargetEntries = NIL;
Expr *expr = targetEntry->expr;
while (expr)
{
SubscriptingRef *subsRef = TargetEntryExprFindSubsRef(expr);
if (!subsRef)
{
break;
}
/*
* Remove refexpr from the SubscriptingRef that we are about to
* wrap in a new TargetEntry and save it for the next one.
*/
Expr *refexpr = subsRef->refexpr;
subsRef->refexpr = NULL;
/*
* Wrap the Expr that holds SubscriptingRef (directly or indirectly)
* in a new TargetEntry; note that it doesn't have a refexpr anymore.
*/
TargetEntry *newTargetEntry = copyObject(targetEntry);
newTargetEntry->expr = expr;
expandedTargetEntries = lappend(expandedTargetEntries, newTargetEntry);
/* now inspect the refexpr that SubscriptingRef at hand were holding */
expr = refexpr;
}
if (expandedTargetEntries == NIL)
{
/* return original entry since it doesn't hold a SubscriptingRef node */
newTargetEntryList = lappend(newTargetEntryList, targetEntry);
}
else
{
/*
* Need to concat expanded target list entries in reverse order
* to preserve ordering of the original target entry list.
*/
List *reversedTgtEntries = NIL;
ListCell *revCell = NULL;
foreach(revCell, expandedTargetEntries)
{
TargetEntry *tgtEntry = (TargetEntry *) lfirst(revCell);
reversedTgtEntries = lcons(tgtEntry, reversedTgtEntries);
}
newTargetEntryList = list_concat(newTargetEntryList, reversedTgtEntries);
}
}
return newTargetEntryList;
}
/*
* TargetEntryExprFindSubsRef searches given Expr --assuming that it is part
* of a target list entry-- to see if it directly (i.e.: itself) or indirectly
* (e.g.: behind some level of coercions) holds a SubscriptingRef node.
*
* Returns the original SubscriptingRef node on success or NULL otherwise.
*
* Note that it wouldn't add much value to use expression_tree_walker here
* since we are only interested in a subset of the fields of a few certain
* node types.
*/
static SubscriptingRef *
TargetEntryExprFindSubsRef(Expr *expr)
{
Node *node = (Node *) expr;
while (node)
{
if (IsA(node, FieldStore))
{
/*
* ModifyPartialQuerySupported doesn't allow INSERT/UPDATE via
* FieldStore. If we decide supporting such commands, then we
* should take the first element of "newvals" list into account
* here. This is because, to support such commands, we will need
* to expand merged FieldStore into separate target entries too.
*
* For this reason, this block is not reachable atm and need to
* uncomment the following if we decide supporting such commands.
*
* """
* FieldStore *fieldStore = (FieldStore *) node;
* node = (Node *) linitial(fieldStore->newvals);
* """
*/
ereport(ERROR, (errmsg("unexpectedly got FieldStore object when "
"generating shard query")));
}
else if (IsA(node, CoerceToDomain))
{
CoerceToDomain *coerceToDomain = (CoerceToDomain *) node;
if (coerceToDomain->coercionformat != COERCE_IMPLICIT_CAST)
{
/* not an implicit coercion, cannot reach to a SubscriptingRef */
break;
}
node = (Node *) coerceToDomain->arg;
}
else if (IsA(node, SubscriptingRef))
{
return (SubscriptingRef *) node;
}
else
{
/* got a node that we are not interested in */
break;
}
}
return NULL;
}

View File

@ -3509,6 +3509,8 @@ get_update_query_targetlist_def(Query *query, List *targetList,
SubLink *cur_ma_sublink; SubLink *cur_ma_sublink;
List *ma_sublinks; List *ma_sublinks;
targetList = ExpandMergedSubscriptingRefEntries(targetList);
/* /*
* Prepare to deal with MULTIEXPR assignments: collect the source SubLinks * Prepare to deal with MULTIEXPR assignments: collect the source SubLinks
* into a list. We expect them to appear, in ID order, in resjunk tlist * into a list. We expect them to appear, in ID order, in resjunk tlist
@ -3532,6 +3534,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

@ -3525,6 +3525,8 @@ get_update_query_targetlist_def(Query *query, List *targetList,
SubLink *cur_ma_sublink; SubLink *cur_ma_sublink;
List *ma_sublinks; List *ma_sublinks;
targetList = ExpandMergedSubscriptingRefEntries(targetList);
/* /*
* Prepare to deal with MULTIEXPR assignments: collect the source SubLinks * Prepare to deal with MULTIEXPR assignments: collect the source SubLinks
* into a list. We expect them to appear, in ID order, in resjunk tlist * into a list. We expect them to appear, in ID order, in resjunk tlist
@ -3548,6 +3550,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

@ -3542,6 +3542,8 @@ get_update_query_targetlist_def(Query *query, List *targetList,
SubLink *cur_ma_sublink; SubLink *cur_ma_sublink;
List *ma_sublinks; List *ma_sublinks;
targetList = ExpandMergedSubscriptingRefEntries(targetList);
/* /*
* Prepare to deal with MULTIEXPR assignments: collect the source SubLinks * Prepare to deal with MULTIEXPR assignments: collect the source SubLinks
* into a list. We expect them to appear, in ID order, in resjunk tlist * into a list. We expect them to appear, in ID order, in resjunk tlist
@ -3565,6 +3567,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

@ -44,6 +44,7 @@ extern bool contain_nextval_expression_walker(Node *node, void *context);
extern char * pg_get_replica_identity_command(Oid tableRelationId); extern char * pg_get_replica_identity_command(Oid tableRelationId);
extern List * pg_get_row_level_security_commands(Oid relationId); extern List * pg_get_row_level_security_commands(Oid relationId);
extern const char * RoleSpecString(RoleSpec *spec, bool withQuoteIdentifier); extern const char * RoleSpecString(RoleSpec *spec, bool withQuoteIdentifier);
extern List * ExpandMergedSubscriptingRefEntries(List *targetEntryList);
extern char * flatten_reloptions(Oid relid); extern char * flatten_reloptions(Oid relid);
/* Function declarations for version dependent PostgreSQL ruleutils functions */ /* Function declarations for version dependent PostgreSQL ruleutils functions */
@ -60,5 +61,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,717 @@
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)
-- Test out of order updates on distributed table
CREATE TABLE dist_test(a1 int, b1 numeric, c1 text, d1 int);
SELECT create_distributed_table('dist_test', 'a1');
create_distributed_table
---------------------------------------------------------------------
(1 row)
INSERT INTO dist_test VALUES (1, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (1, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (2, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (2, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (3, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (3, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (3, 10.0, 'xxx', 4);
-- Router plan:
UPDATE dist_test
SET (d1, c1, b1) = (SELECT 7, 'tractor', 4.2)
WHERE a1=1
RETURNING *;
a1 | b1 | c1 | d1
---------------------------------------------------------------------
1 | 4.2 | tractor | 7
1 | 4.2 | tractor | 7
(2 rows)
-- Pushdown plan:
UPDATE dist_test
SET (d1, c1, b1) = (SELECT X, 'car', Y)
FROM (SELECT r.a * d1 as X, r.b * b1 as Y FROM update_test r, dist_test WHERE r.c=c1) upd
WHERE dist_test.a1 > 2
RETURNING *;
a1 | b1 | c1 | d1 | x | y
---------------------------------------------------------------------
3 | 46.2 | car | 287 | 287 | 46.2
3 | 46.2 | car | 287 | 287 | 46.2
3 | 46.2 | car | 287 | 287 | 46.2
(3 rows)
-- Test subscripting updates
CREATE TABLE jsonb_subscript_update (id INT, data JSONB);
SELECT create_distributed_table('jsonb_subscript_update', 'id');
create_distributed_table
---------------------------------------------------------------------
(1 row)
INSERT INTO jsonb_subscript_update VALUES (1, '{"a": 1}'), (2, '{"a": 2}');
UPDATE jsonb_subscript_update
SET data['b'] = updated_vals.b::TEXT::jsonb,
data['c'] = updated_vals.c::TEXT::jsonb,
data['d'] = updated_vals.d::TEXT::jsonb
FROM (
SELECT id,
data['a'] AS a,
data['a']::NUMERIC + 1 AS b,
data['a']::NUMERIC + 2 AS c,
data['a']::NUMERIC + 3 AS d
FROM jsonb_subscript_update
) updated_vals
WHERE jsonb_subscript_update.id = updated_vals.id;
SELECT * FROM jsonb_subscript_update ORDER BY 1,2;
id | data
---------------------------------------------------------------------
1 | {"a": 1, "b": 2, "c": 3, "d": 4}
2 | {"a": 2, "b": 3, "c": 4, "d": 5}
(2 rows)
TRUNCATE jsonb_subscript_update;
INSERT INTO jsonb_subscript_update VALUES (1, '{"a": 1}'), (2, '{"a": 2}');
-- test router update with jsonb subscript
UPDATE jsonb_subscript_update
SET data['b'] = updated_vals.b::TEXT::jsonb,
data['c'] = updated_vals.c::TEXT::jsonb,
data['d'] = updated_vals.d::TEXT::jsonb
FROM (
SELECT id,
data['a'] AS a,
data['a']::NUMERIC + 1 AS b,
data['a']::NUMERIC + 2 AS c,
data['a']::NUMERIC + 3 AS d
FROM jsonb_subscript_update
) updated_vals
WHERE jsonb_subscript_update.id = updated_vals.id
AND jsonb_subscript_update.id = 1;
SELECT * FROM jsonb_subscript_update WHERE id = 1 ORDER BY 1,2;
id | data
---------------------------------------------------------------------
1 | {"a": 1, "b": 2, "c": 3, "d": 4}
(1 row)
TRUNCATE jsonb_subscript_update;
-- Test updates on nested json objects
INSERT INTO jsonb_subscript_update VALUES (1, '{"a": {"c":20, "d" : 200}}'), (2, '{"a": {"d":10, "c" : 100}}');
BEGIN;
UPDATE jsonb_subscript_update
SET DATA['a']['c'] = (updated_vals.d + updated_vals.a::NUMERIC)::TEXT::JSONB
FROM
(SELECT id,
DATA['a']['c'] AS a,
DATA['a']['c']::NUMERIC + 1 AS b,
DATA['a']['c']::NUMERIC + 2 AS c,
DATA['a']['d']::NUMERIC + 3 AS d
FROM jsonb_subscript_update) updated_vals
WHERE jsonb_subscript_update.id = updated_vals.id;
SELECT * FROM jsonb_subscript_update ORDER BY 1,2;
id | data
---------------------------------------------------------------------
1 | {"a": {"c": 223, "d": 200}}
2 | {"a": {"c": 113, "d": 10}}
(2 rows)
ROLLBACK;
BEGIN;
-- Router plan
UPDATE jsonb_subscript_update
SET DATA['a']['c'] = (updated_vals.d + updated_vals.a::NUMERIC)::TEXT::JSONB
FROM
(SELECT id,
DATA['a']['c'] AS a,
DATA['a']['c']::NUMERIC + 1 AS b,
DATA['a']['c']::NUMERIC + 2 AS c,
DATA['a']['d']::NUMERIC + 3 AS d
FROM jsonb_subscript_update) updated_vals
WHERE jsonb_subscript_update.id = updated_vals.id
AND jsonb_subscript_update.id = 1;
SELECT * FROM jsonb_subscript_update WHERE id = 1 ORDER BY 1,2;
id | data
---------------------------------------------------------------------
1 | {"a": {"c": 223, "d": 200}}
(1 row)
ROLLBACK;
TRUNCATE jsonb_subscript_update;
INSERT INTO jsonb_subscript_update VALUES (1, '{"a": 1}'), (2, '{"a": 2}'), (4, '{"a": 4, "b": 10}');
ALTER TABLE jsonb_subscript_update ADD CONSTRAINT pkey PRIMARY KEY (id, data);
INSERT INTO jsonb_subscript_update VALUES (1, '{"a": 1}'), (2, '{"a": 2}')
ON CONFLICT (id, data)
DO UPDATE SET data['d']=(jsonb_subscript_update.data['a']::INT*100)::TEXT::JSONB,
data['b']=(jsonb_subscript_update.data['a']::INT*-100)::TEXT::JSONB;
SELECT * FROM jsonb_subscript_update ORDER BY 1,2;
id | data
---------------------------------------------------------------------
1 | {"a": 1, "b": -100, "d": 100}
2 | {"a": 2, "b": -200, "d": 200}
4 | {"a": 4, "b": 10}
(3 rows)
CREATE TABLE nested_obj_update(id INT, data JSONB, text_col TEXT);
SELECT create_distributed_table('nested_obj_update', 'id');
create_distributed_table
---------------------------------------------------------------------
(1 row)
INSERT INTO nested_obj_update VALUES
(1, '{"a": [1,2,3], "b": [4,5,6], "c": [7,8,9], "d": [1,2,1,2]}', '4'),
(2, '{"a": [10,20,30], "b": [41,51,61], "c": [72,82,92], "d": [11,21,11,21]}', '6');
BEGIN;
-- Pushdown plan
UPDATE nested_obj_update
SET data['a'][0] = (updated_vals.b * 1)::TEXT::JSONB,
data['b'][2] = (updated_vals.c * 2)::TEXT::JSONB,
data['c'][0] = (updated_vals.d * 3)::TEXT::JSONB,
text_col = (nested_obj_update.id*1000)::TEXT,
data['a'][0] = (text_col::INT * data['a'][0]::INT)::TEXT::JSONB,
data['d'][6] = (nested_obj_update.id*1)::TEXT::JSONB,
data['d'][4] = (nested_obj_update.id*2)::TEXT::JSONB
FROM (
SELECT id,
data['a'][0] AS a,
data['b'][0]::NUMERIC + 1 AS b,
data['c'][0]::NUMERIC + 2 AS c,
data['c'][1]::NUMERIC + 3 AS d
FROM nested_obj_update
) updated_vals
WHERE nested_obj_update.id = updated_vals.id;
SELECT * FROM nested_obj_update ORDER BY 1,2,3;
id | data | text_col
---------------------------------------------------------------------
1 | {"a": [4, 2, 3], "b": [4, 5, 18], "c": [33, 8, 9], "d": [1, 2, 1, 2, 2, null, 1]} | 1000
2 | {"a": [60, 20, 30], "b": [41, 51, 148], "c": [255, 82, 92], "d": [11, 21, 11, 21, 4, null, 2]} | 2000
(2 rows)
ROLLBACK;
BEGIN;
-- Router plan
UPDATE nested_obj_update
SET data['a'][0] = (updated_vals.b * 1)::TEXT::JSONB,
data['b'][2] = (updated_vals.c * 2)::TEXT::JSONB,
data['c'][0] = (updated_vals.d * 3)::TEXT::JSONB,
text_col = (nested_obj_update.id*1000)::TEXT,
data['a'][0] = (text_col::INT * data['a'][0]::INT)::TEXT::JSONB,
data['d'][6] = (nested_obj_update.id*1)::TEXT::JSONB,
data['d'][4] = (nested_obj_update.id*2)::TEXT::JSONB
FROM (
SELECT id,
data['a'][0] AS a,
data['b'][0]::NUMERIC + 1 AS b,
data['c'][0]::NUMERIC + 2 AS c,
data['c'][1]::NUMERIC + 3 AS d
FROM nested_obj_update
) updated_vals
WHERE nested_obj_update.id = updated_vals.id
AND nested_obj_update.id = 2;
SELECT * FROM nested_obj_update WHERE id = 2 ORDER BY 1,2,3;
id | data | text_col
---------------------------------------------------------------------
2 | {"a": [60, 20, 30], "b": [41, 51, 148], "c": [255, 82, 92], "d": [11, 21, 11, 21, 4, null, 2]} | 2000
(1 row)
ROLLBACK;
-- suppress cascade messages
SET client_min_messages to ERROR;
DROP SCHEMA multi_update_select CASCADE;
RESET client_min_messages;

View File

@ -0,0 +1,105 @@
\set VERBOSITY terse
SET citus.next_shard_id TO 1520000;
CREATE SCHEMA subscripting_op;
SET search_path TO subscripting_op;
CREATE TABLE arr_subs_update(id INT, arr INT[], text_col TEXT, int_col_1 INT, int_col_2 INT);
SELECT create_distributed_table('arr_subs_update', 'id');
create_distributed_table
---------------------------------------------------------------------
(1 row)
INSERT INTO arr_subs_update
VALUES (1, '{1,2,3}', 'foo', 50, 60),
(2, '{4,5,6}', 'bar', 60, 70),
(3, '{7,8,9}', 'baz', 70, 80);
BEGIN;
UPDATE arr_subs_update
SET arr[1] = updated_vals.b,
arr[3] = updated_vals.d,
int_col_2 = 400,
arr[2] = updated_vals.c
FROM (
SELECT id,
arr[0] AS a,
arr[1]::NUMERIC + 1 AS b,
arr[2]::NUMERIC + 2 AS c,
arr[3]::NUMERIC + 3 AS d
FROM arr_subs_update
) updated_vals
WHERE arr_subs_update.id = updated_vals.id;
SELECT * FROM arr_subs_update ORDER BY 1,2,3,4;
id | arr | text_col | int_col_1 | int_col_2
---------------------------------------------------------------------
1 | {2,4,6} | foo | 50 | 400
2 | {5,7,9} | bar | 60 | 400
3 | {8,10,12} | baz | 70 | 400
(3 rows)
ROLLBACK;
BEGIN;
-- Test fast path router plan for subscripting update
UPDATE arr_subs_update
SET arr[1] = updated_vals.b,
arr[3] = updated_vals.d,
int_col_2 = 400,
arr[2] = updated_vals.c
FROM (
SELECT id,
arr[0] AS a,
arr[1]::NUMERIC + 1 AS b,
arr[2]::NUMERIC + 2 AS c,
arr[3]::NUMERIC + 3 AS d
FROM arr_subs_update
) updated_vals
WHERE arr_subs_update.id = updated_vals.id
AND arr_subs_update.id = 1;
SELECT * FROM arr_subs_update
WHERE id=1 ORDER BY 1,2,3,4;
id | arr | text_col | int_col_1 | int_col_2
---------------------------------------------------------------------
1 | {2,4,6} | foo | 50 | 400
(1 row)
ROLLBACK;
-- test if we can properly expand target list entries when there are dropped columns
ALTER TABLE arr_subs_update DROP COLUMN int_col_1;
BEGIN;
UPDATE arr_subs_update
SET arr[1] = updated_vals.b,
arr[3] = updated_vals.d,
int_col_2 = 400,
arr[2] = updated_vals.c
FROM (
SELECT id,
arr[0] AS a,
arr[1]::NUMERIC + 1 AS b,
arr[2]::NUMERIC + 2 AS c,
arr[3]::NUMERIC + 3 AS d
FROM arr_subs_update
) updated_vals
WHERE arr_subs_update.id = updated_vals.id;
SELECT * FROM arr_subs_update ORDER BY 1,2,3,4;
id | arr | text_col | int_col_2
---------------------------------------------------------------------
1 | {2,4,6} | foo | 400
2 | {5,7,9} | bar | 400
3 | {8,10,12} | baz | 400
(3 rows)
ROLLBACK;
TRUNCATE arr_subs_update;
INSERT INTO arr_subs_update VALUES (1, '{1,2,3}', 'foo', 60), (2, '{4,5,6}', 'bar', 70);
ALTER TABLE arr_subs_update ADD CONSTRAINT pkey PRIMARY KEY (id, arr);
INSERT INTO arr_subs_update VALUES (1, '{1,2,3}')
ON CONFLICT (id, arr)
DO UPDATE SET arr[0]=100, arr[1]=200, arr[5]=500;
SELECT * FROM arr_subs_update ORDER BY 1,2,3,4;
id | arr | text_col | int_col_2
---------------------------------------------------------------------
1 | [0:5]={100,200,2,3,NULL,500} | foo | 60
2 | {4,5,6} | bar | 70
(2 rows)
SET client_min_messages TO WARNING;
DROP SCHEMA subscripting_op CASCADE;

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

@ -93,6 +93,7 @@ test: multi_average_expression multi_working_columns multi_having_pushdown havin
test: multi_array_agg multi_limit_clause multi_orderby_limit_pushdown test: multi_array_agg multi_limit_clause multi_orderby_limit_pushdown
test: multi_jsonb_agg multi_jsonb_object_agg multi_json_agg multi_json_object_agg bool_agg ch_bench_having chbenchmark_all_queries expression_reference_join anonymous_columns test: multi_jsonb_agg multi_jsonb_object_agg multi_json_agg multi_json_object_agg bool_agg ch_bench_having chbenchmark_all_queries expression_reference_join anonymous_columns
test: ch_bench_subquery_repartition test: ch_bench_subquery_repartition
test: subscripting_op
test: multi_agg_type_conversion multi_count_type_conversion recursive_relation_planning_restriction_pushdown test: multi_agg_type_conversion multi_count_type_conversion recursive_relation_planning_restriction_pushdown
test: multi_partition_pruning single_hash_repartition_join unsupported_lateral_subqueries test: multi_partition_pruning single_hash_repartition_join unsupported_lateral_subqueries
test: multi_join_pruning multi_hash_pruning intermediate_result_pruning test: multi_join_pruning multi_hash_pruning intermediate_result_pruning

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,416 @@
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;
-- Test out of order updates on distributed table
CREATE TABLE dist_test(a1 int, b1 numeric, c1 text, d1 int);
SELECT create_distributed_table('dist_test', 'a1');
INSERT INTO dist_test VALUES (1, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (1, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (2, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (2, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (3, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (3, 10.0, 'xxx', 4);
INSERT INTO dist_test VALUES (3, 10.0, 'xxx', 4);
-- Router plan:
UPDATE dist_test
SET (d1, c1, b1) = (SELECT 7, 'tractor', 4.2)
WHERE a1=1
RETURNING *;
-- Pushdown plan:
UPDATE dist_test
SET (d1, c1, b1) = (SELECT X, 'car', Y)
FROM (SELECT r.a * d1 as X, r.b * b1 as Y FROM update_test r, dist_test WHERE r.c=c1) upd
WHERE dist_test.a1 > 2
RETURNING *;
-- Test subscripting updates
CREATE TABLE jsonb_subscript_update (id INT, data JSONB);
SELECT create_distributed_table('jsonb_subscript_update', 'id');
INSERT INTO jsonb_subscript_update VALUES (1, '{"a": 1}'), (2, '{"a": 2}');
UPDATE jsonb_subscript_update
SET data['b'] = updated_vals.b::TEXT::jsonb,
data['c'] = updated_vals.c::TEXT::jsonb,
data['d'] = updated_vals.d::TEXT::jsonb
FROM (
SELECT id,
data['a'] AS a,
data['a']::NUMERIC + 1 AS b,
data['a']::NUMERIC + 2 AS c,
data['a']::NUMERIC + 3 AS d
FROM jsonb_subscript_update
) updated_vals
WHERE jsonb_subscript_update.id = updated_vals.id;
SELECT * FROM jsonb_subscript_update ORDER BY 1,2;
TRUNCATE jsonb_subscript_update;
INSERT INTO jsonb_subscript_update VALUES (1, '{"a": 1}'), (2, '{"a": 2}');
-- test router update with jsonb subscript
UPDATE jsonb_subscript_update
SET data['b'] = updated_vals.b::TEXT::jsonb,
data['c'] = updated_vals.c::TEXT::jsonb,
data['d'] = updated_vals.d::TEXT::jsonb
FROM (
SELECT id,
data['a'] AS a,
data['a']::NUMERIC + 1 AS b,
data['a']::NUMERIC + 2 AS c,
data['a']::NUMERIC + 3 AS d
FROM jsonb_subscript_update
) updated_vals
WHERE jsonb_subscript_update.id = updated_vals.id
AND jsonb_subscript_update.id = 1;
SELECT * FROM jsonb_subscript_update WHERE id = 1 ORDER BY 1,2;
TRUNCATE jsonb_subscript_update;
-- Test updates on nested json objects
INSERT INTO jsonb_subscript_update VALUES (1, '{"a": {"c":20, "d" : 200}}'), (2, '{"a": {"d":10, "c" : 100}}');
BEGIN;
UPDATE jsonb_subscript_update
SET DATA['a']['c'] = (updated_vals.d + updated_vals.a::NUMERIC)::TEXT::JSONB
FROM
(SELECT id,
DATA['a']['c'] AS a,
DATA['a']['c']::NUMERIC + 1 AS b,
DATA['a']['c']::NUMERIC + 2 AS c,
DATA['a']['d']::NUMERIC + 3 AS d
FROM jsonb_subscript_update) updated_vals
WHERE jsonb_subscript_update.id = updated_vals.id;
SELECT * FROM jsonb_subscript_update ORDER BY 1,2;
ROLLBACK;
BEGIN;
-- Router plan
UPDATE jsonb_subscript_update
SET DATA['a']['c'] = (updated_vals.d + updated_vals.a::NUMERIC)::TEXT::JSONB
FROM
(SELECT id,
DATA['a']['c'] AS a,
DATA['a']['c']::NUMERIC + 1 AS b,
DATA['a']['c']::NUMERIC + 2 AS c,
DATA['a']['d']::NUMERIC + 3 AS d
FROM jsonb_subscript_update) updated_vals
WHERE jsonb_subscript_update.id = updated_vals.id
AND jsonb_subscript_update.id = 1;
SELECT * FROM jsonb_subscript_update WHERE id = 1 ORDER BY 1,2;
ROLLBACK;
TRUNCATE jsonb_subscript_update;
INSERT INTO jsonb_subscript_update VALUES (1, '{"a": 1}'), (2, '{"a": 2}'), (4, '{"a": 4, "b": 10}');
ALTER TABLE jsonb_subscript_update ADD CONSTRAINT pkey PRIMARY KEY (id, data);
INSERT INTO jsonb_subscript_update VALUES (1, '{"a": 1}'), (2, '{"a": 2}')
ON CONFLICT (id, data)
DO UPDATE SET data['d']=(jsonb_subscript_update.data['a']::INT*100)::TEXT::JSONB,
data['b']=(jsonb_subscript_update.data['a']::INT*-100)::TEXT::JSONB;
SELECT * FROM jsonb_subscript_update ORDER BY 1,2;
CREATE TABLE nested_obj_update(id INT, data JSONB, text_col TEXT);
SELECT create_distributed_table('nested_obj_update', 'id');
INSERT INTO nested_obj_update VALUES
(1, '{"a": [1,2,3], "b": [4,5,6], "c": [7,8,9], "d": [1,2,1,2]}', '4'),
(2, '{"a": [10,20,30], "b": [41,51,61], "c": [72,82,92], "d": [11,21,11,21]}', '6');
BEGIN;
-- Pushdown plan
UPDATE nested_obj_update
SET data['a'][0] = (updated_vals.b * 1)::TEXT::JSONB,
data['b'][2] = (updated_vals.c * 2)::TEXT::JSONB,
data['c'][0] = (updated_vals.d * 3)::TEXT::JSONB,
text_col = (nested_obj_update.id*1000)::TEXT,
data['a'][0] = (text_col::INT * data['a'][0]::INT)::TEXT::JSONB,
data['d'][6] = (nested_obj_update.id*1)::TEXT::JSONB,
data['d'][4] = (nested_obj_update.id*2)::TEXT::JSONB
FROM (
SELECT id,
data['a'][0] AS a,
data['b'][0]::NUMERIC + 1 AS b,
data['c'][0]::NUMERIC + 2 AS c,
data['c'][1]::NUMERIC + 3 AS d
FROM nested_obj_update
) updated_vals
WHERE nested_obj_update.id = updated_vals.id;
SELECT * FROM nested_obj_update ORDER BY 1,2,3;
ROLLBACK;
BEGIN;
-- Router plan
UPDATE nested_obj_update
SET data['a'][0] = (updated_vals.b * 1)::TEXT::JSONB,
data['b'][2] = (updated_vals.c * 2)::TEXT::JSONB,
data['c'][0] = (updated_vals.d * 3)::TEXT::JSONB,
text_col = (nested_obj_update.id*1000)::TEXT,
data['a'][0] = (text_col::INT * data['a'][0]::INT)::TEXT::JSONB,
data['d'][6] = (nested_obj_update.id*1)::TEXT::JSONB,
data['d'][4] = (nested_obj_update.id*2)::TEXT::JSONB
FROM (
SELECT id,
data['a'][0] AS a,
data['b'][0]::NUMERIC + 1 AS b,
data['c'][0]::NUMERIC + 2 AS c,
data['c'][1]::NUMERIC + 3 AS d
FROM nested_obj_update
) updated_vals
WHERE nested_obj_update.id = updated_vals.id
AND nested_obj_update.id = 2;
SELECT * FROM nested_obj_update WHERE id = 2 ORDER BY 1,2,3;
ROLLBACK;
-- suppress cascade messages
SET client_min_messages to ERROR;
DROP SCHEMA multi_update_select CASCADE;
RESET client_min_messages;

View File

@ -0,0 +1,93 @@
\set VERBOSITY terse
SET citus.next_shard_id TO 1520000;
CREATE SCHEMA subscripting_op;
SET search_path TO subscripting_op;
CREATE TABLE arr_subs_update(id INT, arr INT[], text_col TEXT, int_col_1 INT, int_col_2 INT);
SELECT create_distributed_table('arr_subs_update', 'id');
INSERT INTO arr_subs_update
VALUES (1, '{1,2,3}', 'foo', 50, 60),
(2, '{4,5,6}', 'bar', 60, 70),
(3, '{7,8,9}', 'baz', 70, 80);
BEGIN;
UPDATE arr_subs_update
SET arr[1] = updated_vals.b,
arr[3] = updated_vals.d,
int_col_2 = 400,
arr[2] = updated_vals.c
FROM (
SELECT id,
arr[0] AS a,
arr[1]::NUMERIC + 1 AS b,
arr[2]::NUMERIC + 2 AS c,
arr[3]::NUMERIC + 3 AS d
FROM arr_subs_update
) updated_vals
WHERE arr_subs_update.id = updated_vals.id;
SELECT * FROM arr_subs_update ORDER BY 1,2,3,4;
ROLLBACK;
BEGIN;
-- Test fast path router plan for subscripting update
UPDATE arr_subs_update
SET arr[1] = updated_vals.b,
arr[3] = updated_vals.d,
int_col_2 = 400,
arr[2] = updated_vals.c
FROM (
SELECT id,
arr[0] AS a,
arr[1]::NUMERIC + 1 AS b,
arr[2]::NUMERIC + 2 AS c,
arr[3]::NUMERIC + 3 AS d
FROM arr_subs_update
) updated_vals
WHERE arr_subs_update.id = updated_vals.id
AND arr_subs_update.id = 1;
SELECT * FROM arr_subs_update
WHERE id=1 ORDER BY 1,2,3,4;
ROLLBACK;
-- test if we can properly expand target list entries when there are dropped columns
ALTER TABLE arr_subs_update DROP COLUMN int_col_1;
BEGIN;
UPDATE arr_subs_update
SET arr[1] = updated_vals.b,
arr[3] = updated_vals.d,
int_col_2 = 400,
arr[2] = updated_vals.c
FROM (
SELECT id,
arr[0] AS a,
arr[1]::NUMERIC + 1 AS b,
arr[2]::NUMERIC + 2 AS c,
arr[3]::NUMERIC + 3 AS d
FROM arr_subs_update
) updated_vals
WHERE arr_subs_update.id = updated_vals.id;
SELECT * FROM arr_subs_update ORDER BY 1,2,3,4;
ROLLBACK;
TRUNCATE arr_subs_update;
INSERT INTO arr_subs_update VALUES (1, '{1,2,3}', 'foo', 60), (2, '{4,5,6}', 'bar', 70);
ALTER TABLE arr_subs_update ADD CONSTRAINT pkey PRIMARY KEY (id, arr);
INSERT INTO arr_subs_update VALUES (1, '{1,2,3}')
ON CONFLICT (id, arr)
DO UPDATE SET arr[0]=100, arr[1]=200, arr[5]=500;
SELECT * FROM arr_subs_update ORDER BY 1,2,3,4;
SET client_min_messages TO WARNING;
DROP SCHEMA subscripting_op CASCADE;