diff --git a/src/backend/distributed/deparser/ruleutils_15.c b/src/backend/distributed/deparser/ruleutils_15.c index 1dae9f27d..6dabacd49 100644 --- a/src/backend/distributed/deparser/ruleutils_15.c +++ b/src/backend/distributed/deparser/ruleutils_15.c @@ -368,6 +368,8 @@ static void get_insert_query_def(Query *query, deparse_context *context, bool colNamesVisible); static void get_update_query_def(Query *query, deparse_context *context, bool colNamesVisible); +static void get_merge_query_def(Query *query, deparse_context *context); + static void get_update_query_targetlist_def(Query *query, List *targetList, deparse_context *context, RangeTblEntry *rte); @@ -459,6 +461,7 @@ static char *generate_function_name(Oid funcid, int nargs, List *argnames, Oid *argtypes, bool has_variadic, bool *use_variadic_p, ParseExprKind special_exprkind); +static List *get_insert_column_names_list(List *targetList, StringInfo buf, deparse_context *context, RangeTblEntry *rte); #define only_marker(rte) ((rte)->inh ? "" : "ONLY ") @@ -2095,6 +2098,10 @@ get_query_def_extended(Query *query, StringInfo buf, List *parentnamespace, get_delete_query_def(query, &context, colNamesVisible); break; + case CMD_MERGE: + get_merge_query_def(query, &context); + break; + case CMD_NOTHING: appendStringInfoString(buf, "NOTHING"); break; @@ -3225,9 +3232,8 @@ get_insert_query_def(Query *query, deparse_context *context, RangeTblEntry *select_rte = NULL; RangeTblEntry *values_rte = NULL; RangeTblEntry *rte; - char *sep; ListCell *l; - List *strippedexprs; + List *strippedexprs = NIL; /* Insert the WITH clause if given */ get_with_clause(query, context); @@ -3281,43 +3287,11 @@ get_insert_query_def(Query *query, deparse_context *context, * Add the insert-column-names list. Any indirection decoration needed on * the column names can be inferred from the top targetlist. */ - strippedexprs = NIL; - sep = ""; if (query->targetList) - appendStringInfoChar(buf, '('); - foreach(l, query->targetList) { - TargetEntry *tle = (TargetEntry *) lfirst(l); - - if (tle->resjunk) - continue; /* ignore junk entries */ - - appendStringInfoString(buf, sep); - sep = ", "; - - /* - * Put out name of target column; look in the catalogs, not at - * tle->resname, since resname will fail to track RENAME. - */ - appendStringInfoString(buf, - quote_identifier(get_attname(rte->relid, - tle->resno, - false))); - - /* - * Print any indirection needed (subfields or subscripts), and strip - * off the top-level nodes representing the indirection assignments. - * Add the stripped expressions to strippedexprs. (If it's a - * single-VALUES statement, the stripped expressions are the VALUES to - * print below. Otherwise they're just Vars and not really - * interesting.) - */ - strippedexprs = lappend(strippedexprs, - processIndirection((Node *) tle->expr, - context)); + strippedexprs = get_insert_column_names_list(query->targetList, + buf, context, rte); } - if (query->targetList) - appendStringInfoString(buf, ") "); if (query->override) { @@ -3741,6 +3715,148 @@ get_delete_query_def(Query *query, deparse_context *context, } } +/* ---------- + * get_merge_query_def - Parse back a MERGE parsetree + * ---------- + */ +static void +get_merge_query_def(Query *query, deparse_context *context) +{ + StringInfo buf = context->buf; + RangeTblEntry *targetRte; + + /* Insert the WITH clause if given */ + get_with_clause(query, context); + + /* + * Start the query with MERGE INTO + */ + targetRte = rt_fetch(query->resultRelation, query->rtable); + + if (PRETTY_INDENT(context)) + { + appendStringInfoChar(buf, ' '); + context->indentLevel += PRETTYINDENT_STD; + } + + /* if it's a shard, do differently */ + if (GetRangeTblKind(targetRte) == CITUS_RTE_SHARD) + { + char *fragmentSchemaName = NULL; + char *fragmentTableName = NULL; + + ExtractRangeTblExtraData(targetRte, NULL, &fragmentSchemaName, &fragmentTableName, NULL); + + /* use schema and table name from the remote alias */ + appendStringInfo(buf, "MERGE INTO %s%s", + only_marker(targetRte), + generate_fragment_name(fragmentSchemaName, fragmentTableName)); + + if(targetRte->eref != NULL) + appendStringInfo(buf, " %s", + quote_identifier(get_rtable_name(query->resultRelation, context))); + } + else + { + appendStringInfo(buf, "MERGE INTO %s%s", + only_marker(targetRte), + generate_relation_or_shard_name(targetRte->relid, + context->distrelid, + context->shardid, NIL)); + + if (targetRte->alias != NULL) + appendStringInfo(buf, " %s", + quote_identifier(get_rtable_name(query->resultRelation, context))); + } + + /* + * Add the MERGE source relation -- USING + */ + get_from_clause(query, " USING ", context); + + /* + * Add the MERGE ON condition + */ + Assert(query->jointree->quals != NULL); + { + appendContextKeyword(context, " ON ", + -PRETTYINDENT_STD, PRETTYINDENT_STD, 1); + get_rule_expr(query->jointree->quals, context, false); + } + + ListCell *actionCell = NULL; + foreach(actionCell, query->mergeActionList) + { + MergeAction *action = (MergeAction *) lfirst(actionCell); + + /* Add WHEN [NOT] MATCHED */ + appendContextKeyword(context, " WHEN", + -PRETTYINDENT_STD, PRETTYINDENT_STD, 1); + appendStringInfo(buf, " %s", action->matched ? "MATCHED" : "NOT MATCHED"); + + /* Add optional AND */ + if (action->qual) + { + appendContextKeyword(context, " AND ", + -PRETTYINDENT_STD, PRETTYINDENT_STD, 1); + get_rule_expr(action->qual, context, false); + } + + appendContextKeyword(context, " THEN", + -PRETTYINDENT_STD, PRETTYINDENT_STD, 1); + + switch (action->commandType) + { + case CMD_INSERT: + { + appendStringInfo(buf, " INSERT " ); + List *strippedexprs = NIL; + + if (action->targetList) + { + strippedexprs = get_insert_column_names_list(action->targetList, + buf, context, targetRte); + } + + if (strippedexprs) + { + /* Add the single-VALUES expression list */ + appendContextKeyword(context, "VALUES (", + -PRETTYINDENT_STD, PRETTYINDENT_STD, 2); + get_rule_list_toplevel(strippedexprs, context, false); + appendStringInfoChar(buf, ')'); + } + else + { + /* No expressions, so it must be DEFAULT VALUES */ + appendStringInfoString(buf, "DEFAULT VALUES"); + } + } + break; + + case CMD_UPDATE: + appendStringInfo(buf, " UPDATE SET " ); + get_update_query_targetlist_def(query, action->targetList, + context, targetRte); + break; + + case CMD_DELETE: + appendStringInfo(buf, " DELETE" ); + break; + + case CMD_NOTHING: + appendStringInfo(buf, " DO NOTHING " ); + break; + + default: + elog(ERROR, "unknown action in MERGE WHEN clause"); + } + } + + ereport(DEBUG1, (errmsg("", buf->data))); +} + + /* ---------- * get_utility_query_def - Parse back a UTILITY parsetree * ---------- @@ -8761,4 +8877,54 @@ getOwnedSequences_internal(Oid relid, AttrNumber attnum, char deptype) return result; } +/* + * get_insert_column_names_list Prepares the insert-column-names list. Any indirection + * decoration needed on the column names can be inferred from the top targetlist. + */ +static List * +get_insert_column_names_list(List *targetList, StringInfo buf, + deparse_context *context, RangeTblEntry *rte) +{ + char *sep; + ListCell *l; + List *strippedexprs; + + strippedexprs = NIL; + sep = ""; + appendStringInfoChar(buf, '('); + foreach(l, targetList) + { + TargetEntry *tle = (TargetEntry *) lfirst(l); + + if (tle->resjunk) + continue; /* ignore junk entries */ + + appendStringInfoString(buf, sep); + sep = ", "; + + /* + * Put out name of target column; look in the catalogs, not at + * tle->resname, since resname will fail to track RENAME. + */ + appendStringInfoString(buf, + quote_identifier(get_attname(rte->relid, + tle->resno, + false))); + + /* + * Print any indirection needed (subfields or subscripts), and strip + * off the top-level nodes representing the indirection assignments. + * Add the stripped expressions to strippedexprs. (If it's a + * single-VALUES statement, the stripped expressions are the VALUES to + * print below. Otherwise they're just Vars and not really + * interesting.) + */ + strippedexprs = lappend(strippedexprs, + processIndirection((Node *) tle->expr, + context)); + } + appendStringInfoString(buf, ") "); + + return strippedexprs; +} #endif /* (PG_VERSION_NUM >= PG_VERSION_15) && (PG_VERSION_NUM < PG_VERSION_16) */ diff --git a/src/backend/distributed/planner/deparse_shard_query.c b/src/backend/distributed/planner/deparse_shard_query.c index 1c5c62034..e62821ad0 100644 --- a/src/backend/distributed/planner/deparse_shard_query.c +++ b/src/backend/distributed/planner/deparse_shard_query.c @@ -78,7 +78,7 @@ RebuildQueryStrings(Job *workerJob) query = copyObject(originalQuery); } - if (UpdateOrDeleteQuery(query)) + if (UpdateOrDeleteOrMergeQuery(query)) { List *relationShardList = task->relationShardList; diff --git a/src/backend/distributed/planner/distributed_planner.c b/src/backend/distributed/planner/distributed_planner.c index b02317773..c23d3b66c 100644 --- a/src/backend/distributed/planner/distributed_planner.c +++ b/src/backend/distributed/planner/distributed_planner.c @@ -25,6 +25,7 @@ #include "distributed/citus_nodefuncs.h" #include "distributed/citus_nodes.h" #include "distributed/citus_ruleutils.h" +#include "distributed/colocation_utils.h" #include "distributed/commands.h" #include "distributed/cte_inline.h" #include "distributed/function_call_delegation.h" @@ -74,7 +75,8 @@ static uint64 NextPlanId = 1; /* keep track of planner call stack levels */ int PlannerLevel = 0; -static void ErrorIfQueryHasMergeCommand(Query *queryTree); +static void ErrorIfQueryHasUnsupportedMergeCommand(Query *queryTree, + List *rangeTableList); static bool ContainsMergeCommandWalker(Node *node); static bool ListContainsDistributedTableRTE(List *rangeTableList, bool *maybeHasForeignDistributedTable); @@ -130,7 +132,7 @@ static PlannedStmt * PlanDistributedStmt(DistributedPlanningContext *planContext static RTEListProperties * GetRTEListProperties(List *rangeTableList); static List * TranslatedVars(PlannerInfo *root, int relationIndex); static void WarnIfListHasForeignDistributedTable(List *rangeTableList); - +static void ErrorIfMergeHasUnsupportedTables(Query *parse, List *rangeTableList); /* Distributed planner hook */ PlannedStmt * @@ -202,7 +204,7 @@ distributed_planner(Query *parse, * Fast path queries cannot have merge command, and we * prevent the remaining here. */ - ErrorIfQueryHasMergeCommand(parse); + ErrorIfQueryHasUnsupportedMergeCommand(parse, rangeTableList); /* * When there are partitioned tables (not applicable to fast path), @@ -303,11 +305,13 @@ distributed_planner(Query *parse, /* - * ErrorIfQueryHasMergeCommand walks over the query tree and throws error - * if there are any Merge command (e.g., CMD_MERGE) in the query tree. + * ErrorIfQueryHasUnsupportedMergeCommand walks over the query tree and bails out + * if there is no Merge command (e.g., CMD_MERGE) in the query tree. For merge, + * looks for all supported combinations, throws an exception if any violations + * are seen. */ static void -ErrorIfQueryHasMergeCommand(Query *queryTree) +ErrorIfQueryHasUnsupportedMergeCommand(Query *queryTree, List *rangeTableList) { /* * Postgres currently doesn't support Merge queries inside subqueries and @@ -316,11 +320,20 @@ ErrorIfQueryHasMergeCommand(Query *queryTree) * We do not call this path for fast-path queries to avoid this additional * overhead. */ - if (ContainsMergeCommandWalker((Node *) queryTree)) + if (!ContainsMergeCommandWalker((Node *) queryTree)) { - ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("MERGE command is not supported on Citus tables yet"))); + /* No MERGE found */ + return; } + + + /* + * In Citus we have limited support for MERGE, it's allowed + * only if all the tables(target, source or any CTE) tables + * are are local i.e. a combination of Citus local and Non-Citus + * tables (regular Postgres tables). + */ + ErrorIfMergeHasUnsupportedTables(queryTree, rangeTableList); } @@ -331,7 +344,10 @@ ErrorIfQueryHasMergeCommand(Query *queryTree) static bool ContainsMergeCommandWalker(Node *node) { -#if PG_VERSION_NUM >= PG_VERSION_15 + #if PG_VERSION_NUM < PG_VERSION_15 + return false; + #endif + if (node == NULL) { return false; @@ -340,7 +356,7 @@ ContainsMergeCommandWalker(Node *node) if (IsA(node, Query)) { Query *query = (Query *) node; - if (query->commandType == CMD_MERGE) + if (IsMergeQuery(query)) { return true; } @@ -349,7 +365,6 @@ ContainsMergeCommandWalker(Node *node) } return expression_tree_walker(node, ContainsMergeCommandWalker, NULL); -#endif return false; } @@ -628,7 +643,7 @@ IsModifyCommand(Query *query) CmdType commandType = query->commandType; if (commandType == CMD_INSERT || commandType == CMD_UPDATE || - commandType == CMD_DELETE) + commandType == CMD_DELETE || commandType == CMD_MERGE) { return true; } @@ -2592,3 +2607,148 @@ WarnIfListHasForeignDistributedTable(List *rangeTableList) } } } + + +/* + * IsMergeAllowedOnRelation takes a relation entry and checks if MERGE command is + * permitted on special relations, such as materialized view, returns true only if + * it's a "source" relation. + */ +bool +IsMergeAllowedOnRelation(Query *parse, RangeTblEntry *rte) +{ + if (!IsMergeQuery(parse)) + { + return false; + } + + RangeTblEntry *targetRte = rt_fetch(parse->resultRelation, parse->rtable); + + /* Is it a target relation? */ + if (targetRte->relid == rte->relid) + { + return false; + } + + return true; +} + + +/* + * ErrorIfMergeHasUnsupportedTables checks if all the tables(target, source or any CTE + * present) in the MERGE command are local i.e. a combination of Citus local and Non-Citus + * tables (regular Postgres tables), raises an exception for all other combinations. + */ +static void +ErrorIfMergeHasUnsupportedTables(Query *parse, List *rangeTableList) +{ + ListCell *tableCell = NULL; + + foreach(tableCell, rangeTableList) + { + RangeTblEntry *rangeTableEntry = (RangeTblEntry *) lfirst(tableCell); + Oid relationId = rangeTableEntry->relid; + + switch (rangeTableEntry->rtekind) + { + case RTE_RELATION: + { + /* Check the relation type */ + break; + } + + case RTE_SUBQUERY: + case RTE_FUNCTION: + case RTE_TABLEFUNC: + case RTE_VALUES: + case RTE_JOIN: + case RTE_CTE: + { + /* Skip them as base table(s) will be checked */ + continue; + } + + /* + * RTE_NAMEDTUPLESTORE is typically used in ephmeral named relations, + * such as, trigger data; until we find a genuine use case, raise an + * exception. + * RTE_RESULT is a node added by the planner and we shouldn't + * encounter it in the parse tree. + */ + case RTE_NAMEDTUPLESTORE: + case RTE_RESULT: + { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("MERGE command is not supported with " + "Tuplestores and results"))); + break; + } + + default: + { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("MERGE command: Unrecognized range table entry."))); + } + } + + /* RTE Relation can be of various types, check them now */ + + /* skip the regular views as they are replaced with subqueries */ + if (rangeTableEntry->relkind == RELKIND_VIEW) + { + continue; + } + + if (rangeTableEntry->relkind == RELKIND_MATVIEW || + rangeTableEntry->relkind == RELKIND_FOREIGN_TABLE) + { + /* Materialized view or Foreign table as target is not allowed */ + if (IsMergeAllowedOnRelation(parse, rangeTableEntry)) + { + /* Non target relation is ok */ + continue; + } + else + { + ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("MERGE command is not allowed " + "on materialized view"))); + } + } + + if (rangeTableEntry->relkind != RELKIND_RELATION && + rangeTableEntry->relkind != RELKIND_PARTITIONED_TABLE) + { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("Unexpected relation type(relkind:%c) in MERGE command", + rangeTableEntry->relkind))); + } + + Assert(rangeTableEntry->relid != 0); + + /* Distributed tables and Reference tables are not supported yet */ + if (IsCitusTableType(relationId, REFERENCE_TABLE) || + IsCitusTableType(relationId, DISTRIBUTED_TABLE)) + { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("MERGE command is not supported on " + "distributed/reference tables yet"))); + } + + /* Regular Postgres tables and Citus local tables are allowed */ + if (!IsCitusTable(relationId) || + IsCitusTableType(relationId, CITUS_LOCAL_TABLE)) + { + continue; + } + + + /* Any other Citus table type missing ? */ + } + + /* All the tables are local, supported */ +} diff --git a/src/backend/distributed/planner/fast_path_router_planner.c b/src/backend/distributed/planner/fast_path_router_planner.c index 5be585c67..b947c036f 100644 --- a/src/backend/distributed/planner/fast_path_router_planner.c +++ b/src/backend/distributed/planner/fast_path_router_planner.c @@ -162,16 +162,11 @@ FastPathRouterQuery(Query *query, Node **distributionKeyValue) return false; } -#if PG_VERSION_NUM >= PG_VERSION_15 - if (query->commandType == CMD_MERGE) + if (IsMergeQuery(query)) { - /* - * Citus doesn't support MERGE command, lets return - * early and explicitly for fast-path queries. - */ + /* MERGE command is not a fast path query */ return false; } -#endif /* * We want to deal with only very simple queries. Some of the diff --git a/src/backend/distributed/planner/multi_physical_planner.c b/src/backend/distributed/planner/multi_physical_planner.c index 4f8ee6a2c..a2590d48d 100644 --- a/src/backend/distributed/planner/multi_physical_planner.c +++ b/src/backend/distributed/planner/multi_physical_planner.c @@ -2464,7 +2464,7 @@ QueryPushdownTaskCreate(Query *originalQuery, int shardIndex, * If it is a modify query with sub-select, we need to set result relation shard's id * as anchor shard id. */ - if (UpdateOrDeleteQuery(originalQuery)) + if (UpdateOrDeleteOrMergeQuery(originalQuery)) { resultRangeTable = rt_fetch(originalQuery->resultRelation, originalQuery->rtable); resultRelationOid = resultRangeTable->relid; @@ -2493,7 +2493,7 @@ QueryPushdownTaskCreate(Query *originalQuery, int shardIndex, anchorShardId = shardInterval->shardId; } } - else if (UpdateOrDeleteQuery(originalQuery)) + else if (UpdateOrDeleteOrMergeQuery(originalQuery)) { shardInterval = cacheEntry->sortedShardIntervalArray[shardIndex]; if (!modifyWithSubselect || relationId == resultRelationOid) diff --git a/src/backend/distributed/planner/multi_router_planner.c b/src/backend/distributed/planner/multi_router_planner.c index 325c382c7..631322e80 100644 --- a/src/backend/distributed/planner/multi_router_planner.c +++ b/src/backend/distributed/planner/multi_router_planner.c @@ -127,9 +127,10 @@ static DeferredErrorMessage * ModifyPartialQuerySupported(Query *queryTree, bool multiShardQuery, Oid *distributedTableId); static bool NodeIsFieldStore(Node *node); -static DeferredErrorMessage * MultiShardUpdateDeleteSupported(Query *originalQuery, - PlannerRestrictionContext * - plannerRestrictionContext); +static DeferredErrorMessage * MultiShardUpdateDeleteMergeSupported(Query *originalQuery, + PlannerRestrictionContext + * + plannerRestrictionContext); static DeferredErrorMessage * SingleShardUpdateDeleteSupported(Query *originalQuery, PlannerRestrictionContext * plannerRestrictionContext); @@ -233,7 +234,7 @@ CreateModifyPlan(Query *originalQuery, Query *query, return distributedPlan; } - if (UpdateOrDeleteQuery(query)) + if (UpdateOrDeleteOrMergeQuery(query)) { job = RouterJob(originalQuery, plannerRestrictionContext, &distributedPlan->planningError); @@ -539,7 +540,7 @@ ModifyPartialQuerySupported(Query *queryTree, bool multiShardQuery, if (queryTree->hasSubLinks == true) { /* we support subqueries for INSERTs only via INSERT INTO ... SELECT */ - if (!UpdateOrDeleteQuery(queryTree)) + if (!UpdateOrDeleteOrMergeQuery(queryTree)) { Assert(queryTree->commandType == CMD_INSERT); @@ -954,9 +955,17 @@ ModifyQuerySupported(Query *queryTree, Query *originalQuery, bool multiShardQuer } else if (rangeTableEntry->relkind == RELKIND_MATVIEW) { - return DeferredError(ERRCODE_FEATURE_NOT_SUPPORTED, - "materialized views in modify queries are not supported", - NULL, NULL); + if (IsMergeAllowedOnRelation(originalQuery, rangeTableEntry)) + { + continue; + } + else + { + return DeferredError(ERRCODE_FEATURE_NOT_SUPPORTED, + "materialized views in " + "modify queries are not supported", + NULL, NULL); + } } /* for other kinds of relations, check if its distributed */ else @@ -995,10 +1004,10 @@ ModifyQuerySupported(Query *queryTree, Query *originalQuery, bool multiShardQuer char *rangeTableEntryErrorDetail = NULL; /* - * We support UPDATE and DELETE with subqueries and joins unless + * We support UPDATE, DELETE and MERGE with subqueries and joins unless * they are multi shard queries. */ - if (UpdateOrDeleteQuery(queryTree)) + if (UpdateOrDeleteOrMergeQuery(queryTree)) { continue; } @@ -1059,8 +1068,9 @@ ModifyQuerySupported(Query *queryTree, Query *originalQuery, bool multiShardQuer if (multiShardQuery) { - errorMessage = MultiShardUpdateDeleteSupported(originalQuery, - plannerRestrictionContext); + errorMessage = MultiShardUpdateDeleteMergeSupported( + originalQuery, + plannerRestrictionContext); } else { @@ -1239,12 +1249,12 @@ ErrorIfOnConflictNotSupported(Query *queryTree) /* - * MultiShardUpdateDeleteSupported returns the error message if the update/delete is + * MultiShardUpdateDeleteMergeSupported returns the error message if the update/delete is * not pushdownable, otherwise it returns NULL. */ static DeferredErrorMessage * -MultiShardUpdateDeleteSupported(Query *originalQuery, - PlannerRestrictionContext *plannerRestrictionContext) +MultiShardUpdateDeleteMergeSupported(Query *originalQuery, + PlannerRestrictionContext *plannerRestrictionContext) { DeferredErrorMessage *errorMessage = NULL; RangeTblEntry *resultRangeTable = ExtractResultRelationRTE(originalQuery); @@ -1382,14 +1392,25 @@ HasDangerousJoinUsing(List *rtableList, Node *joinTreeNode) /* - * UpdateOrDeleteQuery checks if the given query is an UPDATE or DELETE command. - * If it is, it returns true otherwise it returns false. + * UpdateOrDeleteOrMergeQuery checks if the given query is an UPDATE or DELETE or + * MERGE command. If it is, it returns true otherwise it returns false. */ bool -UpdateOrDeleteQuery(Query *query) +UpdateOrDeleteOrMergeQuery(Query *query) { - return query->commandType == CMD_UPDATE || - query->commandType == CMD_DELETE; + return (query->commandType == CMD_UPDATE || + query->commandType == CMD_DELETE || + query->commandType == CMD_MERGE); +} + + +/* + * IsMergeQuery checks if the given query is a MERGE SQL command. + */ +bool +IsMergeQuery(Query *query) +{ + return (query->commandType == CMD_MERGE); } @@ -1827,7 +1848,19 @@ RouterJob(Query *originalQuery, PlannerRestrictionContext *plannerRestrictionCon if (*planningError) { - return NULL; + /* + * For MERGE, we do _not_ plan anything other than Router job, let's + * not continue further down the lane in distributed planning, simply + * bail out. + */ + if (IsMergeQuery(originalQuery)) + { + RaiseDeferredError(*planningError, ERROR); + } + else + { + return NULL; + } } Job *job = CreateJob(originalQuery); @@ -1835,7 +1868,7 @@ RouterJob(Query *originalQuery, PlannerRestrictionContext *plannerRestrictionCon if (originalQuery->resultRelation > 0) { - RangeTblEntry *updateOrDeleteRTE = ExtractResultRelationRTE(originalQuery); + RangeTblEntry *updateOrDeleteOrMergeRTE = ExtractResultRelationRTE(originalQuery); /* * If all of the shards are pruned, we replace the relation RTE into @@ -1844,7 +1877,7 @@ RouterJob(Query *originalQuery, PlannerRestrictionContext *plannerRestrictionCon * DELETE RTE with subquery type, we just set task list to empty and return * the job. */ - if (updateOrDeleteRTE->rtekind == RTE_SUBQUERY) + if (updateOrDeleteOrMergeRTE->rtekind == RTE_SUBQUERY) { job->taskList = NIL; return job; @@ -2250,7 +2283,7 @@ PlanRouterQuery(Query *originalQuery, * We defer error here, later the planner is forced to use a generic plan * by assigning arbitrarily high cost to the plan. */ - if (UpdateOrDeleteQuery(originalQuery) && isMultiShardQuery) + if (UpdateOrDeleteOrMergeQuery(originalQuery) && isMultiShardQuery) { planningError = DeferredError(ERRCODE_FEATURE_NOT_SUPPORTED, "Router planner cannot handle multi-shard " @@ -2289,7 +2322,7 @@ PlanRouterQuery(Query *originalQuery, NULL, NULL); } - Assert(UpdateOrDeleteQuery(originalQuery)); + Assert(UpdateOrDeleteOrMergeQuery(originalQuery)); planningError = ModifyQuerySupported(originalQuery, originalQuery, isMultiShardQuery, plannerRestrictionContext); @@ -2361,7 +2394,7 @@ PlanRouterQuery(Query *originalQuery, * If this is an UPDATE or DELETE query which requires coordinator evaluation, * don't try update shard names, and postpone that to execution phase. */ - bool isUpdateOrDelete = UpdateOrDeleteQuery(originalQuery); + bool isUpdateOrDelete = UpdateOrDeleteOrMergeQuery(originalQuery); if (!(isUpdateOrDelete && RequiresCoordinatorEvaluation(originalQuery))) { UpdateRelationToShardNames((Node *) originalQuery, *relationShardList); diff --git a/src/include/distributed/distributed_planner.h b/src/include/distributed/distributed_planner.h index f0057064b..31eceea40 100644 --- a/src/include/distributed/distributed_planner.h +++ b/src/include/distributed/distributed_planner.h @@ -29,6 +29,11 @@ #define CURSOR_OPT_FORCE_DISTRIBUTED 0x080000 +/* Hack to compile Citus on pre-MERGE Postgres versions */ +#if PG_VERSION_NUM < PG_VERSION_15 +#define CMD_MERGE CMD_UNKNOWN +#endif + /* level of planner calls */ extern int PlannerLevel; @@ -248,4 +253,6 @@ extern struct DistributedPlan * CreateDistributedPlan(uint64 planId, Query *orig PlannerRestrictionContext * plannerRestrictionContext); +extern bool IsMergeAllowedOnRelation(Query *parse, RangeTblEntry *rte); + #endif /* DISTRIBUTED_PLANNER_H */ diff --git a/src/include/distributed/multi_router_planner.h b/src/include/distributed/multi_router_planner.h index 22c334a13..62d698b51 100644 --- a/src/include/distributed/multi_router_planner.h +++ b/src/include/distributed/multi_router_planner.h @@ -76,7 +76,8 @@ extern RangeTblEntry * ExtractResultRelationRTEOrError(Query *query); extern RangeTblEntry * ExtractDistributedInsertValuesRTE(Query *query); extern bool IsMultiRowInsert(Query *query); extern void AddPartitionKeyNotNullFilterToSelect(Query *subqery); -extern bool UpdateOrDeleteQuery(Query *query); +extern bool UpdateOrDeleteOrMergeQuery(Query *query); +extern bool IsMergeQuery(Query *query); extern uint64 GetAnchorShardId(List *relationShardList); extern List * TargetShardIntervalForFastPathQuery(Query *query, diff --git a/src/test/regress/expected/merge.out b/src/test/regress/expected/merge.out new file mode 100644 index 000000000..6fc472b70 --- /dev/null +++ b/src/test/regress/expected/merge.out @@ -0,0 +1,1585 @@ +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int >= 15 AS server_version_ge_15 +\gset +\if :server_version_ge_15 +\else +\q +\endif +-- MERGE command performs a join from data_source to target_table_name +DROP SCHEMA IF EXISTS merge_schema CASCADE; +NOTICE: schema "merge_schema" does not exist, skipping +--MERGE INTO target +--USING source +--WHEN NOT MATCHED +--WHEN MATCHED AND +--WHEN MATCHED +CREATE SCHEMA merge_schema; +SET search_path TO merge_schema; +SET citus.shard_count TO 4; +SET citus.next_shard_id TO 4000000; +SET citus.explain_all_tasks to true; +SELECT 1 FROM master_add_node('localhost', :master_port, groupid => 0); +NOTICE: localhost:xxxxx is the coordinator and already contains metadata, skipping syncing the metadata + ?column? +--------------------------------------------------------------------- + 1 +(1 row) + +CREATE TABLE source +( + order_id INT, + customer_id INT, + order_center VARCHAR, + order_time timestamp +); +CREATE TABLE target +( + customer_id INT, + last_order_id INT, + order_center VARCHAR, + order_count INT, + last_order timestamp +); +CREATE FUNCTION insert_data() RETURNS VOID AS $$ + +INSERT INTO source (order_id, customer_id, order_center, order_time) + VALUES (101, 30000, 'WX', '2022-01-01 00:00:00'); -- Do not match +INSERT INTO source (order_id, customer_id, order_center, order_time) + VALUES (102, 30001, 'CX', '2022-01-01 00:00:00'); -- Do not match + +INSERT INTO source (order_id, customer_id, order_center, order_time) + VALUES (103, 30002, 'AX', '2022-01-01 00:00:00'); -- Does match +INSERT INTO source (order_id, customer_id, order_center, order_time) + VALUES (104, 30003, 'JX','2022-01-01 00:00:00' ); -- Does match +INSERT INTO source (order_id, customer_id, order_center, order_time) + VALUES (105, 30004, 'JX','2022-01-01 00:00:00' ); -- Does match + +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (40000, 097, 'MK', -1, '2019-09-15 08:13:00'); +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (40001, 098, 'NU', -1, '2020-07-12 01:05:00'); +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (40002, 100, 'DS', -1, '2022-05-21 04:12:00'); +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (30002, 103, 'AX', -1, '2021-01-17 19:53:00'); -- Matches the source +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (30003, 099, 'JX', -1, '2020-09-11 03:23:00'); -- Matches the source +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (30004, 099, 'XX', -1, '2020-09-11 03:23:00'); -- Matches the source id AND the condition. +$$ +LANGUAGE SQL; +SELECT insert_data(); + insert_data +--------------------------------------------------------------------- + +(1 row) + +SELECT 'Testing PG tables'; + ?column? +--------------------------------------------------------------------- + Testing PG tables +(1 row) + +MERGE INTO target t + USING source s + ON (t.customer_id = s.customer_id) + WHEN MATCHED AND t.order_center = 'XX' THEN + DELETE + WHEN MATCHED THEN + UPDATE SET -- Existing customer, update the order count and last_order_id + order_count = t.order_count + 1, + last_order_id = s.order_id + WHEN NOT MATCHED THEN -- New entry, record it. + INSERT (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (customer_id, s.order_id, s.order_center, 123, s.order_time); +-- Our gold result to compare against +SELECT * INTO pg_result FROM target ORDER BY 1 ; +-- Clean the slate +TRUNCATE source; +TRUNCATE target; +SELECT insert_data(); + insert_data +--------------------------------------------------------------------- + +(1 row) + +-- Test with both target and source as Citus local +SELECT 'local - local'; + ?column? +--------------------------------------------------------------------- + local - local +(1 row) + +SELECT citus_add_local_table_to_metadata('target'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('source'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +MERGE INTO target t + USING source s + ON (t.customer_id = s.customer_id) + WHEN MATCHED AND t.order_center = 'XX' THEN + DELETE + WHEN MATCHED THEN + UPDATE SET -- Existing customer, update the order count and last_order_id + order_count = t.order_count + 1, + last_order_id = s.order_id + WHEN NOT MATCHED THEN -- New entry, record it. + INSERT (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (customer_id, s.order_id, s.order_center, 123, s.order_time); +SELECT * INTO local_local FROM target ORDER BY 1 ; +-- Should be equal +SELECT c.*, p.* +FROM local_local c, pg_result p +WHERE c.customer_id = p.customer_id +ORDER BY 1,2; + customer_id | last_order_id | order_center | order_count | last_order | customer_id | last_order_id | order_center | order_count | last_order +--------------------------------------------------------------------- + 30000 | 101 | WX | 123 | Sat Jan 01 00:00:00 2022 | 30000 | 101 | WX | 123 | Sat Jan 01 00:00:00 2022 + 30001 | 102 | CX | 123 | Sat Jan 01 00:00:00 2022 | 30001 | 102 | CX | 123 | Sat Jan 01 00:00:00 2022 + 30002 | 103 | AX | 0 | Sun Jan 17 19:53:00 2021 | 30002 | 103 | AX | 0 | Sun Jan 17 19:53:00 2021 + 30003 | 104 | JX | 0 | Fri Sep 11 03:23:00 2020 | 30003 | 104 | JX | 0 | Fri Sep 11 03:23:00 2020 + 40000 | 97 | MK | -1 | Sun Sep 15 08:13:00 2019 | 40000 | 97 | MK | -1 | Sun Sep 15 08:13:00 2019 + 40001 | 98 | NU | -1 | Sun Jul 12 01:05:00 2020 | 40001 | 98 | NU | -1 | Sun Jul 12 01:05:00 2020 + 40002 | 100 | DS | -1 | Sat May 21 04:12:00 2022 | 40002 | 100 | DS | -1 | Sat May 21 04:12:00 2022 +(7 rows) + +-- Must return zero rows +SELECT * +FROM pg_result p +WHERE NOT EXISTS (SELECT FROM local_local c WHERE c.customer_id = p.customer_id); + customer_id | last_order_id | order_center | order_count | last_order +--------------------------------------------------------------------- +(0 rows) + +SELECT 'Testing Dist - Dist'; + ?column? +--------------------------------------------------------------------- + Testing Dist - Dist +(1 row) + +-- Clean the slate +TRUNCATE source; +TRUNCATE target; +SELECT insert_data(); + insert_data +--------------------------------------------------------------------- + +(1 row) + +SELECT undistribute_table('target'); +NOTICE: creating a new table for merge_schema.target +NOTICE: moving the data of merge_schema.target +NOTICE: dropping the old merge_schema.target +NOTICE: renaming the new table to merge_schema.target + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT undistribute_table('source'); +NOTICE: creating a new table for merge_schema.source +NOTICE: moving the data of merge_schema.source +NOTICE: dropping the old merge_schema.source +NOTICE: renaming the new table to merge_schema.source + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('target', 'customer_id'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.target$$) + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('source', 'customer_id'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.source$$) + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +MERGE INTO target t + USING source s + ON (t.customer_id = s.customer_id) + WHEN MATCHED AND t.order_center = 'XX' THEN + DELETE + WHEN MATCHED THEN + UPDATE SET -- Existing customer, update the order count and last_order_id + order_count = t.order_count + 1, + last_order_id = s.order_id + WHEN NOT MATCHED THEN -- New entry, record it. + INSERT (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (customer_id, s.order_id, s.order_center, 123, s.order_time); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- +-- Test MERGE with CTE as source +-- +CREATE TABLE t1(id int, val int); +CREATE TABLE s1(id int, val int); +CREATE FUNCTION load() RETURNS VOID AS $$ + +INSERT INTO s1 VALUES(1, 0); -- Matches DELETE clause +INSERT INTO s1 VALUES(2, 1); -- Matches UPDATE clause +INSERT INTO s1 VALUES(3, 1); -- No Match INSERT clause +INSERT INTO s1 VALUES(4, 1); -- No Match INSERT clause +INSERT INTO s1 VALUES(6, 1); -- No Match INSERT clause + +INSERT INTO t1 VALUES(1, 0); -- Will be deleted +INSERT INTO t1 VALUES(2, 0); -- Will be updated +INSERT INTO t1 VALUES(5, 0); -- Will be intact + +$$ +LANGUAGE SQL; +SELECT 'Testing PG tables'; + ?column? +--------------------------------------------------------------------- + Testing PG tables +(1 row) + +SELECT load(); + load +--------------------------------------------------------------------- + +(1 row) + +WITH pg_res AS ( + SELECT * FROM s1 +) +MERGE INTO t1 + USING pg_res ON (pg_res.id = t1.id) + WHEN MATCHED AND pg_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (pg_res.id, pg_res.val); +-- Two rows with id 2 and val incremented, id 3, and id 1 is deleted +SELECT * FROM t1 order by id; + id | val +--------------------------------------------------------------------- + 2 | 1 + 3 | 1 + 4 | 1 + 5 | 0 + 6 | 1 +(5 rows) + +SELECT * INTO merge_result FROM t1 order by id; +-- Test Citus local tables +TRUNCATE t1; +TRUNCATE s1; +SELECT load(); + load +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('t1'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('s1'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +WITH s1_res AS ( + SELECT * FROM s1 +) +MERGE INTO t1 + USING s1_res ON (s1_res.id = t1.id) + WHEN MATCHED AND s1_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1_res.id, s1_res.val); +-- Two rows with id 2 and val incremented, id 3, and id 1 is deleted +SELECT * FROM t1 order by id; + id | val +--------------------------------------------------------------------- + 2 | 1 + 3 | 1 + 4 | 1 + 5 | 0 + 6 | 1 +(5 rows) + +-- Should be empty +SELECT * +FROM merge_result p +WHERE NOT EXISTS (SELECT 1 FROM t1 c WHERE c.id = p.id AND c.val = p.val); + id | val +--------------------------------------------------------------------- +(0 rows) + +SELECT 'Testing dist - dist'; + ?column? +--------------------------------------------------------------------- + Testing dist - dist +(1 row) + +SELECT undistribute_table('t1'); +NOTICE: creating a new table for merge_schema.t1 +NOTICE: moving the data of merge_schema.t1 +NOTICE: dropping the old merge_schema.t1 +NOTICE: renaming the new table to merge_schema.t1 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT undistribute_table('s1'); +NOTICE: creating a new table for merge_schema.s1 +NOTICE: moving the data of merge_schema.s1 +NOTICE: dropping the old merge_schema.s1 +NOTICE: renaming the new table to merge_schema.s1 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +TRUNCATE t1; +TRUNCATE s1; +SELECT load(); + load +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('t1', 'id'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.t1$$) + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('s1', 'id'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.s1$$) + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +WITH s1_res AS ( + SELECT * FROM s1 +) +MERGE INTO t1 + USING s1_res ON (s1_res.id = t1.id) + WHEN MATCHED AND s1_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1_res.id, s1_res.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- +-- Test with multiple join conditions +-- +CREATE TABLE t2(id int, val int, src text); +CREATE TABLE s2(id int, val int, src text); +CREATE OR REPLACE FUNCTION insert_data() RETURNS VOID AS $$ +INSERT INTO t2 VALUES(1, 0, 'target'); +INSERT INTO t2 VALUES(2, 0, 'target'); +INSERT INTO t2 VALUES(3, 1, 'match'); +INSERT INTO t2 VALUES(4, 0, 'match'); + +INSERT INTO s2 VALUES(2, 0, 'source'); -- No match insert +INSERT INTO s2 VALUES(4, 0, 'match'); -- Match delete +INSERT INTO s2 VALUES(3, 10, 'match'); -- Match update + +$$ +LANGUAGE SQL; +SELECT 'Testing PG tables'; + ?column? +--------------------------------------------------------------------- + Testing PG tables +(1 row) + +SELECT insert_data(); + insert_data +--------------------------------------------------------------------- + +(1 row) + +MERGE INTO t2 +USING s2 +ON t2.id = s2.id AND t2.src = s2.src + WHEN MATCHED AND t2.val = 1 THEN + UPDATE SET val = s2.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s2.id, s2.val, s2.src); +SELECT * FROM t2 ORDER BY 1; + id | val | src +--------------------------------------------------------------------- + 1 | 0 | target + 2 | 0 | target + 2 | 0 | source + 3 | 20 | match +(4 rows) + +SELECT * INTO pg_t2 FROM t2; +SELECT 'Testing Citus local tables'; + ?column? +--------------------------------------------------------------------- + Testing Citus local tables +(1 row) + +TRUNCATE t2; +TRUNCATE s2; +SELECT insert_data(); + insert_data +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('t2'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('s2'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +MERGE INTO t2 +USING s2 +ON t2.id = s2.id AND t2.src = s2.src + WHEN MATCHED AND t2.val = 1 THEN + UPDATE SET val = s2.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s2.id, s2.val, s2.src); +SELECT * FROM t2 ORDER BY 1; + id | val | src +--------------------------------------------------------------------- + 1 | 0 | target + 2 | 0 | target + 2 | 0 | source + 3 | 20 | match +(4 rows) + +-- Should be empty +SELECT * +FROM pg_t2 p +WHERE NOT EXISTS (SELECT 1 FROM t2 c WHERE c.id = p.id AND c.val = p.val AND c.src = p.src); + id | val | src +--------------------------------------------------------------------- +(0 rows) + +SELECT 'Testing Dist - Dist'; + ?column? +--------------------------------------------------------------------- + Testing Dist - Dist +(1 row) + +-- Clean the slate +TRUNCATE t2; +TRUNCATE s2; +SELECT insert_data(); + insert_data +--------------------------------------------------------------------- + +(1 row) + +SELECT undistribute_table('t2'); +NOTICE: creating a new table for merge_schema.t2 +NOTICE: moving the data of merge_schema.t2 +NOTICE: dropping the old merge_schema.t2 +NOTICE: renaming the new table to merge_schema.t2 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT undistribute_table('s2'); +NOTICE: creating a new table for merge_schema.s2 +NOTICE: moving the data of merge_schema.s2 +NOTICE: dropping the old merge_schema.s2 +NOTICE: renaming the new table to merge_schema.s2 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('t2', 'id'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.t2$$) + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('s2', 'id'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.s2$$) + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +MERGE INTO t2 +USING s2 +ON t2.id = s2.id AND t2.src = s2.src + WHEN MATCHED AND t2.val = 1 THEN + UPDATE SET val = s2.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s2.id, s2.val, s2.src); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- +-- With sub-query as the MERGE source +-- +TRUNCATE t2; +TRUNCATE s2; +SELECT undistribute_table('t2'); +NOTICE: creating a new table for merge_schema.t2 +NOTICE: moving the data of merge_schema.t2 +NOTICE: dropping the old merge_schema.t2 +NOTICE: renaming the new table to merge_schema.t2 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT undistribute_table('s2'); +NOTICE: creating a new table for merge_schema.s2 +NOTICE: moving the data of merge_schema.s2 +NOTICE: dropping the old merge_schema.s2 +NOTICE: renaming the new table to merge_schema.s2 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('t2'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('s2'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT insert_data(); + insert_data +--------------------------------------------------------------------- + +(1 row) + +MERGE INTO t2 t +USING (SELECT * FROM s2) s +ON t.id = s.id AND t.src = s.src + WHEN MATCHED AND t.val = 1 THEN + UPDATE SET val = s.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s.id, s.val, s.src); +SELECT * FROM t2 ORDER BY 1; + id | val | src +--------------------------------------------------------------------- + 1 | 0 | target + 2 | 0 | target + 2 | 0 | source + 3 | 20 | match +(4 rows) + +SELECT * INTO dist_res FROM t2 ORDER BY 1; +-- Should be equal +SELECT c.*, p.* +FROM t2 c, pg_t2 p +WHERE c.id = p.id AND c.src = p.src +ORDER BY 1,2; + id | val | src | id | val | src +--------------------------------------------------------------------- + 1 | 0 | target | 1 | 0 | target + 2 | 0 | source | 2 | 0 | source + 2 | 0 | target | 2 | 0 | target + 3 | 20 | match | 3 | 20 | match +(4 rows) + +-- Should be empty +SELECT * +FROM pg_t2 p +WHERE NOT EXISTS (SELECT 1 FROM t2 c WHERE c.id = p.id AND c.val = p.val AND c.src = p.src); + id | val | src +--------------------------------------------------------------------- +(0 rows) + +-- +-- Using two source tables +-- +CREATE TABLE t3(id int, val int, src text); +CREATE TABLE s3_1(id int, val int, src text); +CREATE TABLE s3_2(id int, val int, src text); +CREATE OR REPLACE FUNCTION insert_data() RETURNS VOID AS $$ +INSERT INTO t3 VALUES(1, 0, 'target'); -- Intact +INSERT INTO t3 VALUES(2, 0, 'target'); +INSERT INTO t3 VALUES(3, 0, 'target'); +INSERT INTO t3 VALUES(5, 0, 'target'); -- Intact + +INSERT INTO s3_1 VALUES(2, 0, 'source1'); +INSERT INTO s3_1 VALUES(3, 0, 'source1'); +INSERT INTO s3_1 VALUES(4, 0, 'source1'); + +INSERT INTO s3_2 VALUES(2, 1, 'source2'); -- Match update +INSERT INTO s3_2 VALUES(3, 0, 'source2'); -- Match delete +INSERT INTO s3_2 VALUES(4, 0, 'source2'); -- No match insert +INSERT INTO s3_2 VALUES(6, 0, 'source2'); -- Will miss the source-subquery-join +$$ +LANGUAGE SQL; +SELECT insert_data(); + insert_data +--------------------------------------------------------------------- + +(1 row) + +MERGE INTO t3 + USING (SELECT s3_1.id, s3_2.val, s3_2.src FROM s3_1, s3_2 WHERE s3_1.id = s3_2.id) sub + ON (t3.id = sub.id) + WHEN MATCHED AND sub.val = 1 THEN + UPDATE SET val = t3.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (sub.id, sub.val, sub.src); +-- Joining on columns inside the sub-query +MERGE INTO t3 + USING (SELECT s3_1.id, s3_2.val, s3_2.src FROM s3_1, s3_2 WHERE s3_1.id = s3_2.id) sub + ON (t3.id = sub.id) + WHEN MATCHED AND sub.val = 1 THEN + UPDATE SET val = t3.val + 1 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (sub.id, sub.val, sub.src); +-- Constant Join condition +WITH s3_res AS ( + SELECT * FROM s3_1 +) +MERGE INTO t3 + USING s3_res ON (FALSE) + WHEN MATCHED AND s3_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t3.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s3_res.id, s3_res.val, s3_res.src); +SELECT * FROM t3 ORDER BY 1,3; + id | val | src +--------------------------------------------------------------------- + 1 | 0 | target + 2 | 0 | source1 + 2 | 11 | target + 3 | 0 | source1 + 3 | 0 | source2 + 4 | 0 | source1 + 5 | 0 | target +(7 rows) + +SELECT * INTO pg_t3 FROM t3 ORDER BY 1; +SELECT 'Testing Local - Local'; + ?column? +--------------------------------------------------------------------- + Testing Local - Local +(1 row) + +TRUNCATE t3; +TRUNCATE s3_1; +TRUNCATE s3_2; +SELECT citus_add_local_table_to_metadata('t3'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('s3_1'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('s3_2'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT insert_data(); + insert_data +--------------------------------------------------------------------- + +(1 row) + +MERGE INTO t3 + USING (SELECT s3_1.id, s3_2.val, s3_2.src FROM s3_1, s3_2 WHERE s3_1.id = s3_2.id) sub + ON (t3.id = sub.id) + WHEN MATCHED AND sub.val = 1 THEN + UPDATE SET val = t3.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (sub.id, sub.val, sub.src); +-- Joining on columns inside the sub-query +MERGE INTO t3 + USING (SELECT s3_1.id, s3_2.val, s3_2.src FROM s3_1, s3_2 WHERE s3_1.id = s3_2.id) sub + ON (t3.id = sub.id) + WHEN MATCHED AND sub.val = 1 THEN + UPDATE SET val = t3.val + 1 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (sub.id, sub.val, sub.src); +-- Constant Join condition +WITH s3_res AS ( + SELECT * FROM s3_1 +) +MERGE INTO t3 + USING s3_res ON (FALSE) + WHEN MATCHED AND s3_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t3.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s3_res.id, s3_res.val, s3_res.src); +SELECT * FROM t3 ORDER BY 1,3; + id | val | src +--------------------------------------------------------------------- + 1 | 0 | target + 2 | 0 | source1 + 2 | 11 | target + 3 | 0 | source1 + 3 | 0 | source2 + 4 | 0 | source1 + 5 | 0 | target +(7 rows) + +SELECT * INTO local_t3 FROM t3 ORDER BY 1; +-- Should be equal +SELECT c.*, p.* +FROM t3 c, pg_t3 p +WHERE c.id = p.id +ORDER BY 1,2; + id | val | src | id | val | src +--------------------------------------------------------------------- + 1 | 0 | target | 1 | 0 | target + 2 | 0 | source1 | 2 | 0 | source1 + 2 | 0 | source1 | 2 | 11 | target + 2 | 11 | target | 2 | 0 | source1 + 2 | 11 | target | 2 | 11 | target + 3 | 0 | source2 | 3 | 0 | source2 + 3 | 0 | source2 | 3 | 0 | source1 + 3 | 0 | source1 | 3 | 0 | source2 + 3 | 0 | source1 | 3 | 0 | source1 + 4 | 0 | source1 | 4 | 0 | source1 + 5 | 0 | target | 5 | 0 | target +(11 rows) + +-- Should be empty +SELECT * +FROM pg_t3 p +WHERE NOT EXISTS (SELECT 1 FROM local_t3 c WHERE c.id = p.id AND c.val = p.val AND c.src = p.src); + id | val | src +--------------------------------------------------------------------- +(0 rows) + +-- +-- Test table functions +-- +CREATE TABLE tf_target(first_name varchar, last_name varchar, eid text); +WITH doc as ( +SELECT ' + + foo + bar + 100 + + + moo + bar + 200 + +'::xml as source_xml +) +MERGE INTO tf_target +USING ( +SELECT decoded.* +FROM doc, xmltable( + '//people/person' + passing source_xml + columns + first_name text, + last_name text, + eid text) as decoded) as tf_source +ON tf_source.first_name = tf_target.first_name +WHEN NOT MATCHED THEN +INSERT VALUES (tf_source.first_name, tf_source.last_name, tf_source.eid); +-- Our gold result to compare against +SELECT * INTO tf_result FROM tf_target ORDER BY 1 ; +TRUNCATE tf_target; +SELECT citus_add_local_table_to_metadata('tf_target'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +WITH doc as ( +SELECT ' + + foo + bar + 100 + + + moo + bar + 200 + +'::xml as source_xml +) +MERGE INTO tf_target +USING ( +SELECT decoded.* +FROM doc, xmltable( + '//people/person' + passing source_xml + columns + first_name text, + last_name text, + eid text) as decoded) as tf_source +ON tf_source.first_name = tf_target.first_name +WHEN NOT MATCHED THEN +INSERT VALUES (tf_source.first_name, tf_source.last_name, tf_source.eid); +SELECT * INTO tf_local FROM tf_target ORDER BY 1 ; +-- Should be equal +SELECT c.*, p.* +FROM tf_local c, tf_result p +WHERE c.eid = p.eid +ORDER BY 1,2; + first_name | last_name | eid | first_name | last_name | eid +--------------------------------------------------------------------- + foo | bar | 100 | foo | bar | 100 + moo | bar | 200 | moo | bar | 200 +(2 rows) + +-- Must return zero rows +SELECT * +FROM tf_result p +WHERE NOT EXISTS (SELECT FROM tf_local c WHERE c.eid = p.eid); + first_name | last_name | eid +--------------------------------------------------------------------- +(0 rows) + +-- +-- Test VALUES RTE type +-- +CREATE TABLE vl_target(id int, value varchar); +INSERT INTO vl_target VALUES(100, 'target'); +MERGE INTO vl_target +USING (SELECT * + FROM (VALUES(100, 'source1'), (200, 'source2')) AS vl (ID, value)) as vl_source +ON vl_source.ID = vl_target.ID +WHEN MATCHED THEN +UPDATE SET value = vl_source.value, id = vl_target.id + 1 +WHEN NOT MATCHED THEN +INSERT VALUES(vl_source.ID, vl_source.value); +-- Our gold result to compare against +SELECT * INTO vl_result FROM vl_target ORDER BY 1 ; +-- Clean the slate +TRUNCATE vl_target; +INSERT INTO vl_target VALUES(100, 'target'); +SELECT citus_add_local_table_to_metadata('vl_target'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SET client_min_messages TO DEBUG1; +MERGE INTO vl_target +USING (SELECT * + FROM (VALUES(100, 'source1'), (200, 'source2')) AS vl (ID, value)) as vl_source +ON vl_source.ID = vl_target.ID +WHEN MATCHED THEN +UPDATE SET value = vl_source.value, id = vl_target.id + 1 +WHEN NOT MATCHED THEN +INSERT VALUES(vl_source.ID, vl_source.value); +DEBUG: +RESET client_min_messages; +SELECT * INTO vl_local FROM vl_target ORDER BY 1 ; +-- Should be equal +SELECT c.*, p.* +FROM vl_local c, vl_result p +WHERE c.id = p.id +ORDER BY 1,2; + id | value | id | value +--------------------------------------------------------------------- + 101 | source1 | 101 | source1 + 200 | source2 | 200 | source2 +(2 rows) + +-- Must return zero rows +SELECT * +FROM vl_result p +WHERE NOT EXISTS (SELECT FROM vl_local c WHERE c.id = p.id); + id | value +--------------------------------------------------------------------- +(0 rows) + +-- +-- Test function scan +-- +CREATE FUNCTION f_immutable(i integer) RETURNS INTEGER AS +$$ BEGIN RETURN i; END; $$ LANGUAGE PLPGSQL IMMUTABLE; +CREATE TABLE rs_target(id int); +MERGE INTO rs_target +USING (SELECT * FROM f_immutable(99) id WHERE id in (SELECT 99)) AS rs_source +ON rs_source.id = rs_target.id +WHEN MATCHED THEN +DO NOTHING +WHEN NOT MATCHED THEN +INSERT VALUES(rs_source.id); +-- Our gold result to compare against +SELECT * INTO rs_result FROM rs_target ORDER BY 1 ; +-- Clean the slate +TRUNCATE rs_target; +SELECT citus_add_local_table_to_metadata('rs_target'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SET client_min_messages TO DEBUG1; +MERGE INTO rs_target +USING (SELECT * FROM f_immutable(99) id WHERE id in (SELECT 99)) AS rs_source +ON rs_source.id = rs_target.id +WHEN MATCHED THEN +DO NOTHING +WHEN NOT MATCHED THEN +INSERT VALUES(rs_source.id); +DEBUG: +RESET client_min_messages; +SELECT * INTO rs_local FROM rs_target ORDER BY 1 ; +-- Should be equal +SELECT c.*, p.* +FROM rs_local c, rs_result p +WHERE c.id = p.id +ORDER BY 1,2; + id | id +--------------------------------------------------------------------- + 99 | 99 +(1 row) + +-- Must return zero rows +SELECT * +FROM rs_result p +WHERE NOT EXISTS (SELECT FROM rs_local c WHERE c.id = p.id); + id +--------------------------------------------------------------------- +(0 rows) + +-- +-- Test Materialized view +-- +CREATE TABLE mv_target(id int, val varchar); +CREATE TABLE mv_source_table(id int, val varchar); +INSERT INTO mv_source_table VALUES(1, 'src1'); +INSERT INTO mv_source_table VALUES(2, 'src2'); +CREATE MATERIALIZED VIEW mv_source AS +SELECT * FROM mv_source_table; +MERGE INTO mv_target +USING mv_source +ON mv_source.id = mv_target.id +WHEN MATCHED THEN + DO NOTHING +WHEN NOT MATCHED THEN + INSERT VALUES(mv_source.id, mv_source.val); +-- Our gold result to compare against +SELECT * INTO mv_result FROM mv_target ORDER BY 1 ; +-- Clean the slate +TRUNCATE mv_target; +SELECT citus_add_local_table_to_metadata('mv_target'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('mv_source_table'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +DROP MATERIALIZED VIEW mv_source; +CREATE MATERIALIZED VIEW mv_source AS +SELECT * FROM mv_source_table; +MERGE INTO mv_target +USING mv_source +ON mv_source.id = mv_target.id +WHEN MATCHED THEN + DO NOTHING +WHEN NOT MATCHED THEN + INSERT VALUES(mv_source.id, mv_source.val); +SELECT * INTO mv_local FROM mv_target ORDER BY 1 ; +-- Should be equal +SELECT c.*, p.* +FROM mv_local c, mv_result p +WHERE c.id = p.id +ORDER BY 1,2; + id | val | id | val +--------------------------------------------------------------------- + 1 | src1 | 1 | src1 + 2 | src2 | 2 | src2 +(2 rows) + +-- Must return zero rows +SELECT * +FROM mv_result p +WHERE NOT EXISTS (SELECT FROM mv_local c WHERE c.id = p.id); + id | val +--------------------------------------------------------------------- +(0 rows) + +-- +-- Distributed table as source (indirect) +-- +CREATE TABLE dist_table(id int, source varchar); +INSERT INTO dist_table VALUES(2, 'dist_table'); +INSERT INTO dist_table VALUES(3, 'dist_table'); +INSERT INTO dist_table VALUES(100, 'dist_table'); +CREATE FUNCTION f_dist() returns SETOF RECORD AS +$$ +BEGIN +RETURN QUERY SELECT id, source FROM dist_table; +END; +$$ language plpgsql volatile; +CREATE TABLE fn_target(id int, data varchar); +MERGE INTO fn_target +USING (SELECT * FROM f_dist() f(id integer, source varchar)) as fn_source +ON fn_source.id = fn_target.id +WHEN MATCHED THEN +DO NOTHING +WHEN NOT MATCHED THEN +INSERT VALUES(fn_source.id, fn_source.source); +-- Our gold result to compare against +SELECT * INTO fn_result FROM fn_target ORDER BY 1 ; +-- Clean the slate +TRUNCATE TABLE fn_target; +SELECT citus_add_local_table_to_metadata('fn_target'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('dist_table', 'id'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.dist_table$$) + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +SET client_min_messages TO DEBUG1; +MERGE INTO fn_target +USING (SELECT * FROM f_dist() f(id integer, source varchar)) as fn_source +ON fn_source.id = fn_target.id +WHEN MATCHED THEN +DO NOTHING +WHEN NOT MATCHED THEN +INSERT VALUES(fn_source.id, fn_source.source); +DEBUG: function does not have co-located tables +DEBUG: generating subplan XXX_1 for subquery SELECT id, source FROM merge_schema.f_dist() f(id integer, source character varying) +DEBUG: +DEBUG: Plan XXX query after replacing subqueries and CTEs: MERGE INTO merge_schema.fn_target USING (SELECT intermediate_result.id, intermediate_result.source FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(id integer, source character varying)) fn_source ON (fn_source.id OPERATOR(pg_catalog.=) fn_target.id) WHEN MATCHED THEN DO NOTHING WHEN NOT MATCHED THEN INSERT (id, data) VALUES (fn_source.id, fn_source.source) +DEBUG: +RESET client_min_messages; +SELECT * INTO fn_local FROM fn_target ORDER BY 1 ; +-- Should be equal +SELECT c.*, p.* +FROM fn_local c, fn_result p +WHERE c.id = p.id +ORDER BY 1,2; + id | data | id | data +--------------------------------------------------------------------- + 2 | dist_table | 2 | dist_table + 3 | dist_table | 3 | dist_table + 100 | dist_table | 100 | dist_table +(3 rows) + +-- Must return zero rows +SELECT * +FROM fn_result p +WHERE NOT EXISTS (SELECT FROM fn_local c WHERE c.id = p.id); + id | data +--------------------------------------------------------------------- +(0 rows) + +-- +-- Foreign tables +-- +CREATE TABLE ft_target (id integer NOT NULL, user_val varchar); +CREATE TABLE ft_source (id integer NOT NULL, user_val varchar); +SELECT citus_add_local_table_to_metadata('ft_source'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO ft_target VALUES (1, 'target'); +INSERT INTO ft_target VALUES (2, 'target'); +INSERT INTO ft_source VALUES (2, 'source'); +INSERT INTO ft_source VALUES (3, 'source'); +SELECT * FROM ft_target; + id | user_val +--------------------------------------------------------------------- + 1 | target + 2 | target +(2 rows) + +CREATE EXTENSION postgres_fdw; +CREATE SERVER foreign_server + FOREIGN DATA WRAPPER postgres_fdw + OPTIONS (host 'localhost', port :'master_port', dbname 'regression'); +CREATE USER MAPPING FOR CURRENT_USER + SERVER foreign_server + OPTIONS (user 'postgres'); +CREATE FOREIGN TABLE foreign_table ( + id integer NOT NULL, + user_val text +) + SERVER foreign_server + OPTIONS (schema_name 'merge_schema', table_name 'ft_source'); +SELECT citus_add_local_table_to_metadata('foreign_table'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +-- Foreign table as source +SET client_min_messages TO DEBUG1; +MERGE INTO ft_target + USING foreign_table ON (foreign_table.id = ft_target.id) + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, user_val) VALUES (foreign_table.id, foreign_table.user_val); +DEBUG: +RESET client_min_messages; +SELECT * FROM ft_target; + id | user_val +--------------------------------------------------------------------- + 1 | target + 3 | source +(2 rows) + +-- +-- Error and Unsupported scenarios +-- +-- Foreign table as target +MERGE INTO foreign_table + USING ft_target ON (foreign_table.id = ft_target.id) + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, user_val) VALUES (ft_target.id, ft_target.user_val); +ERROR: cannot execute MERGE on relation "foreign_table" +DETAIL: This operation is not supported for foreign tables. +TRUNCATE t1; +TRUNCATE s1; +SELECT undistribute_table('t1'); +NOTICE: creating a new table for merge_schema.t1 +NOTICE: moving the data of merge_schema.t1 +NOTICE: dropping the old merge_schema.t1 +NOTICE: renaming the new table to merge_schema.t1 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT undistribute_table('s1'); +NOTICE: creating a new table for merge_schema.s1 +NOTICE: moving the data of merge_schema.s1 +NOTICE: dropping the old merge_schema.s1 +NOTICE: renaming the new table to merge_schema.s1 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('t1'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('s1', 'id'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +SELECT load(); + load +--------------------------------------------------------------------- + +(1 row) + +-- Combination of Citus local table and distributed table +MERGE INTO t1 + USING s1 ON (s1.id = t1.val) -- val is not a distribution column + WHEN MATCHED AND s1.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1.id, s1.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- Joining on partition columns with sub-query +MERGE INTO t1 + USING (SELECT * FROM s1) sub ON (sub.val = t1.id) -- sub.val is not a distribution column + WHEN MATCHED AND sub.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (sub.id, sub.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- Joining on partition columns with CTE +WITH s1_res AS ( + SELECT * FROM s1 +) +MERGE INTO t1 + USING s1_res ON (s1_res.val = t1.id) + WHEN MATCHED AND s1_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1_res.id, s1_res.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- Constant Join condition +WITH s1_res AS ( + SELECT * FROM s1 +) +MERGE INTO t1 + USING s1_res ON (TRUE) + WHEN MATCHED AND s1_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1_res.id, s1_res.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- With a single WHEN clause, which causes a non-left join +WITH s1_res AS ( + SELECT * FROM s1 + ) + MERGE INTO t1 USING s1_res ON (s1_res.id = t1.val) + WHEN MATCHED THEN DELETE + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1_res.id, s1_res.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- +-- Reference tables +-- +SELECT undistribute_table('t1'); +NOTICE: creating a new table for merge_schema.t1 +NOTICE: moving the data of merge_schema.t1 +NOTICE: dropping the old merge_schema.t1 +NOTICE: renaming the new table to merge_schema.t1 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT undistribute_table('s1'); +NOTICE: creating a new table for merge_schema.s1 +NOTICE: moving the data of merge_schema.s1 +NOTICE: dropping the old merge_schema.s1 +NOTICE: renaming the new table to merge_schema.s1 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_reference_table('t1'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.t1$$) + create_reference_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_reference_table('s1'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.s1$$) + create_reference_table +--------------------------------------------------------------------- + +(1 row) + +MERGE INTO t1 + USING s1 ON (s1.id = t1.id) + WHEN MATCHED AND s1.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1.id, s1.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- +-- Postgres + Citus-Distributed table +-- +SELECT undistribute_table('t1'); +NOTICE: creating a new table for merge_schema.t1 +NOTICE: moving the data of merge_schema.t1 +NOTICE: dropping the old merge_schema.t1 +NOTICE: renaming the new table to merge_schema.t1 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT undistribute_table('s1'); +NOTICE: creating a new table for merge_schema.s1 +NOTICE: moving the data of merge_schema.s1 +NOTICE: dropping the old merge_schema.s1 +NOTICE: renaming the new table to merge_schema.s1 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('t1', 'id'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.t1$$) + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +MERGE INTO t1 + USING s1 ON (s1.id = t1.id) + WHEN MATCHED AND s1.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1.id, s1.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +MERGE INTO t1 + USING (SELECT * FROM s1) sub ON (sub.id = t1.id) + WHEN MATCHED AND sub.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (sub.id, sub.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +CREATE TABLE pg(val int); +SELECT create_distributed_table('s1', 'id'); +NOTICE: Copying data from local table... +NOTICE: copying the data has completed +DETAIL: The local data in the table is no longer visible, but is still on disk. +HINT: To remove the local data, run: SELECT truncate_local_data_after_distributing_table($$merge_schema.s1$$) + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +-- Both t1 and s1 are citus distributed tables now, mix Postgres table in sub-query +MERGE INTO t1 + USING (SELECT s1.id, pg.val FROM s1, pg) sub ON (sub.id = t1.id) + WHEN MATCHED AND sub.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (sub.id, sub.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- Mix Postgres table in CTE +WITH pg_res AS ( + SELECT * FROM pg +) +MERGE INTO t1 + USING (SELECT s1.id, pg_res.val FROM s1, pg_res) sub ON (sub.id = t1.id) + WHEN MATCHED AND sub.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (sub.id, sub.val); +ERROR: MERGE command is not supported on distributed/reference tables yet +-- Match more than one source row should fail same as Postgres behavior +SELECT undistribute_table('t1'); +NOTICE: creating a new table for merge_schema.t1 +NOTICE: moving the data of merge_schema.t1 +NOTICE: dropping the old merge_schema.t1 +NOTICE: renaming the new table to merge_schema.t1 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT undistribute_table('s1'); +NOTICE: creating a new table for merge_schema.s1 +NOTICE: moving the data of merge_schema.s1 +NOTICE: dropping the old merge_schema.s1 +NOTICE: renaming the new table to merge_schema.s1 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('t1'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('s1'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO s1 VALUES(1, 1); -- From load(), we already have row with id = 1 +MERGE INTO t1 + USING s1 ON (s1.id = t1.id) + WHEN MATCHED AND s1.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1.id, s1.val); +ERROR: MERGE command cannot affect row a second time +HINT: Ensure that not more than one source row matches any one target row. +-- Materialized view as target is not allowed +MERGE INTO mv_source +USING mv_target +ON mv_source.id = mv_target.id +WHEN MATCHED THEN + DO NOTHING +WHEN NOT MATCHED THEN + INSERT VALUES(mv_source.id, mv_source.val); +ERROR: cannot execute MERGE on relation "mv_source" +DETAIL: This operation is not supported for materialized views. +DROP SERVER foreign_server CASCADE; +NOTICE: drop cascades to 3 other objects +DETAIL: drop cascades to user mapping for postgres on server foreign_server +drop cascades to foreign table foreign_table_4000046 +drop cascades to foreign table foreign_table +NOTICE: foreign table "foreign_table_4000046" does not exist, skipping +CONTEXT: SQL statement "SELECT citus_drop_all_shards(v_obj.objid, v_obj.schema_name, v_obj.object_name, drop_shards_metadata_only := false)" +PL/pgSQL function citus_drop_trigger() line XX at PERFORM +DROP SCHEMA merge_schema CASCADE; +NOTICE: drop cascades to 56 other objects +DETAIL: drop cascades to function insert_data() +drop cascades to table pg_result +drop cascades to table local_local +drop cascades to table target +drop cascades to table source +drop cascades to function load() +drop cascades to table merge_result +drop cascades to table pg_t2 +drop cascades to table t2_4000030 +drop cascades to table s2_4000031 +drop cascades to table t2 +drop cascades to table s2 +drop cascades to table dist_res +drop cascades to table t3_4000032 +drop cascades to table s3_1_4000033 +drop cascades to table s3_2_4000034 +drop cascades to table pg_t3 +drop cascades to table t3 +drop cascades to table s3_1 +drop cascades to table s3_2 +drop cascades to table local_t3 +drop cascades to table tf_target_4000035 +drop cascades to table tf_result +drop cascades to table tf_target +drop cascades to table tf_local +drop cascades to table vl_target_4000036 +drop cascades to table vl_result +drop cascades to table vl_target +drop cascades to table vl_local +drop cascades to function f_immutable(integer) +drop cascades to table rs_target_4000037 +drop cascades to table rs_result +drop cascades to table rs_target +drop cascades to table rs_local +drop cascades to table mv_target_4000038 +drop cascades to table mv_source_table_4000039 +drop cascades to table mv_result +drop cascades to table mv_target +drop cascades to table mv_source_table +drop cascades to materialized view mv_source +drop cascades to table mv_local +drop cascades to table dist_table +drop cascades to function f_dist() +drop cascades to table fn_target_4000040 +drop cascades to table fn_result +drop cascades to table fn_target +drop cascades to table fn_local +drop cascades to table ft_target +drop cascades to table ft_source_4000045 +drop cascades to table ft_source +drop cascades to extension postgres_fdw +drop cascades to table pg +drop cascades to table t1_4000062 +drop cascades to table s1_4000063 +drop cascades to table t1 +drop cascades to table s1 +SELECT 1 FROM master_remove_node('localhost', :master_port); + ?column? +--------------------------------------------------------------------- + 1 +(1 row) + diff --git a/src/test/regress/expected/merge_0.out b/src/test/regress/expected/merge_0.out new file mode 100644 index 000000000..a7e3fbf20 --- /dev/null +++ b/src/test/regress/expected/merge_0.out @@ -0,0 +1,6 @@ +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int >= 15 AS server_version_ge_15 +\gset +\if :server_version_ge_15 +\else +\q diff --git a/src/test/regress/expected/pg15.out b/src/test/regress/expected/pg15.out index 5dcd2c04d..7a41b25ec 100644 --- a/src/test/regress/expected/pg15.out +++ b/src/test/regress/expected/pg15.out @@ -254,7 +254,7 @@ NOTICE: renaming the new table to pg15.generated_stored_ref -- -- In PG15, there is a new command called MERGE --- It is currently not supported for Citus tables +-- It is currently not supported for Citus non-local tables -- Test the behavior with various commands with Citus table types -- Relevant PG Commit: 7103ebb7aae8ab8076b7e85f335ceb8fe799097c -- @@ -287,7 +287,6 @@ SELECT citus_add_local_table_to_metadata('tbl1'); MERGE INTO tbl1 USING tbl2 ON (true) WHEN MATCHED THEN DELETE; -ERROR: MERGE command is not supported on Citus tables yet SELECT undistribute_table('tbl1'); NOTICE: creating a new table for pg15.tbl1 NOTICE: moving the data of pg15.tbl1 @@ -307,7 +306,6 @@ SELECT citus_add_local_table_to_metadata('tbl2'); MERGE INTO tbl1 USING tbl2 ON (true) WHEN MATCHED THEN DELETE; -ERROR: MERGE command is not supported on Citus tables yet -- one table is reference, the other local, not supported SELECT create_reference_table('tbl2'); create_reference_table @@ -317,7 +315,7 @@ SELECT create_reference_table('tbl2'); MERGE INTO tbl1 USING tbl2 ON (true) WHEN MATCHED THEN DELETE; -ERROR: MERGE command is not supported on Citus tables yet +ERROR: MERGE command is not supported on distributed/reference tables yet -- now, both are reference, still not supported SELECT create_reference_table('tbl1'); create_reference_table @@ -327,7 +325,7 @@ SELECT create_reference_table('tbl1'); MERGE INTO tbl1 USING tbl2 ON (true) WHEN MATCHED THEN DELETE; -ERROR: MERGE command is not supported on Citus tables yet +ERROR: MERGE command is not supported on distributed/reference tables yet -- now, both distributed, not works SELECT undistribute_table('tbl1'); NOTICE: creating a new table for pg15.tbl1 @@ -421,14 +419,14 @@ SELECT create_distributed_table('tbl2', 'x'); MERGE INTO tbl1 USING tbl2 ON (true) WHEN MATCHED THEN DELETE; -ERROR: MERGE command is not supported on Citus tables yet +ERROR: MERGE command is not supported on distributed/reference tables yet -- also, not inside subqueries & ctes WITH targq AS ( SELECT * FROM tbl2 ) MERGE INTO tbl1 USING targq ON (true) WHEN MATCHED THEN DELETE; -ERROR: MERGE command is not supported on Citus tables yet +ERROR: MERGE command is not supported on distributed/reference tables yet -- crashes on beta3, fixed on 15 stable --WITH foo AS ( -- MERGE INTO tbl1 USING tbl2 ON (true) @@ -443,7 +441,7 @@ USING tbl2 ON (true) WHEN MATCHED THEN UPDATE SET x = (SELECT count(*) FROM tbl2); -ERROR: MERGE command is not supported on Citus tables yet +ERROR: MERGE command is not supported on distributed/reference tables yet -- test numeric types with negative scale CREATE TABLE numeric_negative_scale(numeric_column numeric(3,-1), orig_value int); INSERT into numeric_negative_scale SELECT x,x FROM generate_series(111, 115) x; @@ -1490,3 +1488,5 @@ SELECT run_command_on_workers($$DROP ACCESS METHOD heap2$$); \set VERBOSITY terse SET client_min_messages TO ERROR; DROP SCHEMA pg15 CASCADE; +DROP ROLE rls_tenant_1; +DROP ROLE rls_tenant_2; diff --git a/src/test/regress/expected/pgmerge.out b/src/test/regress/expected/pgmerge.out new file mode 100644 index 000000000..b90760691 --- /dev/null +++ b/src/test/regress/expected/pgmerge.out @@ -0,0 +1,2129 @@ +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int >= 15 AS server_version_ge_15 +\gset +\if :server_version_ge_15 +\else +\q +\endif +-- +-- MERGE test from PG community (adapted to Citus by converting all tables to Citus local) +-- +DROP SCHEMA IF EXISTS pgmerge_schema CASCADE; +NOTICE: schema "pgmerge_schema" does not exist, skipping +CREATE SCHEMA pgmerge_schema; +SET search_path TO pgmerge_schema; +SET citus.use_citus_managed_tables to true; +\set SHOW_CONTEXT errors +SET citus.next_shard_id TO 4001000; +SELECT 1 FROM master_add_node('localhost', :master_port, groupid => 0); +NOTICE: localhost:xxxxx is the coordinator and already contains metadata, skipping syncing the metadata + ?column? +--------------------------------------------------------------------- + 1 +(1 row) + +CREATE USER regress_merge_privs; +CREATE USER regress_merge_no_privs; +DROP TABLE IF EXISTS target; +NOTICE: table "target" does not exist, skipping +DROP TABLE IF EXISTS source; +NOTICE: table "source" does not exist, skipping +CREATE TABLE target (tid integer, balance integer) + WITH (autovacuum_enabled=off); +CREATE TABLE source (sid integer, delta integer) -- no index + WITH (autovacuum_enabled=off); +SELECT citus_add_local_table_to_metadata('target'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('source'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO target VALUES (1, 10); +INSERT INTO target VALUES (2, 20); +INSERT INTO target VALUES (3, 30); +SELECT t.ctid is not null as matched, t.*, s.* FROM source s FULL OUTER JOIN target t ON s.sid = t.tid ORDER BY t.tid, s.sid; + matched | tid | balance | sid | delta +--------------------------------------------------------------------- + t | 1 | 10 | | + t | 2 | 20 | | + t | 3 | 30 | | +(3 rows) + +ALTER TABLE target OWNER TO regress_merge_privs; +ALTER TABLE source OWNER TO regress_merge_privs; +CREATE TABLE target2 (tid integer, balance integer) + WITH (autovacuum_enabled=off); +CREATE TABLE source2 (sid integer, delta integer) + WITH (autovacuum_enabled=off); +SELECT citus_add_local_table_to_metadata('target2'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('source2'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +ALTER TABLE target2 OWNER TO regress_merge_no_privs; +ALTER TABLE source2 OWNER TO regress_merge_no_privs; +GRANT INSERT ON target TO regress_merge_no_privs; +GRANT USAGE, CREATE ON SCHEMA pgmerge_schema TO regress_merge_privs; +GRANT USAGE ON SCHEMA pgmerge_schema TO regress_merge_no_privs; +SET SESSION AUTHORIZATION regress_merge_privs; +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; + QUERY PLAN +--------------------------------------------------------------------- + Custom Scan (Citus Adaptive) + Task Count: 1 + Tasks Shown: All + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Merge on target_4001000 t + -> Merge Join + Merge Cond: (t.tid = s.sid) + -> Sort + Sort Key: t.tid + -> Seq Scan on target_4001000 t + -> Sort + Sort Key: s.sid + -> Seq Scan on source_4001001 s +(14 rows) + +-- +-- Errors +-- +MERGE INTO target t RANDOMWORD +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +ERROR: syntax error at or near "RANDOMWORD" +-- MATCHED/INSERT error +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: syntax error at or near "INSERT" +-- incorrectly specifying INTO target +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT INTO target DEFAULT VALUES; +ERROR: syntax error at or near "INTO" +-- Multiple VALUES clause +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (1,1), (2,2); +ERROR: syntax error at or near "," +-- SELECT query for INSERT +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT SELECT (1, 1); +ERROR: syntax error at or near "SELECT" +-- NOT MATCHED/UPDATE +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + UPDATE SET balance = 0; +ERROR: syntax error at or near "UPDATE" +-- UPDATE tablename +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE target SET balance = 0; +ERROR: syntax error at or near "target" +-- source and target names the same +MERGE INTO target +USING target +ON tid = tid +WHEN MATCHED THEN DO NOTHING; +ERROR: name "target" specified more than once +DETAIL: The name is used both as MERGE target table and data source. +-- used in a CTE +WITH foo AS ( + MERGE INTO target USING source ON (true) + WHEN MATCHED THEN DELETE +) SELECT * FROM foo; +ERROR: MERGE not supported in WITH query +-- used in COPY +COPY ( + MERGE INTO target USING source ON (true) + WHEN MATCHED THEN DELETE +) TO stdout; +ERROR: MERGE not supported in COPY +-- unsupported relation types +-- view +CREATE VIEW tv AS SELECT * FROM target; +MERGE INTO tv t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: cannot execute MERGE on relation "tv" +DETAIL: This operation is not supported for views. +DROP VIEW tv; +-- materialized view +CREATE MATERIALIZED VIEW mv AS SELECT * FROM target; +MERGE INTO mv t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: cannot execute MERGE on relation "mv" +DETAIL: This operation is not supported for materialized views. +DROP MATERIALIZED VIEW mv; +-- permissions +MERGE INTO target +USING source2 +ON target.tid = source2.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +ERROR: permission denied for table source2 +GRANT INSERT ON target TO regress_merge_no_privs; +SET SESSION AUTHORIZATION regress_merge_no_privs; +MERGE INTO target +USING source2 +ON target.tid = source2.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +ERROR: permission denied for table target +GRANT UPDATE ON target2 TO regress_merge_privs; +SET SESSION AUTHORIZATION regress_merge_privs; +MERGE INTO target2 +USING source +ON target2.tid = source.sid +WHEN MATCHED THEN + DELETE; +ERROR: permission denied for table target2 +MERGE INTO target2 +USING source +ON target2.tid = source.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: permission denied for table target2 +-- check if the target can be accessed from source relation subquery; we should +-- not be able to do so +MERGE INTO target t +USING (SELECT * FROM source WHERE t.tid > sid) s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: invalid reference to FROM-clause entry for table "t" +HINT: There is an entry for table "t", but it cannot be referenced from this part of the query. +-- +-- initial tests +-- +-- zero rows in source has no effect +MERGE INTO target +USING source +ON target.tid = source.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ROLLBACK; +-- insert some non-matching source rows to work from +INSERT INTO source VALUES (4, 40); +SELECT * FROM source ORDER BY sid; + sid | delta +--------------------------------------------------------------------- + 4 | 40 +(1 row) + +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + DO NOTHING; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 + | +(4 rows) + +ROLLBACK; +-- index plans +INSERT INTO target SELECT generate_series(1000,2500), 0; +ALTER TABLE target ADD CONSTRAINT targetidx PRIMARY KEY (tid); +ANALYZE target; +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; + QUERY PLAN +--------------------------------------------------------------------- + Custom Scan (Citus Adaptive) + Task Count: 1 + Tasks Shown: All + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Merge on target_4001000 t + -> Hash Join + Hash Cond: (s.sid = t.tid) + -> Seq Scan on source_4001001 s + -> Hash + -> Seq Scan on target_4001000 t +(11 rows) + +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; + QUERY PLAN +--------------------------------------------------------------------- + Custom Scan (Citus Adaptive) + Task Count: 1 + Tasks Shown: All + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Merge on target_4001000 t + -> Hash Join + Hash Cond: (s.sid = t.tid) + -> Seq Scan on source_4001001 s + -> Hash + -> Seq Scan on target_4001000 t +(11 rows) + +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); + QUERY PLAN +--------------------------------------------------------------------- + Custom Scan (Citus Adaptive) + Task Count: 1 + Tasks Shown: All + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Merge on target_4001000 t + -> Hash Left Join + Hash Cond: (s.sid = t.tid) + -> Seq Scan on source_4001001 s + -> Hash + -> Seq Scan on target_4001000 t +(11 rows) + +DELETE FROM target WHERE tid > 100; +ANALYZE target; +-- insert some matching source rows to work from +INSERT INTO source VALUES (2, 5); +INSERT INTO source VALUES (3, 20); +SELECT * FROM source ORDER BY sid; + sid | delta +--------------------------------------------------------------------- + 2 | 5 + 3 | 20 + 4 | 40 +(3 rows) + +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +-- equivalent of an UPDATE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 0 + 3 | 0 +(3 rows) + +ROLLBACK; +-- equivalent of a DELETE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 +(1 row) + +ROLLBACK; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DO NOTHING; +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +ROLLBACK; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | +(4 rows) + +ROLLBACK; +-- duplicate source row causes multiple target row update ERROR +INSERT INTO source VALUES (2, 5); +SELECT * FROM source ORDER BY sid; + sid | delta +--------------------------------------------------------------------- + 2 | 5 + 2 | 5 + 3 | 20 + 4 | 40 +(4 rows) + +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +ERROR: MERGE command cannot affect row a second time +HINT: Ensure that not more than one source row matches any one target row. +ROLLBACK; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +ERROR: MERGE command cannot affect row a second time +HINT: Ensure that not more than one source row matches any one target row. +ROLLBACK; +-- remove duplicate MATCHED data from source data +DELETE FROM source WHERE sid = 2; +INSERT INTO source VALUES (2, 5); +SELECT * FROM source ORDER BY sid; + sid | delta +--------------------------------------------------------------------- + 2 | 5 + 3 | 20 + 4 | 40 +(3 rows) + +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +-- duplicate source row on INSERT should fail because of target_pkey +INSERT INTO source VALUES (4, 40); +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); +ERROR: duplicate key value violates unique constraint "targetidx_4001000" +DETAIL: Key (tid)=(4) already exists. +SELECT * FROM target ORDER BY tid; +ERROR: current transaction is aborted, commands ignored until end of transaction block +ROLLBACK; +-- remove duplicate NOT MATCHED data from source data +DELETE FROM source WHERE sid = 4; +INSERT INTO source VALUES (4, 40); +SELECT * FROM source ORDER BY sid; + sid | delta +--------------------------------------------------------------------- + 2 | 5 + 3 | 20 + 4 | 40 +(3 rows) + +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +-- remove constraints +alter table target drop CONSTRAINT targetidx; +alter table target alter column tid drop not null; +-- multiple actions +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, 4) +WHEN MATCHED THEN + UPDATE SET balance = 0; +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 0 + 3 | 0 + 4 | 4 +(4 rows) + +ROLLBACK; +-- should be equivalent +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0 +WHEN NOT MATCHED THEN + INSERT VALUES (4, 4); +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 0 + 3 | 0 + 4 | 4 +(4 rows) + +ROLLBACK; +-- column references +-- do a simple equivalent of an UPDATE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance + s.delta; +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 25 + 3 | 50 +(3 rows) + +ROLLBACK; +-- do a simple equivalent of an INSERT SELECT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 +(4 rows) + +ROLLBACK; +-- and again with duplicate source rows +INSERT INTO source VALUES (5, 50); +INSERT INTO source VALUES (5, 50); +-- do a simple equivalent of an INSERT SELECT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 + 5 | 50 + 5 | 50 +(6 rows) + +ROLLBACK; +-- removing duplicate source rows +DELETE FROM source WHERE sid = 5; +-- and again with explicitly identified column list +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 +(4 rows) + +ROLLBACK; +-- and again with a subtle error: referring to non-existent target row for NOT MATCHED +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (t.tid, s.delta); +ERROR: invalid reference to FROM-clause entry for table "t" +HINT: There is an entry for table "t", but it cannot be referenced from this part of the query. +-- and again with a constant ON clause +BEGIN; +MERGE INTO target t +USING source AS s +ON (SELECT true) +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (t.tid, s.delta); +ERROR: invalid reference to FROM-clause entry for table "t" +HINT: There is an entry for table "t", but it cannot be referenced from this part of the query. +SELECT * FROM target ORDER BY tid; +ERROR: current transaction is aborted, commands ignored until end of transaction block +ROLLBACK; +-- now the classic UPSERT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance + s.delta +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 25 + 3 | 50 + 4 | 40 +(4 rows) + +ROLLBACK; +-- unreachable WHEN clause should ERROR +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN /* Terminal WHEN clause for MATCHED */ + DELETE +WHEN MATCHED AND s.delta > 0 THEN + UPDATE SET balance = t.balance - s.delta; +ERROR: unreachable WHEN clause specified after unconditional WHEN clause +ROLLBACK; +-- conditional WHEN clause +CREATE TABLE wq_target (tid integer not null, balance integer DEFAULT -1) + WITH (autovacuum_enabled=off); +CREATE TABLE wq_source (balance integer, sid integer) + WITH (autovacuum_enabled=off); +SELECT citus_add_local_table_to_metadata('wq_target'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('wq_source'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO wq_source (sid, balance) VALUES (1, 100); +BEGIN; +-- try a simple INSERT with default values first +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | -1 +(1 row) + +ROLLBACK; +-- this time with a FALSE condition +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND FALSE THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- +(0 rows) + +-- this time with an actual condition which returns false +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance <> 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- +(0 rows) + +BEGIN; +-- and now with a condition which returns true +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | -1 +(1 row) + +ROLLBACK; +-- conditions in the NOT MATCHED clause can only refer to source columns +BEGIN; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND t.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +ERROR: invalid reference to FROM-clause entry for table "t" +HINT: There is an entry for table "t", but it cannot be referenced from this part of the query. +SELECT * FROM wq_target; +ERROR: current transaction is aborted, commands ignored until end of transaction block +ROLLBACK; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | -1 +(1 row) + +-- conditions in MATCHED clause can refer to both source and target +SELECT * FROM wq_source; + balance | sid +--------------------------------------------------------------------- + 100 | 1 +(1 row) + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND s.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | 99 +(1 row) + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | 99 +(1 row) + +-- check if AND works +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 AND s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | 99 +(1 row) + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 AND s.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | 199 +(1 row) + +-- check if OR works +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 OR s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | 199 +(1 row) + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 199 OR s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | 299 +(1 row) + +-- check source-side whole-row references +BEGIN; +MERGE INTO wq_target t +USING wq_source s ON (t.tid = s.sid) +WHEN matched and t = s or t.tid = s.sid THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | 399 +(1 row) + +ROLLBACK; +-- check if subqueries work in the conditions? +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance > (SELECT max(balance) FROM target) THEN + UPDATE SET balance = t.balance + s.balance; +-- check if we can access system columns in the conditions +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.xmin = t.xmax THEN + UPDATE SET balance = t.balance + s.balance; +ERROR: cannot use system column "xmin" in MERGE WHEN condition +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.tableoid >= 0 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +--------------------------------------------------------------------- + 1 | 499 +(1 row) + +-- test preventing WHEN conditions from writing to the database +create or replace function merge_when_and_write() returns boolean +language plpgsql as +$$ +BEGIN + INSERT INTO target VALUES (100, 100); + RETURN TRUE; +END; +$$; +BEGIN; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND (merge_when_and_write()) THEN + UPDATE SET balance = t.balance + s.balance; +ERROR: functions used in UPDATE queries on distributed tables must not be VOLATILE +ROLLBACK; +drop function merge_when_and_write(); +DROP TABLE wq_target, wq_source; +-- test triggers +create or replace function merge_trigfunc () returns trigger +language plpgsql as +$$ +DECLARE + line text; +BEGIN + SELECT INTO line format('%s %s %s trigger%s', + TG_WHEN, TG_OP, TG_LEVEL, CASE + WHEN TG_OP = 'INSERT' AND TG_LEVEL = 'ROW' + THEN format(' row: %s', NEW) + WHEN TG_OP = 'UPDATE' AND TG_LEVEL = 'ROW' + THEN format(' row: %s -> %s', OLD, NEW) + WHEN TG_OP = 'DELETE' AND TG_LEVEL = 'ROW' + THEN format(' row: %s', OLD) + END); + + RAISE NOTICE '%', line; + IF (TG_WHEN = 'BEFORE' AND TG_LEVEL = 'ROW') THEN + IF (TG_OP = 'DELETE') THEN + RETURN OLD; + ELSE + RETURN NEW; + END IF; + ELSE + RETURN NULL; + END IF; +END; +$$; +CREATE TRIGGER merge_bsi BEFORE INSERT ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bsu BEFORE UPDATE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bsd BEFORE DELETE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asi AFTER INSERT ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asu AFTER UPDATE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asd AFTER DELETE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bri BEFORE INSERT ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bru BEFORE UPDATE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_brd BEFORE DELETE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_ari AFTER INSERT ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_aru AFTER UPDATE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_ard AFTER DELETE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +-- now the classic UPSERT, with a DELETE +BEGIN; +UPDATE target SET balance = 0 WHERE tid = 3; +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (3,30) -> (3,0) +NOTICE: AFTER UPDATE ROW trigger row: (3,30) -> (3,0) +NOTICE: AFTER UPDATE STATEMENT trigger +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED AND t.balance > s.delta THEN + UPDATE SET balance = t.balance - s.delta +WHEN MATCHED THEN + DELETE +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE DELETE STATEMENT trigger +NOTICE: BEFORE DELETE ROW trigger row: (3,0) +NOTICE: BEFORE UPDATE ROW trigger row: (2,20) -> (2,15) +NOTICE: BEFORE INSERT ROW trigger row: (4,40) +NOTICE: AFTER DELETE ROW trigger row: (3,0) +NOTICE: AFTER UPDATE ROW trigger row: (2,20) -> (2,15) +NOTICE: AFTER INSERT ROW trigger row: (4,40) +NOTICE: AFTER DELETE STATEMENT trigger +NOTICE: AFTER UPDATE STATEMENT trigger +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 15 + 4 | 40 +(3 rows) + +ROLLBACK; +-- Test behavior of triggers that turn UPDATE/DELETE into no-ops +create or replace function skip_merge_op() returns trigger +language plpgsql as +$$ +BEGIN + RETURN NULL; +END; +$$; +SELECT * FROM target full outer join source on (sid = tid); + tid | balance | sid | delta +--------------------------------------------------------------------- + 3 | 30 | 3 | 20 + 2 | 20 | 2 | 5 + | | 4 | 40 + 1 | 10 | | +(4 rows) + +create trigger merge_skip BEFORE INSERT OR UPDATE or DELETE + ON target FOR EACH ROW EXECUTE FUNCTION skip_merge_op(); +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED AND s.sid = 3 THEN UPDATE SET balance = t.balance + s.delta +WHEN MATCHED THEN DELETE +WHEN NOT MATCHED THEN INSERT VALUES (sid, delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE DELETE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (3,30) -> (3,50) +NOTICE: BEFORE DELETE ROW trigger row: (2,20) +NOTICE: BEFORE INSERT ROW trigger row: (4,40) +NOTICE: AFTER DELETE STATEMENT trigger +NOTICE: AFTER UPDATE STATEMENT trigger +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target FULL OUTER JOIN source ON (sid = tid); + tid | balance | sid | delta +--------------------------------------------------------------------- + 3 | 30 | 3 | 20 + 2 | 20 | 2 | 5 + | | 4 | 40 + 1 | 10 | | +(4 rows) + +DROP TRIGGER merge_skip ON target; +DROP FUNCTION skip_merge_op(); +-- test from PL/pgSQL +-- make sure MERGE INTO isn't interpreted to mean returning variables like SELECT INTO +BEGIN; +DO LANGUAGE plpgsql $$ +BEGIN +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED AND t.balance > s.delta THEN + UPDATE SET balance = t.balance - s.delta; +END; +$$; +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (3,30) -> (3,10) +NOTICE: BEFORE UPDATE ROW trigger row: (2,20) -> (2,15) +NOTICE: AFTER UPDATE ROW trigger row: (3,30) -> (3,10) +NOTICE: AFTER UPDATE ROW trigger row: (2,20) -> (2,15) +NOTICE: AFTER UPDATE STATEMENT trigger +ROLLBACK; +--source constants +BEGIN; +MERGE INTO target t +USING (SELECT 9 AS sid, 57 AS delta) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE INSERT ROW trigger row: (9,57) +NOTICE: AFTER INSERT ROW trigger row: (9,57) +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 + 9 | 57 +(4 rows) + +ROLLBACK; +--source query +BEGIN; +MERGE INTO target t +USING (SELECT sid, delta FROM source WHERE delta > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 +(4 rows) + +ROLLBACK; +BEGIN; +MERGE INTO target t +USING (SELECT sid, delta as newname FROM source WHERE delta > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.newname); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 +(4 rows) + +ROLLBACK; +--self-merge +BEGIN; +MERGE INTO target t1 +USING target t2 +ON t1.tid = t2.tid +WHEN MATCHED THEN + UPDATE SET balance = t1.balance + t2.balance +WHEN NOT MATCHED THEN + INSERT VALUES (t2.tid, t2.balance); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (1,10) -> (1,20) +NOTICE: BEFORE UPDATE ROW trigger row: (2,20) -> (2,40) +NOTICE: BEFORE UPDATE ROW trigger row: (3,30) -> (3,60) +NOTICE: AFTER UPDATE ROW trigger row: (1,10) -> (1,20) +NOTICE: AFTER UPDATE ROW trigger row: (2,20) -> (2,40) +NOTICE: AFTER UPDATE ROW trigger row: (3,30) -> (3,60) +NOTICE: AFTER UPDATE STATEMENT trigger +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 20 + 2 | 40 + 3 | 60 +(3 rows) + +ROLLBACK; +BEGIN; +MERGE INTO target t +USING (SELECT tid as sid, balance as delta FROM target WHERE balance > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +ROLLBACK; +BEGIN; +MERGE INTO target t +USING +(SELECT sid, max(delta) AS delta + FROM source + GROUP BY sid + HAVING count(*) = 1 + ORDER BY sid ASC) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 +(4 rows) + +ROLLBACK; +-- plpgsql parameters and results +BEGIN; +CREATE FUNCTION merge_func (p_id integer, p_bal integer) +RETURNS INTEGER +LANGUAGE plpgsql +AS $$ +DECLARE + result integer; +BEGIN +MERGE INTO target t +USING (SELECT p_id AS sid) AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance - p_bal; +IF FOUND THEN + GET DIAGNOSTICS result := ROW_COUNT; +END IF; +RETURN result; +END; +$$; +SELECT merge_func(3, 4); +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (3,30) -> (3,26) +NOTICE: AFTER UPDATE ROW trigger row: (3,30) -> (3,26) +NOTICE: AFTER UPDATE STATEMENT trigger + merge_func +--------------------------------------------------------------------- + 1 +(1 row) + +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 10 + 2 | 20 + 3 | 26 +(3 rows) + +ROLLBACK; +-- PREPARE +BEGIN; +prepare foom as merge into target t using (select 1 as sid) s on (t.tid = s.sid) when matched then update set balance = 1; +execute foom; +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (1,10) -> (1,1) +NOTICE: AFTER UPDATE ROW trigger row: (1,10) -> (1,1) +NOTICE: AFTER UPDATE STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 1 + 2 | 20 + 3 | 30 +(3 rows) + +ROLLBACK; +BEGIN; +PREPARE foom2 (integer, integer) AS +MERGE INTO target t +USING (SELECT 1) s +ON t.tid = $1 +WHEN MATCHED THEN +UPDATE SET balance = $2; +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +execute foom2 (1, 1); +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (1,10) -> (1,1) +NOTICE: AFTER UPDATE ROW trigger row: (1,10) -> (1,1) +NOTICE: AFTER UPDATE STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +--------------------------------------------------------------------- + 1 | 1 + 2 | 20 + 3 | 30 +(3 rows) + +ROLLBACK; +-- subqueries in source relation +CREATE TABLE sq_target (tid integer NOT NULL, balance integer) + WITH (autovacuum_enabled=off); +CREATE TABLE sq_source (delta integer, sid integer, balance integer DEFAULT 0) + WITH (autovacuum_enabled=off); +SELECT citus_add_local_table_to_metadata('sq_target'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('sq_source'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO sq_target(tid, balance) VALUES (1,100), (2,200), (3,300); +INSERT INTO sq_source(sid, delta) VALUES (1,10), (2,20), (4,40); +BEGIN; +MERGE INTO sq_target t +USING (SELECT * FROM sq_source) s +ON tid = sid +WHEN MATCHED AND t.balance > delta THEN + UPDATE SET balance = t.balance + delta; +SELECT * FROM sq_target; + tid | balance +--------------------------------------------------------------------- + 3 | 300 + 1 | 110 + 2 | 220 +(3 rows) + +ROLLBACK; +-- try a view +CREATE VIEW v AS SELECT * FROM sq_source WHERE sid < 2; +BEGIN; +MERGE INTO sq_target +USING v +ON tid = sid +WHEN MATCHED THEN + UPDATE SET balance = v.balance + delta; +SELECT * FROM sq_target; + tid | balance +--------------------------------------------------------------------- + 2 | 200 + 3 | 300 + 1 | 10 +(3 rows) + +ROLLBACK; +-- ambiguous reference to a column +BEGIN; +MERGE INTO sq_target +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +ERROR: column reference "balance" is ambiguous +ROLLBACK; +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +SELECT * FROM sq_target; + tid | balance +--------------------------------------------------------------------- + 2 | 200 + 3 | 300 + -1 | -11 +(3 rows) + +ROLLBACK; +-- CTEs +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +WITH targq AS ( + SELECT * FROM v +) +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +ROLLBACK; +-- RETURNING +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE +RETURNING *; +ERROR: syntax error at or near "RETURNING" +ROLLBACK; +-- EXPLAIN +CREATE TABLE ex_mtarget (a int, b int) + WITH (autovacuum_enabled=off); +CREATE TABLE ex_msource (a int, b int) + WITH (autovacuum_enabled=off); +SELECT citus_add_local_table_to_metadata('ex_mtarget'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('ex_msource'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO ex_mtarget SELECT i, i*10 FROM generate_series(1,100,2) i; +INSERT INTO ex_msource SELECT i, i*10 FROM generate_series(1,100,1) i; +CREATE FUNCTION explain_merge(query text) RETURNS SETOF text +LANGUAGE plpgsql AS +$$ +DECLARE ln text; +BEGIN + FOR ln IN + EXECUTE 'explain (analyze, timing off, summary off, costs off) ' || + query + LOOP + ln := regexp_replace(ln, '(Memory( Usage)?|Buckets|Batches): \S*', '\1: xxx', 'g'); + RETURN NEXT ln; + END LOOP; +END; +$$; +-- only updates +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = t.b + 1'); + explain_merge +--------------------------------------------------------------------- + Custom Scan (Citus Adaptive) (actual rows=0 loops=1) + Task Count: 1 + Tasks Shown: All + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Merge on ex_mtarget_4001008 t (actual rows=0 loops=1) + Tuples: updated=50 + -> Merge Join (actual rows=50 loops=1) + Merge Cond: (t.a = s.a) + -> Sort (actual rows=50 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget_4001008 t (actual rows=50 loops=1) + -> Sort (actual rows=100 loops=1) + Sort Key: s.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_msource_4001009 s (actual rows=100 loops=1) +(17 rows) + +-- only updates to selected tuples +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1'); + explain_merge +--------------------------------------------------------------------- + Custom Scan (Citus Adaptive) (actual rows=0 loops=1) + Task Count: 1 + Tasks Shown: All + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Merge on ex_mtarget_4001008 t (actual rows=0 loops=1) + Tuples: updated=5 skipped=45 + -> Merge Join (actual rows=50 loops=1) + Merge Cond: (t.a = s.a) + -> Sort (actual rows=50 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget_4001008 t (actual rows=50 loops=1) + -> Sort (actual rows=100 loops=1) + Sort Key: s.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_msource_4001009 s (actual rows=100 loops=1) +(17 rows) + +-- updates + deletes +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1 +WHEN MATCHED AND t.a >= 10 AND t.a <= 20 THEN + DELETE'); + explain_merge +--------------------------------------------------------------------- + Custom Scan (Citus Adaptive) (actual rows=0 loops=1) + Task Count: 1 + Tasks Shown: All + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Merge on ex_mtarget_4001008 t (actual rows=0 loops=1) + Tuples: updated=5 deleted=5 skipped=40 + -> Merge Join (actual rows=50 loops=1) + Merge Cond: (t.a = s.a) + -> Sort (actual rows=50 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget_4001008 t (actual rows=50 loops=1) + -> Sort (actual rows=100 loops=1) + Sort Key: s.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_msource_4001009 s (actual rows=100 loops=1) +(17 rows) + +-- only inserts +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN NOT MATCHED AND s.a < 10 THEN + INSERT VALUES (a, b)'); + explain_merge +--------------------------------------------------------------------- + Custom Scan (Citus Adaptive) (actual rows=0 loops=1) + Task Count: 1 + Tasks Shown: All + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Merge on ex_mtarget_4001008 t (actual rows=0 loops=1) + Tuples: inserted=4 skipped=96 + -> Merge Left Join (actual rows=100 loops=1) + Merge Cond: (s.a = t.a) + -> Sort (actual rows=100 loops=1) + Sort Key: s.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_msource_4001009 s (actual rows=100 loops=1) + -> Sort (actual rows=45 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget_4001008 t (actual rows=45 loops=1) +(17 rows) + +-- all three +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1 +WHEN MATCHED AND t.a >= 30 AND t.a <= 40 THEN + DELETE +WHEN NOT MATCHED AND s.a < 20 THEN + INSERT VALUES (a, b)'); + explain_merge +--------------------------------------------------------------------- + Custom Scan (Citus Adaptive) (actual rows=0 loops=1) + Task Count: 1 + Tasks Shown: All + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Merge on ex_mtarget_4001008 t (actual rows=0 loops=1) + Tuples: inserted=10 updated=9 deleted=5 skipped=76 + -> Merge Left Join (actual rows=100 loops=1) + Merge Cond: (s.a = t.a) + -> Sort (actual rows=100 loops=1) + Sort Key: s.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_msource_4001009 s (actual rows=100 loops=1) + -> Sort (actual rows=49 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget_4001008 t (actual rows=49 loops=1) +(17 rows) + +-- nothing +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a AND t.a < -1000 +WHEN MATCHED AND t.a < 10 THEN + DO NOTHING'); + explain_merge +--------------------------------------------------------------------- + Custom Scan (Citus Adaptive) (actual rows=0 loops=1) + Task Count: 1 + Tasks Shown: All + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Merge on ex_mtarget_4001008 t (actual rows=0 loops=1) + -> Merge Join (actual rows=0 loops=1) + Merge Cond: (t.a = s.a) + -> Sort (actual rows=0 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget_4001008 t (actual rows=0 loops=1) + Filter: (a < '-1000'::integer) + Rows Removed by Filter: 54 + -> Sort (never executed) + Sort Key: s.a + -> Seq Scan on ex_msource_4001009 s (never executed) +(17 rows) + +DROP TABLE ex_msource, ex_mtarget; +DROP FUNCTION explain_merge(text); +-- Subqueries +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED THEN + UPDATE SET balance = (SELECT count(*) FROM sq_target); +SELECT * FROM sq_target WHERE tid = 1; + tid | balance +--------------------------------------------------------------------- + 1 | 3 +(1 row) + +ROLLBACK; +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND (SELECT count(*) > 0 FROM sq_target) THEN + UPDATE SET balance = 42; +SELECT * FROM sq_target WHERE tid = 1; + tid | balance +--------------------------------------------------------------------- + 1 | 42 +(1 row) + +ROLLBACK; +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid AND (SELECT count(*) > 0 FROM sq_target) +WHEN MATCHED THEN + UPDATE SET balance = 42; +SELECT * FROM sq_target WHERE tid = 1; + tid | balance +--------------------------------------------------------------------- + 1 | 42 +(1 row) + +ROLLBACK; +DROP TABLE sq_target, sq_source CASCADE; +NOTICE: drop cascades to view v +CREATE TABLE pa_target (tid integer, balance float, val text) + PARTITION BY LIST (tid); +CREATE TABLE part1 PARTITION OF pa_target FOR VALUES IN (1,4) + WITH (autovacuum_enabled=off); +CREATE TABLE part2 PARTITION OF pa_target FOR VALUES IN (2,5,6) + WITH (autovacuum_enabled=off); +CREATE TABLE part3 PARTITION OF pa_target FOR VALUES IN (3,8,9) + WITH (autovacuum_enabled=off); +CREATE TABLE part4 PARTITION OF pa_target DEFAULT + WITH (autovacuum_enabled=off); +CREATE TABLE pa_source (sid integer, delta float); +-- insert many rows to the source table +INSERT INTO pa_source SELECT id, id * 10 FROM generate_series(1,14) AS id; +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT id, id * 100, 'initial' FROM generate_series(1,14,2) AS id; +SELECT citus_add_local_table_to_metadata('pa_target'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +SELECT citus_add_local_table_to_metadata('pa_source'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +-- try simple MERGE +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +--------------------------------------------------------------------- + 1 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 3 | 330 | initial updated by merge + 4 | 40 | inserted by merge + 5 | 550 | initial updated by merge + 6 | 60 | inserted by merge + 7 | 770 | initial updated by merge + 8 | 80 | inserted by merge + 9 | 990 | initial updated by merge + 10 | 100 | inserted by merge + 11 | 1210 | initial updated by merge + 12 | 120 | inserted by merge + 13 | 1430 | initial updated by merge + 14 | 140 | inserted by merge +(14 rows) + +ROLLBACK; +-- same with a constant qual +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid AND tid = 1 + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +--------------------------------------------------------------------- + 1 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 3 | 30 | inserted by merge + 3 | 300 | initial + 4 | 40 | inserted by merge + 5 | 500 | initial + 5 | 50 | inserted by merge + 6 | 60 | inserted by merge + 7 | 700 | initial + 7 | 70 | inserted by merge + 8 | 80 | inserted by merge + 9 | 90 | inserted by merge + 9 | 900 | initial + 10 | 100 | inserted by merge + 11 | 1100 | initial + 11 | 110 | inserted by merge + 12 | 120 | inserted by merge + 13 | 1300 | initial + 13 | 130 | inserted by merge + 14 | 140 | inserted by merge +(20 rows) + +ROLLBACK; +-- try updating the partition key column +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET tid = tid + 1, balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +--------------------------------------------------------------------- + 2 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 4 | 40 | inserted by merge + 4 | 330 | initial updated by merge + 6 | 550 | initial updated by merge + 6 | 60 | inserted by merge + 8 | 80 | inserted by merge + 8 | 770 | initial updated by merge + 10 | 990 | initial updated by merge + 10 | 100 | inserted by merge + 12 | 1210 | initial updated by merge + 12 | 120 | inserted by merge + 14 | 1430 | initial updated by merge + 14 | 140 | inserted by merge +(14 rows) + +ROLLBACK; +DROP TABLE pa_target CASCADE; +-- The target table is partitioned in the same way, but this time by attaching +-- partitions which have columns in different order, dropped columns etc. +CREATE TABLE pa_target (tid integer, balance float, val text) + PARTITION BY LIST (tid); +CREATE TABLE part1 (tid integer, balance float, val text) + WITH (autovacuum_enabled=off); +CREATE TABLE part2 (balance float, tid integer, val text) + WITH (autovacuum_enabled=off); +CREATE TABLE part3 (tid integer, balance float, val text) + WITH (autovacuum_enabled=off); +CREATE TABLE part4 (extraid text, tid integer, balance float, val text) + WITH (autovacuum_enabled=off); +ALTER TABLE part4 DROP COLUMN extraid; +ALTER TABLE pa_target ATTACH PARTITION part1 FOR VALUES IN (1,4); +ALTER TABLE pa_target ATTACH PARTITION part2 FOR VALUES IN (2,5,6); +ALTER TABLE pa_target ATTACH PARTITION part3 FOR VALUES IN (3,8,9); +ALTER TABLE pa_target ATTACH PARTITION part4 DEFAULT; +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT id, id * 100, 'initial' FROM generate_series(1,14,2) AS id; +-- try simple MERGE +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +--------------------------------------------------------------------- + 1 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 3 | 330 | initial updated by merge + 4 | 40 | inserted by merge + 5 | 550 | initial updated by merge + 6 | 60 | inserted by merge + 7 | 770 | initial updated by merge + 8 | 80 | inserted by merge + 9 | 990 | initial updated by merge + 10 | 100 | inserted by merge + 11 | 1210 | initial updated by merge + 12 | 120 | inserted by merge + 13 | 1430 | initial updated by merge + 14 | 140 | inserted by merge +(14 rows) + +ROLLBACK; +-- same with a constant qual +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid AND tid IN (1, 5) + WHEN MATCHED AND tid % 5 = 0 THEN DELETE + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +--------------------------------------------------------------------- + 1 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 3 | 30 | inserted by merge + 3 | 300 | initial + 4 | 40 | inserted by merge + 6 | 60 | inserted by merge + 7 | 700 | initial + 7 | 70 | inserted by merge + 8 | 80 | inserted by merge + 9 | 900 | initial + 9 | 90 | inserted by merge + 10 | 100 | inserted by merge + 11 | 110 | inserted by merge + 11 | 1100 | initial + 12 | 120 | inserted by merge + 13 | 1300 | initial + 13 | 130 | inserted by merge + 14 | 140 | inserted by merge +(18 rows) + +ROLLBACK; +-- try updating the partition key column +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET tid = tid + 1, balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +--------------------------------------------------------------------- + 2 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 4 | 40 | inserted by merge + 4 | 330 | initial updated by merge + 6 | 550 | initial updated by merge + 6 | 60 | inserted by merge + 8 | 80 | inserted by merge + 8 | 770 | initial updated by merge + 10 | 990 | initial updated by merge + 10 | 100 | inserted by merge + 12 | 1210 | initial updated by merge + 12 | 120 | inserted by merge + 14 | 1430 | initial updated by merge + 14 | 140 | inserted by merge +(14 rows) + +ROLLBACK; +DROP TABLE pa_source; +DROP TABLE pa_target CASCADE; +-- Sub-partitioning +SET citus.use_citus_managed_tables to false; +CREATE TABLE pa_target (logts timestamp, tid integer, balance float, val text) + PARTITION BY RANGE (logts); +CREATE TABLE part_m01 PARTITION OF pa_target + FOR VALUES FROM ('2017-01-01') TO ('2017-02-01') + PARTITION BY LIST (tid); +SET citus.use_citus_managed_tables to true; +CREATE TABLE part_m01_odd PARTITION OF part_m01 + FOR VALUES IN (1,3,5,7,9) WITH (autovacuum_enabled=off); +CREATE TABLE part_m01_even PARTITION OF part_m01 + FOR VALUES IN (2,4,6,8) WITH (autovacuum_enabled=off); +CREATE TABLE part_m02 PARTITION OF pa_target + FOR VALUES FROM ('2017-02-01') TO ('2017-03-01') + PARTITION BY LIST (tid); +CREATE TABLE part_m02_odd PARTITION OF part_m02 + FOR VALUES IN (1,3,5,7,9) WITH (autovacuum_enabled=off); +CREATE TABLE part_m02_even PARTITION OF part_m02 + FOR VALUES IN (2,4,6,8) WITH (autovacuum_enabled=off); +CREATE TABLE pa_source (sid integer, delta float) + WITH (autovacuum_enabled=off); +-- insert many rows to the source table +INSERT INTO pa_source SELECT id, id * 10 FROM generate_series(1,14) AS id; +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT '2017-01-31', id, id * 100, 'initial' FROM generate_series(1,9,3) AS id; +INSERT INTO pa_target SELECT '2017-02-28', id, id * 100, 'initial' FROM generate_series(2,9,3) AS id; +-- try simple MERGE +SET client_min_messages TO DEBUG1; +BEGIN; +MERGE INTO pa_target t + USING (SELECT '2017-01-15' AS slogts, * FROM pa_source WHERE sid < 10) s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (slogts::timestamp, sid, delta, 'inserted by merge'); +DEBUG: +SELECT * FROM pa_target ORDER BY tid; + logts | tid | balance | val +--------------------------------------------------------------------- + Tue Jan 31 00:00:00 2017 | 1 | 110 | initial updated by merge + Tue Feb 28 00:00:00 2017 | 2 | 220 | initial updated by merge + Sun Jan 15 00:00:00 2017 | 3 | 30 | inserted by merge + Tue Jan 31 00:00:00 2017 | 4 | 440 | initial updated by merge + Tue Feb 28 00:00:00 2017 | 5 | 550 | initial updated by merge + Sun Jan 15 00:00:00 2017 | 6 | 60 | inserted by merge + Tue Jan 31 00:00:00 2017 | 7 | 770 | initial updated by merge + Tue Feb 28 00:00:00 2017 | 8 | 880 | initial updated by merge + Sun Jan 15 00:00:00 2017 | 9 | 90 | inserted by merge +(9 rows) + +ROLLBACK; +RESET client_min_messages; +DROP TABLE pa_source; +DROP TABLE pa_target CASCADE; +-- some complex joins on the source side +CREATE TABLE cj_target (tid integer, balance float, val text) + WITH (autovacuum_enabled=off); +CREATE TABLE cj_source1 (sid1 integer, scat integer, delta integer) + WITH (autovacuum_enabled=off); +CREATE TABLE cj_source2 (sid2 integer, sval text) + WITH (autovacuum_enabled=off); +INSERT INTO cj_source1 VALUES (1, 10, 100); +INSERT INTO cj_source1 VALUES (1, 20, 200); +INSERT INTO cj_source1 VALUES (2, 20, 300); +INSERT INTO cj_source1 VALUES (3, 10, 400); +INSERT INTO cj_source2 VALUES (1, 'initial source2'); +INSERT INTO cj_source2 VALUES (2, 'initial source2'); +INSERT INTO cj_source2 VALUES (3, 'initial source2'); +-- source relation is an unaliased join +MERGE INTO cj_target t +USING cj_source1 s1 + INNER JOIN cj_source2 s2 ON sid1 = sid2 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid1, delta, sval); +-- try accessing columns from either side of the source join +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 AND scat = 20 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid2, delta, sval) +WHEN MATCHED THEN + DELETE; +-- some simple expressions in INSERT targetlist +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid2, delta + scat, sval) +WHEN MATCHED THEN + UPDATE SET val = val || ' updated by merge'; +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 AND scat = 20 +ON t.tid = sid1 +WHEN MATCHED THEN + UPDATE SET val = val || ' ' || delta::text; +SELECT * FROM cj_target; + tid | balance | val +--------------------------------------------------------------------- + 3 | 400 | initial source2 updated by merge + 1 | 220 | initial source2 200 + 1 | 110 | initial source2 200 + 2 | 320 | initial source2 300 +(4 rows) + +ALTER TABLE cj_source1 RENAME COLUMN sid1 TO sid; +ALTER TABLE cj_source2 RENAME COLUMN sid2 TO sid; +TRUNCATE cj_target; +MERGE INTO cj_target t +USING cj_source1 s1 + INNER JOIN cj_source2 s2 ON s1.sid = s2.sid +ON t.tid = s1.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s2.sid, delta, sval); +DROP TABLE cj_source2, cj_source1, cj_target; +-- Function scans +CREATE TABLE fs_target (a int, b int, c text) + WITH (autovacuum_enabled=off); +MERGE INTO fs_target t +USING generate_series(1,100,1) AS id +ON t.a = id +WHEN MATCHED THEN + UPDATE SET b = b + id +WHEN NOT MATCHED THEN + INSERT VALUES (id, -1); +MERGE INTO fs_target t +USING generate_series(1,100,2) AS id +ON t.a = id +WHEN MATCHED THEN + UPDATE SET b = b + id, c = 'updated '|| id.*::text +WHEN NOT MATCHED THEN + INSERT VALUES (id, -1, 'inserted ' || id.*::text); +SELECT count(*) FROM fs_target; + count +--------------------------------------------------------------------- + 100 +(1 row) + +DROP TABLE fs_target; +-- SERIALIZABLE test +-- handled in isolation tests +-- Inheritance-based partitioning +SET citus.use_citus_managed_tables to false; +CREATE TABLE measurement ( + city_id int not null, + logdate date not null, + peaktemp int, + unitsales int +) WITH (autovacuum_enabled=off); +CREATE TABLE measurement_y2006m02 ( + CHECK ( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' ) +) INHERITS (measurement) WITH (autovacuum_enabled=off); +CREATE TABLE measurement_y2006m03 ( + CHECK ( logdate >= DATE '2006-03-01' AND logdate < DATE '2006-04-01' ) +) INHERITS (measurement) WITH (autovacuum_enabled=off); +CREATE TABLE measurement_y2007m01 ( + filler text, + peaktemp int, + logdate date not null, + city_id int not null, + unitsales int + CHECK ( logdate >= DATE '2007-01-01' AND logdate < DATE '2007-02-01') +) WITH (autovacuum_enabled=off); +ALTER TABLE measurement_y2007m01 DROP COLUMN filler; +ALTER TABLE measurement_y2007m01 INHERIT measurement; +SET citus.use_citus_managed_tables to true; +CREATE OR REPLACE FUNCTION measurement_insert_trigger() +RETURNS TRIGGER AS $$ +BEGIN + IF ( NEW.logdate >= DATE '2006-02-01' AND + NEW.logdate < DATE '2006-03-01' ) THEN + INSERT INTO measurement_y2006m02 VALUES (NEW.*); + ELSIF ( NEW.logdate >= DATE '2006-03-01' AND + NEW.logdate < DATE '2006-04-01' ) THEN + INSERT INTO measurement_y2006m03 VALUES (NEW.*); + ELSIF ( NEW.logdate >= DATE '2007-01-01' AND + NEW.logdate < DATE '2007-02-01' ) THEN + INSERT INTO measurement_y2007m01 (city_id, logdate, peaktemp, unitsales) + VALUES (NEW.*); + ELSE + RAISE EXCEPTION 'Date out of range. Fix the measurement_insert_trigger() function!'; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql ; +CREATE TRIGGER insert_measurement_trigger + BEFORE INSERT ON measurement + FOR EACH ROW EXECUTE PROCEDURE measurement_insert_trigger(); +INSERT INTO measurement VALUES (1, '2006-02-10', 35, 10); +INSERT INTO measurement VALUES (1, '2006-02-16', 45, 20); +INSERT INTO measurement VALUES (1, '2006-03-17', 25, 10); +INSERT INTO measurement VALUES (1, '2006-03-27', 15, 40); +INSERT INTO measurement VALUES (1, '2007-01-15', 10, 10); +INSERT INTO measurement VALUES (1, '2007-01-17', 10, 10); +SELECT tableoid::regclass, * FROM measurement ORDER BY city_id, logdate; + tableoid | city_id | logdate | peaktemp | unitsales +--------------------------------------------------------------------- + measurement_y2006m02 | 1 | 02-10-2006 | 35 | 10 + measurement_y2006m02 | 1 | 02-16-2006 | 45 | 20 + measurement_y2006m03 | 1 | 03-17-2006 | 25 | 10 + measurement_y2006m03 | 1 | 03-27-2006 | 15 | 40 + measurement_y2007m01 | 1 | 01-15-2007 | 10 | 10 + measurement_y2007m01 | 1 | 01-17-2007 | 10 | 10 +(6 rows) + +CREATE TABLE new_measurement (LIKE measurement) WITH (autovacuum_enabled=off); +INSERT INTO new_measurement VALUES (1, '2006-03-01', 20, 10); +INSERT INTO new_measurement VALUES (1, '2006-02-16', 50, 10); +INSERT INTO new_measurement VALUES (2, '2006-02-10', 20, 20); +INSERT INTO new_measurement VALUES (1, '2006-03-27', NULL, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-17', NULL, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-15', 5, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-16', 10, 10); +SET client_min_messages TO DEBUG1; +MERGE into measurement m + USING new_measurement nm ON + (m.city_id = nm.city_id and m.logdate=nm.logdate) +WHEN MATCHED AND nm.peaktemp IS NULL THEN DELETE +WHEN MATCHED THEN UPDATE + SET peaktemp = greatest(m.peaktemp, nm.peaktemp), + unitsales = m.unitsales + coalesce(nm.unitsales, 0) +WHEN NOT MATCHED THEN INSERT + (city_id, logdate, peaktemp, unitsales) + VALUES (city_id, logdate, peaktemp, unitsales); +DEBUG: +RESET client_min_messages; +SELECT tableoid::regclass, * FROM measurement ORDER BY city_id, logdate; + tableoid | city_id | logdate | peaktemp | unitsales +--------------------------------------------------------------------- + measurement_y2006m02 | 1 | 02-10-2006 | 35 | 10 + measurement_y2006m02 | 1 | 02-16-2006 | 50 | 30 + measurement_y2006m03 | 1 | 03-01-2006 | 20 | 10 + measurement_y2006m03 | 1 | 03-17-2006 | 25 | 10 + measurement_y2007m01 | 1 | 01-15-2007 | 10 | 10 + measurement_y2007m01 | 1 | 01-16-2007 | 10 | 10 + measurement_y2006m02 | 2 | 02-10-2006 | 20 | 20 +(7 rows) + +DROP TABLE measurement, new_measurement CASCADE; +NOTICE: drop cascades to 3 other objects +DETAIL: drop cascades to table measurement_y2006m02 +drop cascades to table measurement_y2006m03 +drop cascades to table measurement_y2007m01 +DROP FUNCTION measurement_insert_trigger(); +-- prepare +RESET SESSION AUTHORIZATION; +SET citus.use_citus_managed_tables to false; +REVOKE ALL ON SCHEMA pgmerge_schema FROM regress_merge_privs; +REVOKE ALL ON SCHEMA pgmerge_schema FROM regress_merge_no_privs; +DROP SCHEMA pgmerge_schema CASCADE; +NOTICE: drop cascades to 9 other objects +DETAIL: drop cascades to table target_4001000 +drop cascades to table target +drop cascades to table source_4001001 +drop cascades to table source +drop cascades to table target2_4001002 +drop cascades to table target2 +drop cascades to table source2_4001003 +drop cascades to table source2 +drop cascades to function merge_trigfunc() +DROP USER regress_merge_privs; +DROP USER regress_merge_no_privs; +SELECT 1 FROM master_remove_node('localhost', :master_port); + ?column? +--------------------------------------------------------------------- + 1 +(1 row) + diff --git a/src/test/regress/expected/pgmerge_0.out b/src/test/regress/expected/pgmerge_0.out new file mode 100644 index 000000000..a7e3fbf20 --- /dev/null +++ b/src/test/regress/expected/pgmerge_0.out @@ -0,0 +1,6 @@ +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int >= 15 AS server_version_ge_15 +\gset +\if :server_version_ge_15 +\else +\q diff --git a/src/test/regress/multi_schedule b/src/test/regress/multi_schedule index 0c788ccf7..028d994eb 100644 --- a/src/test/regress/multi_schedule +++ b/src/test/regress/multi_schedule @@ -104,6 +104,10 @@ test: background_task_queue_monitor # Causal clock test test: clock +# MERGE tests +test: merge +test: pgmerge + # --------- # test that no tests leaked intermediate results. This should always be last # --------- diff --git a/src/test/regress/sql/merge.sql b/src/test/regress/sql/merge.sql new file mode 100644 index 000000000..c266b5333 --- /dev/null +++ b/src/test/regress/sql/merge.sql @@ -0,0 +1,1002 @@ +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int >= 15 AS server_version_ge_15 +\gset +\if :server_version_ge_15 +\else +\q +\endif + +-- MERGE command performs a join from data_source to target_table_name +DROP SCHEMA IF EXISTS merge_schema CASCADE; +--MERGE INTO target +--USING source +--WHEN NOT MATCHED +--WHEN MATCHED AND +--WHEN MATCHED + +CREATE SCHEMA merge_schema; +SET search_path TO merge_schema; +SET citus.shard_count TO 4; +SET citus.next_shard_id TO 4000000; +SET citus.explain_all_tasks to true; +SELECT 1 FROM master_add_node('localhost', :master_port, groupid => 0); + +CREATE TABLE source +( + order_id INT, + customer_id INT, + order_center VARCHAR, + order_time timestamp +); + +CREATE TABLE target +( + customer_id INT, + last_order_id INT, + order_center VARCHAR, + order_count INT, + last_order timestamp +); + +CREATE FUNCTION insert_data() RETURNS VOID AS $$ + +INSERT INTO source (order_id, customer_id, order_center, order_time) + VALUES (101, 30000, 'WX', '2022-01-01 00:00:00'); -- Do not match +INSERT INTO source (order_id, customer_id, order_center, order_time) + VALUES (102, 30001, 'CX', '2022-01-01 00:00:00'); -- Do not match + +INSERT INTO source (order_id, customer_id, order_center, order_time) + VALUES (103, 30002, 'AX', '2022-01-01 00:00:00'); -- Does match +INSERT INTO source (order_id, customer_id, order_center, order_time) + VALUES (104, 30003, 'JX','2022-01-01 00:00:00' ); -- Does match +INSERT INTO source (order_id, customer_id, order_center, order_time) + VALUES (105, 30004, 'JX','2022-01-01 00:00:00' ); -- Does match + +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (40000, 097, 'MK', -1, '2019-09-15 08:13:00'); +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (40001, 098, 'NU', -1, '2020-07-12 01:05:00'); +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (40002, 100, 'DS', -1, '2022-05-21 04:12:00'); +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (30002, 103, 'AX', -1, '2021-01-17 19:53:00'); -- Matches the source +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (30003, 099, 'JX', -1, '2020-09-11 03:23:00'); -- Matches the source +INSERT INTO target (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (30004, 099, 'XX', -1, '2020-09-11 03:23:00'); -- Matches the source id AND the condition. +$$ + +LANGUAGE SQL; + +SELECT insert_data(); + +SELECT 'Testing PG tables'; + +MERGE INTO target t + USING source s + ON (t.customer_id = s.customer_id) + + WHEN MATCHED AND t.order_center = 'XX' THEN + DELETE + + WHEN MATCHED THEN + UPDATE SET -- Existing customer, update the order count and last_order_id + order_count = t.order_count + 1, + last_order_id = s.order_id + + WHEN NOT MATCHED THEN -- New entry, record it. + INSERT (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (customer_id, s.order_id, s.order_center, 123, s.order_time); + +-- Our gold result to compare against +SELECT * INTO pg_result FROM target ORDER BY 1 ; + +-- Clean the slate +TRUNCATE source; +TRUNCATE target; +SELECT insert_data(); + +-- Test with both target and source as Citus local + +SELECT 'local - local'; +SELECT citus_add_local_table_to_metadata('target'); +SELECT citus_add_local_table_to_metadata('source'); + +MERGE INTO target t + USING source s + ON (t.customer_id = s.customer_id) + + WHEN MATCHED AND t.order_center = 'XX' THEN + DELETE + + WHEN MATCHED THEN + UPDATE SET -- Existing customer, update the order count and last_order_id + order_count = t.order_count + 1, + last_order_id = s.order_id + + WHEN NOT MATCHED THEN -- New entry, record it. + INSERT (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (customer_id, s.order_id, s.order_center, 123, s.order_time); + +SELECT * INTO local_local FROM target ORDER BY 1 ; + +-- Should be equal +SELECT c.*, p.* +FROM local_local c, pg_result p +WHERE c.customer_id = p.customer_id +ORDER BY 1,2; + +-- Must return zero rows +SELECT * +FROM pg_result p +WHERE NOT EXISTS (SELECT FROM local_local c WHERE c.customer_id = p.customer_id); + + +SELECT 'Testing Dist - Dist'; + +-- Clean the slate +TRUNCATE source; +TRUNCATE target; +SELECT insert_data(); +SELECT undistribute_table('target'); +SELECT undistribute_table('source'); +SELECT create_distributed_table('target', 'customer_id'); +SELECT create_distributed_table('source', 'customer_id'); + +MERGE INTO target t + USING source s + ON (t.customer_id = s.customer_id) + + WHEN MATCHED AND t.order_center = 'XX' THEN + DELETE + + WHEN MATCHED THEN + UPDATE SET -- Existing customer, update the order count and last_order_id + order_count = t.order_count + 1, + last_order_id = s.order_id + + WHEN NOT MATCHED THEN -- New entry, record it. + INSERT (customer_id, last_order_id, order_center, order_count, last_order) + VALUES (customer_id, s.order_id, s.order_center, 123, s.order_time); + +-- +-- Test MERGE with CTE as source +-- +CREATE TABLE t1(id int, val int); +CREATE TABLE s1(id int, val int); + +CREATE FUNCTION load() RETURNS VOID AS $$ + +INSERT INTO s1 VALUES(1, 0); -- Matches DELETE clause +INSERT INTO s1 VALUES(2, 1); -- Matches UPDATE clause +INSERT INTO s1 VALUES(3, 1); -- No Match INSERT clause +INSERT INTO s1 VALUES(4, 1); -- No Match INSERT clause +INSERT INTO s1 VALUES(6, 1); -- No Match INSERT clause + +INSERT INTO t1 VALUES(1, 0); -- Will be deleted +INSERT INTO t1 VALUES(2, 0); -- Will be updated +INSERT INTO t1 VALUES(5, 0); -- Will be intact + +$$ +LANGUAGE SQL; + +SELECT 'Testing PG tables'; + +SELECT load(); + +WITH pg_res AS ( + SELECT * FROM s1 +) +MERGE INTO t1 + USING pg_res ON (pg_res.id = t1.id) + + WHEN MATCHED AND pg_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (pg_res.id, pg_res.val); + +-- Two rows with id 2 and val incremented, id 3, and id 1 is deleted +SELECT * FROM t1 order by id; +SELECT * INTO merge_result FROM t1 order by id; + +-- Test Citus local tables + +TRUNCATE t1; +TRUNCATE s1; +SELECT load(); + +SELECT citus_add_local_table_to_metadata('t1'); +SELECT citus_add_local_table_to_metadata('s1'); + +WITH s1_res AS ( + SELECT * FROM s1 +) +MERGE INTO t1 + USING s1_res ON (s1_res.id = t1.id) + + WHEN MATCHED AND s1_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1_res.id, s1_res.val); + +-- Two rows with id 2 and val incremented, id 3, and id 1 is deleted +SELECT * FROM t1 order by id; + +-- Should be empty +SELECT * +FROM merge_result p +WHERE NOT EXISTS (SELECT 1 FROM t1 c WHERE c.id = p.id AND c.val = p.val); + + +SELECT 'Testing dist - dist'; + +SELECT undistribute_table('t1'); +SELECT undistribute_table('s1'); +TRUNCATE t1; +TRUNCATE s1; +SELECT load(); +SELECT create_distributed_table('t1', 'id'); +SELECT create_distributed_table('s1', 'id'); + + +WITH s1_res AS ( + SELECT * FROM s1 +) +MERGE INTO t1 + USING s1_res ON (s1_res.id = t1.id) + + WHEN MATCHED AND s1_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1_res.id, s1_res.val); + +-- +-- Test with multiple join conditions +-- +CREATE TABLE t2(id int, val int, src text); +CREATE TABLE s2(id int, val int, src text); + +CREATE OR REPLACE FUNCTION insert_data() RETURNS VOID AS $$ +INSERT INTO t2 VALUES(1, 0, 'target'); +INSERT INTO t2 VALUES(2, 0, 'target'); +INSERT INTO t2 VALUES(3, 1, 'match'); +INSERT INTO t2 VALUES(4, 0, 'match'); + +INSERT INTO s2 VALUES(2, 0, 'source'); -- No match insert +INSERT INTO s2 VALUES(4, 0, 'match'); -- Match delete +INSERT INTO s2 VALUES(3, 10, 'match'); -- Match update + +$$ +LANGUAGE SQL; + +SELECT 'Testing PG tables'; +SELECT insert_data(); + +MERGE INTO t2 +USING s2 +ON t2.id = s2.id AND t2.src = s2.src + WHEN MATCHED AND t2.val = 1 THEN + UPDATE SET val = s2.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s2.id, s2.val, s2.src); + +SELECT * FROM t2 ORDER BY 1; +SELECT * INTO pg_t2 FROM t2; + +SELECT 'Testing Citus local tables'; +TRUNCATE t2; +TRUNCATE s2; +SELECT insert_data(); +SELECT citus_add_local_table_to_metadata('t2'); +SELECT citus_add_local_table_to_metadata('s2'); + +MERGE INTO t2 +USING s2 +ON t2.id = s2.id AND t2.src = s2.src + WHEN MATCHED AND t2.val = 1 THEN + UPDATE SET val = s2.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s2.id, s2.val, s2.src); + +SELECT * FROM t2 ORDER BY 1; + +-- Should be empty +SELECT * +FROM pg_t2 p +WHERE NOT EXISTS (SELECT 1 FROM t2 c WHERE c.id = p.id AND c.val = p.val AND c.src = p.src); + +SELECT 'Testing Dist - Dist'; +-- Clean the slate +TRUNCATE t2; +TRUNCATE s2; +SELECT insert_data(); +SELECT undistribute_table('t2'); +SELECT undistribute_table('s2'); +SELECT create_distributed_table('t2', 'id'); +SELECT create_distributed_table('s2', 'id'); + +MERGE INTO t2 +USING s2 +ON t2.id = s2.id AND t2.src = s2.src + WHEN MATCHED AND t2.val = 1 THEN + UPDATE SET val = s2.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s2.id, s2.val, s2.src); + +-- +-- With sub-query as the MERGE source +-- +TRUNCATE t2; +TRUNCATE s2; +SELECT undistribute_table('t2'); +SELECT undistribute_table('s2'); +SELECT citus_add_local_table_to_metadata('t2'); +SELECT citus_add_local_table_to_metadata('s2'); +SELECT insert_data(); + +MERGE INTO t2 t +USING (SELECT * FROM s2) s +ON t.id = s.id AND t.src = s.src + WHEN MATCHED AND t.val = 1 THEN + UPDATE SET val = s.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s.id, s.val, s.src); + +SELECT * FROM t2 ORDER BY 1; +SELECT * INTO dist_res FROM t2 ORDER BY 1; + +-- Should be equal +SELECT c.*, p.* +FROM t2 c, pg_t2 p +WHERE c.id = p.id AND c.src = p.src +ORDER BY 1,2; + +-- Should be empty +SELECT * +FROM pg_t2 p +WHERE NOT EXISTS (SELECT 1 FROM t2 c WHERE c.id = p.id AND c.val = p.val AND c.src = p.src); + + +-- +-- Using two source tables +-- +CREATE TABLE t3(id int, val int, src text); +CREATE TABLE s3_1(id int, val int, src text); +CREATE TABLE s3_2(id int, val int, src text); + +CREATE OR REPLACE FUNCTION insert_data() RETURNS VOID AS $$ +INSERT INTO t3 VALUES(1, 0, 'target'); -- Intact +INSERT INTO t3 VALUES(2, 0, 'target'); +INSERT INTO t3 VALUES(3, 0, 'target'); +INSERT INTO t3 VALUES(5, 0, 'target'); -- Intact + +INSERT INTO s3_1 VALUES(2, 0, 'source1'); +INSERT INTO s3_1 VALUES(3, 0, 'source1'); +INSERT INTO s3_1 VALUES(4, 0, 'source1'); + +INSERT INTO s3_2 VALUES(2, 1, 'source2'); -- Match update +INSERT INTO s3_2 VALUES(3, 0, 'source2'); -- Match delete +INSERT INTO s3_2 VALUES(4, 0, 'source2'); -- No match insert +INSERT INTO s3_2 VALUES(6, 0, 'source2'); -- Will miss the source-subquery-join +$$ +LANGUAGE SQL; + +SELECT insert_data(); + +MERGE INTO t3 + USING (SELECT s3_1.id, s3_2.val, s3_2.src FROM s3_1, s3_2 WHERE s3_1.id = s3_2.id) sub + ON (t3.id = sub.id) + WHEN MATCHED AND sub.val = 1 THEN + UPDATE SET val = t3.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (sub.id, sub.val, sub.src); + +-- Joining on columns inside the sub-query +MERGE INTO t3 + USING (SELECT s3_1.id, s3_2.val, s3_2.src FROM s3_1, s3_2 WHERE s3_1.id = s3_2.id) sub + ON (t3.id = sub.id) + WHEN MATCHED AND sub.val = 1 THEN + UPDATE SET val = t3.val + 1 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (sub.id, sub.val, sub.src); + +-- Constant Join condition +WITH s3_res AS ( + SELECT * FROM s3_1 +) +MERGE INTO t3 + USING s3_res ON (FALSE) + WHEN MATCHED AND s3_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t3.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s3_res.id, s3_res.val, s3_res.src); + +SELECT * FROM t3 ORDER BY 1,3; +SELECT * INTO pg_t3 FROM t3 ORDER BY 1; + +SELECT 'Testing Local - Local'; + +TRUNCATE t3; +TRUNCATE s3_1; +TRUNCATE s3_2; +SELECT citus_add_local_table_to_metadata('t3'); +SELECT citus_add_local_table_to_metadata('s3_1'); +SELECT citus_add_local_table_to_metadata('s3_2'); +SELECT insert_data(); + +MERGE INTO t3 + USING (SELECT s3_1.id, s3_2.val, s3_2.src FROM s3_1, s3_2 WHERE s3_1.id = s3_2.id) sub + ON (t3.id = sub.id) + WHEN MATCHED AND sub.val = 1 THEN + UPDATE SET val = t3.val + 10 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (sub.id, sub.val, sub.src); + +-- Joining on columns inside the sub-query +MERGE INTO t3 + USING (SELECT s3_1.id, s3_2.val, s3_2.src FROM s3_1, s3_2 WHERE s3_1.id = s3_2.id) sub + ON (t3.id = sub.id) + WHEN MATCHED AND sub.val = 1 THEN + UPDATE SET val = t3.val + 1 + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (sub.id, sub.val, sub.src); + +-- Constant Join condition +WITH s3_res AS ( + SELECT * FROM s3_1 +) +MERGE INTO t3 + USING s3_res ON (FALSE) + WHEN MATCHED AND s3_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t3.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val, src) VALUES (s3_res.id, s3_res.val, s3_res.src); + +SELECT * FROM t3 ORDER BY 1,3; +SELECT * INTO local_t3 FROM t3 ORDER BY 1; + +-- Should be equal +SELECT c.*, p.* +FROM t3 c, pg_t3 p +WHERE c.id = p.id +ORDER BY 1,2; + +-- Should be empty +SELECT * +FROM pg_t3 p +WHERE NOT EXISTS (SELECT 1 FROM local_t3 c WHERE c.id = p.id AND c.val = p.val AND c.src = p.src); + +-- +-- Test table functions +-- + +CREATE TABLE tf_target(first_name varchar, last_name varchar, eid text); + +WITH doc as ( +SELECT ' + + foo + bar + 100 + + + moo + bar + 200 + +'::xml as source_xml +) + +MERGE INTO tf_target +USING ( +SELECT decoded.* +FROM doc, xmltable( + '//people/person' + passing source_xml + columns + first_name text, + last_name text, + eid text) as decoded) as tf_source +ON tf_source.first_name = tf_target.first_name +WHEN NOT MATCHED THEN +INSERT VALUES (tf_source.first_name, tf_source.last_name, tf_source.eid); + +-- Our gold result to compare against +SELECT * INTO tf_result FROM tf_target ORDER BY 1 ; + +TRUNCATE tf_target; +SELECT citus_add_local_table_to_metadata('tf_target'); + +WITH doc as ( +SELECT ' + + foo + bar + 100 + + + moo + bar + 200 + +'::xml as source_xml +) + +MERGE INTO tf_target +USING ( +SELECT decoded.* +FROM doc, xmltable( + '//people/person' + passing source_xml + columns + first_name text, + last_name text, + eid text) as decoded) as tf_source +ON tf_source.first_name = tf_target.first_name +WHEN NOT MATCHED THEN +INSERT VALUES (tf_source.first_name, tf_source.last_name, tf_source.eid); + +SELECT * INTO tf_local FROM tf_target ORDER BY 1 ; + +-- Should be equal +SELECT c.*, p.* +FROM tf_local c, tf_result p +WHERE c.eid = p.eid +ORDER BY 1,2; + +-- Must return zero rows +SELECT * +FROM tf_result p +WHERE NOT EXISTS (SELECT FROM tf_local c WHERE c.eid = p.eid); + +-- +-- Test VALUES RTE type +-- +CREATE TABLE vl_target(id int, value varchar); +INSERT INTO vl_target VALUES(100, 'target'); + +MERGE INTO vl_target +USING (SELECT * + FROM (VALUES(100, 'source1'), (200, 'source2')) AS vl (ID, value)) as vl_source +ON vl_source.ID = vl_target.ID +WHEN MATCHED THEN +UPDATE SET value = vl_source.value, id = vl_target.id + 1 +WHEN NOT MATCHED THEN +INSERT VALUES(vl_source.ID, vl_source.value); + +-- Our gold result to compare against +SELECT * INTO vl_result FROM vl_target ORDER BY 1 ; + +-- Clean the slate +TRUNCATE vl_target; +INSERT INTO vl_target VALUES(100, 'target'); +SELECT citus_add_local_table_to_metadata('vl_target'); + +SET client_min_messages TO DEBUG1; +MERGE INTO vl_target +USING (SELECT * + FROM (VALUES(100, 'source1'), (200, 'source2')) AS vl (ID, value)) as vl_source +ON vl_source.ID = vl_target.ID +WHEN MATCHED THEN +UPDATE SET value = vl_source.value, id = vl_target.id + 1 +WHEN NOT MATCHED THEN +INSERT VALUES(vl_source.ID, vl_source.value); +RESET client_min_messages; + +SELECT * INTO vl_local FROM vl_target ORDER BY 1 ; + +-- Should be equal +SELECT c.*, p.* +FROM vl_local c, vl_result p +WHERE c.id = p.id +ORDER BY 1,2; + +-- Must return zero rows +SELECT * +FROM vl_result p +WHERE NOT EXISTS (SELECT FROM vl_local c WHERE c.id = p.id); + + +-- +-- Test function scan +-- +CREATE FUNCTION f_immutable(i integer) RETURNS INTEGER AS +$$ BEGIN RETURN i; END; $$ LANGUAGE PLPGSQL IMMUTABLE; + +CREATE TABLE rs_target(id int); + +MERGE INTO rs_target +USING (SELECT * FROM f_immutable(99) id WHERE id in (SELECT 99)) AS rs_source +ON rs_source.id = rs_target.id +WHEN MATCHED THEN +DO NOTHING +WHEN NOT MATCHED THEN +INSERT VALUES(rs_source.id); + +-- Our gold result to compare against +SELECT * INTO rs_result FROM rs_target ORDER BY 1 ; + +-- Clean the slate +TRUNCATE rs_target; +SELECT citus_add_local_table_to_metadata('rs_target'); + +SET client_min_messages TO DEBUG1; +MERGE INTO rs_target +USING (SELECT * FROM f_immutable(99) id WHERE id in (SELECT 99)) AS rs_source +ON rs_source.id = rs_target.id +WHEN MATCHED THEN +DO NOTHING +WHEN NOT MATCHED THEN +INSERT VALUES(rs_source.id); +RESET client_min_messages; + +SELECT * INTO rs_local FROM rs_target ORDER BY 1 ; + +-- Should be equal +SELECT c.*, p.* +FROM rs_local c, rs_result p +WHERE c.id = p.id +ORDER BY 1,2; + +-- Must return zero rows +SELECT * +FROM rs_result p +WHERE NOT EXISTS (SELECT FROM rs_local c WHERE c.id = p.id); + +-- +-- Test Materialized view +-- + +CREATE TABLE mv_target(id int, val varchar); +CREATE TABLE mv_source_table(id int, val varchar); + +INSERT INTO mv_source_table VALUES(1, 'src1'); +INSERT INTO mv_source_table VALUES(2, 'src2'); + +CREATE MATERIALIZED VIEW mv_source AS +SELECT * FROM mv_source_table; + +MERGE INTO mv_target +USING mv_source +ON mv_source.id = mv_target.id +WHEN MATCHED THEN + DO NOTHING +WHEN NOT MATCHED THEN + INSERT VALUES(mv_source.id, mv_source.val); + +-- Our gold result to compare against +SELECT * INTO mv_result FROM mv_target ORDER BY 1 ; + +-- Clean the slate +TRUNCATE mv_target; +SELECT citus_add_local_table_to_metadata('mv_target'); +SELECT citus_add_local_table_to_metadata('mv_source_table'); +DROP MATERIALIZED VIEW mv_source; +CREATE MATERIALIZED VIEW mv_source AS +SELECT * FROM mv_source_table; + +MERGE INTO mv_target +USING mv_source +ON mv_source.id = mv_target.id +WHEN MATCHED THEN + DO NOTHING +WHEN NOT MATCHED THEN + INSERT VALUES(mv_source.id, mv_source.val); + +SELECT * INTO mv_local FROM mv_target ORDER BY 1 ; + +-- Should be equal +SELECT c.*, p.* +FROM mv_local c, mv_result p +WHERE c.id = p.id +ORDER BY 1,2; + +-- Must return zero rows +SELECT * +FROM mv_result p +WHERE NOT EXISTS (SELECT FROM mv_local c WHERE c.id = p.id); + +-- +-- Distributed table as source (indirect) +-- +CREATE TABLE dist_table(id int, source varchar); +INSERT INTO dist_table VALUES(2, 'dist_table'); +INSERT INTO dist_table VALUES(3, 'dist_table'); +INSERT INTO dist_table VALUES(100, 'dist_table'); + +CREATE FUNCTION f_dist() returns SETOF RECORD AS +$$ +BEGIN +RETURN QUERY SELECT id, source FROM dist_table; +END; +$$ language plpgsql volatile; + +CREATE TABLE fn_target(id int, data varchar); + +MERGE INTO fn_target +USING (SELECT * FROM f_dist() f(id integer, source varchar)) as fn_source +ON fn_source.id = fn_target.id +WHEN MATCHED THEN +DO NOTHING +WHEN NOT MATCHED THEN +INSERT VALUES(fn_source.id, fn_source.source); + +-- Our gold result to compare against +SELECT * INTO fn_result FROM fn_target ORDER BY 1 ; + +-- Clean the slate +TRUNCATE TABLE fn_target; +SELECT citus_add_local_table_to_metadata('fn_target'); +SELECT create_distributed_table('dist_table', 'id'); + +SET client_min_messages TO DEBUG1; +MERGE INTO fn_target +USING (SELECT * FROM f_dist() f(id integer, source varchar)) as fn_source +ON fn_source.id = fn_target.id +WHEN MATCHED THEN +DO NOTHING +WHEN NOT MATCHED THEN +INSERT VALUES(fn_source.id, fn_source.source); +RESET client_min_messages; + +SELECT * INTO fn_local FROM fn_target ORDER BY 1 ; + +-- Should be equal +SELECT c.*, p.* +FROM fn_local c, fn_result p +WHERE c.id = p.id +ORDER BY 1,2; + +-- Must return zero rows +SELECT * +FROM fn_result p +WHERE NOT EXISTS (SELECT FROM fn_local c WHERE c.id = p.id); + +-- +-- Foreign tables +-- +CREATE TABLE ft_target (id integer NOT NULL, user_val varchar); +CREATE TABLE ft_source (id integer NOT NULL, user_val varchar); +SELECT citus_add_local_table_to_metadata('ft_source'); + +INSERT INTO ft_target VALUES (1, 'target'); +INSERT INTO ft_target VALUES (2, 'target'); + +INSERT INTO ft_source VALUES (2, 'source'); +INSERT INTO ft_source VALUES (3, 'source'); + +SELECT * FROM ft_target; + +CREATE EXTENSION postgres_fdw; + +CREATE SERVER foreign_server + FOREIGN DATA WRAPPER postgres_fdw + OPTIONS (host 'localhost', port :'master_port', dbname 'regression'); + +CREATE USER MAPPING FOR CURRENT_USER + SERVER foreign_server + OPTIONS (user 'postgres'); + +CREATE FOREIGN TABLE foreign_table ( + id integer NOT NULL, + user_val text +) + SERVER foreign_server + OPTIONS (schema_name 'merge_schema', table_name 'ft_source'); + +SELECT citus_add_local_table_to_metadata('foreign_table'); + +-- Foreign table as source +SET client_min_messages TO DEBUG1; +MERGE INTO ft_target + USING foreign_table ON (foreign_table.id = ft_target.id) + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, user_val) VALUES (foreign_table.id, foreign_table.user_val); +RESET client_min_messages; + +SELECT * FROM ft_target; + +-- +-- Error and Unsupported scenarios +-- + +-- Foreign table as target +MERGE INTO foreign_table + USING ft_target ON (foreign_table.id = ft_target.id) + WHEN MATCHED THEN + DELETE + WHEN NOT MATCHED THEN + INSERT (id, user_val) VALUES (ft_target.id, ft_target.user_val); + +TRUNCATE t1; +TRUNCATE s1; +SELECT undistribute_table('t1'); +SELECT undistribute_table('s1'); +SELECT citus_add_local_table_to_metadata('t1'); +SELECT create_distributed_table('s1', 'id'); +SELECT load(); + +-- Combination of Citus local table and distributed table +MERGE INTO t1 + USING s1 ON (s1.id = t1.val) -- val is not a distribution column + WHEN MATCHED AND s1.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1.id, s1.val); + +-- Joining on partition columns with sub-query +MERGE INTO t1 + USING (SELECT * FROM s1) sub ON (sub.val = t1.id) -- sub.val is not a distribution column + WHEN MATCHED AND sub.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (sub.id, sub.val); + +-- Joining on partition columns with CTE +WITH s1_res AS ( + SELECT * FROM s1 +) +MERGE INTO t1 + USING s1_res ON (s1_res.val = t1.id) + WHEN MATCHED AND s1_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1_res.id, s1_res.val); + +-- Constant Join condition +WITH s1_res AS ( + SELECT * FROM s1 +) +MERGE INTO t1 + USING s1_res ON (TRUE) + WHEN MATCHED AND s1_res.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1_res.id, s1_res.val); + +-- With a single WHEN clause, which causes a non-left join +WITH s1_res AS ( + SELECT * FROM s1 + ) + MERGE INTO t1 USING s1_res ON (s1_res.id = t1.val) + WHEN MATCHED THEN DELETE + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1_res.id, s1_res.val); + + +-- +-- Reference tables +-- +SELECT undistribute_table('t1'); +SELECT undistribute_table('s1'); +SELECT create_reference_table('t1'); +SELECT create_reference_table('s1'); + +MERGE INTO t1 + USING s1 ON (s1.id = t1.id) + + WHEN MATCHED AND s1.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1.id, s1.val); + + +-- +-- Postgres + Citus-Distributed table +-- +SELECT undistribute_table('t1'); +SELECT undistribute_table('s1'); +SELECT create_distributed_table('t1', 'id'); + +MERGE INTO t1 + USING s1 ON (s1.id = t1.id) + WHEN MATCHED AND s1.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1.id, s1.val); + +MERGE INTO t1 + USING (SELECT * FROM s1) sub ON (sub.id = t1.id) + WHEN MATCHED AND sub.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (sub.id, sub.val); + +CREATE TABLE pg(val int); +SELECT create_distributed_table('s1', 'id'); + +-- Both t1 and s1 are citus distributed tables now, mix Postgres table in sub-query +MERGE INTO t1 + USING (SELECT s1.id, pg.val FROM s1, pg) sub ON (sub.id = t1.id) + WHEN MATCHED AND sub.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (sub.id, sub.val); + +-- Mix Postgres table in CTE +WITH pg_res AS ( + SELECT * FROM pg +) +MERGE INTO t1 + USING (SELECT s1.id, pg_res.val FROM s1, pg_res) sub ON (sub.id = t1.id) + WHEN MATCHED AND sub.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (sub.id, sub.val); + +-- Match more than one source row should fail same as Postgres behavior +SELECT undistribute_table('t1'); +SELECT undistribute_table('s1'); +SELECT citus_add_local_table_to_metadata('t1'); +SELECT citus_add_local_table_to_metadata('s1'); + +INSERT INTO s1 VALUES(1, 1); -- From load(), we already have row with id = 1 + +MERGE INTO t1 + USING s1 ON (s1.id = t1.id) + + WHEN MATCHED AND s1.val = 0 THEN + DELETE + WHEN MATCHED THEN + UPDATE SET val = t1.val + 1 + WHEN NOT MATCHED THEN + INSERT (id, val) VALUES (s1.id, s1.val); + +-- Materialized view as target is not allowed +MERGE INTO mv_source +USING mv_target +ON mv_source.id = mv_target.id +WHEN MATCHED THEN + DO NOTHING +WHEN NOT MATCHED THEN + INSERT VALUES(mv_source.id, mv_source.val); + +DROP SERVER foreign_server CASCADE; +DROP SCHEMA merge_schema CASCADE; +SELECT 1 FROM master_remove_node('localhost', :master_port); diff --git a/src/test/regress/sql/pg15.sql b/src/test/regress/sql/pg15.sql index c334671bc..121b41f86 100644 --- a/src/test/regress/sql/pg15.sql +++ b/src/test/regress/sql/pg15.sql @@ -160,7 +160,7 @@ SELECT undistribute_table('generated_stored_ref'); -- -- In PG15, there is a new command called MERGE --- It is currently not supported for Citus tables +-- It is currently not supported for Citus non-local tables -- Test the behavior with various commands with Citus table types -- Relevant PG Commit: 7103ebb7aae8ab8076b7e85f335ceb8fe799097c -- @@ -943,3 +943,5 @@ SELECT run_command_on_workers($$DROP ACCESS METHOD heap2$$); \set VERBOSITY terse SET client_min_messages TO ERROR; DROP SCHEMA pg15 CASCADE; +DROP ROLE rls_tenant_1; +DROP ROLE rls_tenant_2; diff --git a/src/test/regress/sql/pgmerge.sql b/src/test/regress/sql/pgmerge.sql new file mode 100644 index 000000000..6842f516a --- /dev/null +++ b/src/test/regress/sql/pgmerge.sql @@ -0,0 +1,1367 @@ +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int >= 15 AS server_version_ge_15 +\gset +\if :server_version_ge_15 +\else +\q +\endif + +-- +-- MERGE test from PG community (adapted to Citus by converting all tables to Citus local) +-- +DROP SCHEMA IF EXISTS pgmerge_schema CASCADE; +CREATE SCHEMA pgmerge_schema; +SET search_path TO pgmerge_schema; + +SET citus.use_citus_managed_tables to true; + +\set SHOW_CONTEXT errors + +SET citus.next_shard_id TO 4001000; + +SELECT 1 FROM master_add_node('localhost', :master_port, groupid => 0); + +CREATE USER regress_merge_privs; +CREATE USER regress_merge_no_privs; +DROP TABLE IF EXISTS target; +DROP TABLE IF EXISTS source; +CREATE TABLE target (tid integer, balance integer) + WITH (autovacuum_enabled=off); +CREATE TABLE source (sid integer, delta integer) -- no index + WITH (autovacuum_enabled=off); + +SELECT citus_add_local_table_to_metadata('target'); +SELECT citus_add_local_table_to_metadata('source'); + +INSERT INTO target VALUES (1, 10); +INSERT INTO target VALUES (2, 20); +INSERT INTO target VALUES (3, 30); +SELECT t.ctid is not null as matched, t.*, s.* FROM source s FULL OUTER JOIN target t ON s.sid = t.tid ORDER BY t.tid, s.sid; + +ALTER TABLE target OWNER TO regress_merge_privs; +ALTER TABLE source OWNER TO regress_merge_privs; + +CREATE TABLE target2 (tid integer, balance integer) + WITH (autovacuum_enabled=off); +CREATE TABLE source2 (sid integer, delta integer) + WITH (autovacuum_enabled=off); +SELECT citus_add_local_table_to_metadata('target2'); +SELECT citus_add_local_table_to_metadata('source2'); + + +ALTER TABLE target2 OWNER TO regress_merge_no_privs; +ALTER TABLE source2 OWNER TO regress_merge_no_privs; + +GRANT INSERT ON target TO regress_merge_no_privs; + +GRANT USAGE, CREATE ON SCHEMA pgmerge_schema TO regress_merge_privs; +GRANT USAGE ON SCHEMA pgmerge_schema TO regress_merge_no_privs; +SET SESSION AUTHORIZATION regress_merge_privs; + +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; + +-- +-- Errors +-- +MERGE INTO target t RANDOMWORD +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +-- MATCHED/INSERT error +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + INSERT DEFAULT VALUES; +-- incorrectly specifying INTO target +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT INTO target DEFAULT VALUES; +-- Multiple VALUES clause +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (1,1), (2,2); +-- SELECT query for INSERT +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT SELECT (1, 1); +-- NOT MATCHED/UPDATE +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + UPDATE SET balance = 0; +-- UPDATE tablename +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE target SET balance = 0; +-- source and target names the same +MERGE INTO target +USING target +ON tid = tid +WHEN MATCHED THEN DO NOTHING; +-- used in a CTE +WITH foo AS ( + MERGE INTO target USING source ON (true) + WHEN MATCHED THEN DELETE +) SELECT * FROM foo; +-- used in COPY +COPY ( + MERGE INTO target USING source ON (true) + WHEN MATCHED THEN DELETE +) TO stdout; + +-- unsupported relation types +-- view +CREATE VIEW tv AS SELECT * FROM target; +MERGE INTO tv t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +DROP VIEW tv; + +-- materialized view +CREATE MATERIALIZED VIEW mv AS SELECT * FROM target; +MERGE INTO mv t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +DROP MATERIALIZED VIEW mv; + +-- permissions + +MERGE INTO target +USING source2 +ON target.tid = source2.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; + +GRANT INSERT ON target TO regress_merge_no_privs; +SET SESSION AUTHORIZATION regress_merge_no_privs; + +MERGE INTO target +USING source2 +ON target.tid = source2.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; + +GRANT UPDATE ON target2 TO regress_merge_privs; +SET SESSION AUTHORIZATION regress_merge_privs; + +MERGE INTO target2 +USING source +ON target2.tid = source.sid +WHEN MATCHED THEN + DELETE; + +MERGE INTO target2 +USING source +ON target2.tid = source.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; + +-- check if the target can be accessed from source relation subquery; we should +-- not be able to do so +MERGE INTO target t +USING (SELECT * FROM source WHERE t.tid > sid) s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +-- +-- initial tests +-- +-- zero rows in source has no effect +MERGE INTO target +USING source +ON target.tid = source.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; + +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ROLLBACK; +-- insert some non-matching source rows to work from +INSERT INTO source VALUES (4, 40); +SELECT * FROM source ORDER BY sid; +SELECT * FROM target ORDER BY tid; + +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + DO NOTHING; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- index plans +INSERT INTO target SELECT generate_series(1000,2500), 0; +ALTER TABLE target ADD CONSTRAINT targetidx PRIMARY KEY (tid); +ANALYZE target; + +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); +DELETE FROM target WHERE tid > 100; +ANALYZE target; + +-- insert some matching source rows to work from +INSERT INTO source VALUES (2, 5); +INSERT INTO source VALUES (3, 20); +SELECT * FROM source ORDER BY sid; +SELECT * FROM target ORDER BY tid; + +-- equivalent of an UPDATE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- equivalent of a DELETE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DO NOTHING; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- duplicate source row causes multiple target row update ERROR +INSERT INTO source VALUES (2, 5); +SELECT * FROM source ORDER BY sid; +SELECT * FROM target ORDER BY tid; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +ROLLBACK; + +-- remove duplicate MATCHED data from source data +DELETE FROM source WHERE sid = 2; +INSERT INTO source VALUES (2, 5); +SELECT * FROM source ORDER BY sid; +SELECT * FROM target ORDER BY tid; + +-- duplicate source row on INSERT should fail because of target_pkey +INSERT INTO source VALUES (4, 40); +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- remove duplicate NOT MATCHED data from source data +DELETE FROM source WHERE sid = 4; +INSERT INTO source VALUES (4, 40); +SELECT * FROM source ORDER BY sid; +SELECT * FROM target ORDER BY tid; + +-- remove constraints +alter table target drop CONSTRAINT targetidx; +alter table target alter column tid drop not null; + +-- multiple actions +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, 4) +WHEN MATCHED THEN + UPDATE SET balance = 0; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- should be equivalent +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0 +WHEN NOT MATCHED THEN + INSERT VALUES (4, 4); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- column references +-- do a simple equivalent of an UPDATE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance + s.delta; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- do a simple equivalent of an INSERT SELECT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- and again with duplicate source rows +INSERT INTO source VALUES (5, 50); +INSERT INTO source VALUES (5, 50); + +-- do a simple equivalent of an INSERT SELECT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- removing duplicate source rows +DELETE FROM source WHERE sid = 5; + +-- and again with explicitly identified column list +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- and again with a subtle error: referring to non-existent target row for NOT MATCHED +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (t.tid, s.delta); + +-- and again with a constant ON clause +BEGIN; +MERGE INTO target t +USING source AS s +ON (SELECT true) +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (t.tid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- now the classic UPSERT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance + s.delta +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- unreachable WHEN clause should ERROR +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN /* Terminal WHEN clause for MATCHED */ + DELETE +WHEN MATCHED AND s.delta > 0 THEN + UPDATE SET balance = t.balance - s.delta; +ROLLBACK; + +-- conditional WHEN clause +CREATE TABLE wq_target (tid integer not null, balance integer DEFAULT -1) + WITH (autovacuum_enabled=off); +CREATE TABLE wq_source (balance integer, sid integer) + WITH (autovacuum_enabled=off); + +SELECT citus_add_local_table_to_metadata('wq_target'); +SELECT citus_add_local_table_to_metadata('wq_source'); +INSERT INTO wq_source (sid, balance) VALUES (1, 100); + +BEGIN; +-- try a simple INSERT with default values first +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; +ROLLBACK; + +-- this time with a FALSE condition +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND FALSE THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + +-- this time with an actual condition which returns false +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance <> 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + +BEGIN; +-- and now with a condition which returns true +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; +ROLLBACK; + +-- conditions in the NOT MATCHED clause can only refer to source columns +BEGIN; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND t.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; +ROLLBACK; + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + +-- conditions in MATCHED clause can refer to both source and target +SELECT * FROM wq_source; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND s.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +-- check if AND works +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 AND s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 AND s.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +-- check if OR works +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 OR s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 199 OR s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +-- check source-side whole-row references +BEGIN; +MERGE INTO wq_target t +USING wq_source s ON (t.tid = s.sid) +WHEN matched and t = s or t.tid = s.sid THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; +ROLLBACK; + +-- check if subqueries work in the conditions? +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance > (SELECT max(balance) FROM target) THEN + UPDATE SET balance = t.balance + s.balance; + +-- check if we can access system columns in the conditions +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.xmin = t.xmax THEN + UPDATE SET balance = t.balance + s.balance; + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.tableoid >= 0 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +-- test preventing WHEN conditions from writing to the database +create or replace function merge_when_and_write() returns boolean +language plpgsql as +$$ +BEGIN + INSERT INTO target VALUES (100, 100); + RETURN TRUE; +END; +$$; + +BEGIN; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND (merge_when_and_write()) THEN + UPDATE SET balance = t.balance + s.balance; +ROLLBACK; +drop function merge_when_and_write(); + +DROP TABLE wq_target, wq_source; + +-- test triggers +create or replace function merge_trigfunc () returns trigger +language plpgsql as +$$ +DECLARE + line text; +BEGIN + SELECT INTO line format('%s %s %s trigger%s', + TG_WHEN, TG_OP, TG_LEVEL, CASE + WHEN TG_OP = 'INSERT' AND TG_LEVEL = 'ROW' + THEN format(' row: %s', NEW) + WHEN TG_OP = 'UPDATE' AND TG_LEVEL = 'ROW' + THEN format(' row: %s -> %s', OLD, NEW) + WHEN TG_OP = 'DELETE' AND TG_LEVEL = 'ROW' + THEN format(' row: %s', OLD) + END); + + RAISE NOTICE '%', line; + IF (TG_WHEN = 'BEFORE' AND TG_LEVEL = 'ROW') THEN + IF (TG_OP = 'DELETE') THEN + RETURN OLD; + ELSE + RETURN NEW; + END IF; + ELSE + RETURN NULL; + END IF; +END; +$$; +CREATE TRIGGER merge_bsi BEFORE INSERT ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bsu BEFORE UPDATE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bsd BEFORE DELETE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asi AFTER INSERT ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asu AFTER UPDATE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asd AFTER DELETE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bri BEFORE INSERT ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bru BEFORE UPDATE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_brd BEFORE DELETE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_ari AFTER INSERT ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_aru AFTER UPDATE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_ard AFTER DELETE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); + +-- now the classic UPSERT, with a DELETE +BEGIN; +UPDATE target SET balance = 0 WHERE tid = 3; +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED AND t.balance > s.delta THEN + UPDATE SET balance = t.balance - s.delta +WHEN MATCHED THEN + DELETE +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- Test behavior of triggers that turn UPDATE/DELETE into no-ops +create or replace function skip_merge_op() returns trigger +language plpgsql as +$$ +BEGIN + RETURN NULL; +END; +$$; + +SELECT * FROM target full outer join source on (sid = tid); +create trigger merge_skip BEFORE INSERT OR UPDATE or DELETE + ON target FOR EACH ROW EXECUTE FUNCTION skip_merge_op(); +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED AND s.sid = 3 THEN UPDATE SET balance = t.balance + s.delta +WHEN MATCHED THEN DELETE +WHEN NOT MATCHED THEN INSERT VALUES (sid, delta); +SELECT * FROM target FULL OUTER JOIN source ON (sid = tid); +DROP TRIGGER merge_skip ON target; +DROP FUNCTION skip_merge_op(); + +-- test from PL/pgSQL +-- make sure MERGE INTO isn't interpreted to mean returning variables like SELECT INTO +BEGIN; +DO LANGUAGE plpgsql $$ +BEGIN +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED AND t.balance > s.delta THEN + UPDATE SET balance = t.balance - s.delta; +END; +$$; +ROLLBACK; + +--source constants +BEGIN; +MERGE INTO target t +USING (SELECT 9 AS sid, 57 AS delta) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +--source query +BEGIN; +MERGE INTO target t +USING (SELECT sid, delta FROM source WHERE delta > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING (SELECT sid, delta as newname FROM source WHERE delta > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.newname); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +--self-merge +BEGIN; +MERGE INTO target t1 +USING target t2 +ON t1.tid = t2.tid +WHEN MATCHED THEN + UPDATE SET balance = t1.balance + t2.balance +WHEN NOT MATCHED THEN + INSERT VALUES (t2.tid, t2.balance); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING (SELECT tid as sid, balance as delta FROM target WHERE balance > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING +(SELECT sid, max(delta) AS delta + FROM source + GROUP BY sid + HAVING count(*) = 1 + ORDER BY sid ASC) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- plpgsql parameters and results +BEGIN; +CREATE FUNCTION merge_func (p_id integer, p_bal integer) +RETURNS INTEGER +LANGUAGE plpgsql +AS $$ +DECLARE + result integer; +BEGIN +MERGE INTO target t +USING (SELECT p_id AS sid) AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance - p_bal; +IF FOUND THEN + GET DIAGNOSTICS result := ROW_COUNT; +END IF; +RETURN result; +END; +$$; +SELECT merge_func(3, 4); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- PREPARE +BEGIN; +prepare foom as merge into target t using (select 1 as sid) s on (t.tid = s.sid) when matched then update set balance = 1; +execute foom; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +PREPARE foom2 (integer, integer) AS +MERGE INTO target t +USING (SELECT 1) s +ON t.tid = $1 +WHEN MATCHED THEN +UPDATE SET balance = $2; +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +execute foom2 (1, 1); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- subqueries in source relation + +CREATE TABLE sq_target (tid integer NOT NULL, balance integer) + WITH (autovacuum_enabled=off); +CREATE TABLE sq_source (delta integer, sid integer, balance integer DEFAULT 0) + WITH (autovacuum_enabled=off); + +SELECT citus_add_local_table_to_metadata('sq_target'); +SELECT citus_add_local_table_to_metadata('sq_source'); + +INSERT INTO sq_target(tid, balance) VALUES (1,100), (2,200), (3,300); +INSERT INTO sq_source(sid, delta) VALUES (1,10), (2,20), (4,40); + +BEGIN; +MERGE INTO sq_target t +USING (SELECT * FROM sq_source) s +ON tid = sid +WHEN MATCHED AND t.balance > delta THEN + UPDATE SET balance = t.balance + delta; +SELECT * FROM sq_target; +ROLLBACK; + +-- try a view +CREATE VIEW v AS SELECT * FROM sq_source WHERE sid < 2; + +BEGIN; +MERGE INTO sq_target +USING v +ON tid = sid +WHEN MATCHED THEN + UPDATE SET balance = v.balance + delta; +SELECT * FROM sq_target; +ROLLBACK; + +-- ambiguous reference to a column +BEGIN; +MERGE INTO sq_target +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +ROLLBACK; + +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +SELECT * FROM sq_target; +ROLLBACK; + +-- CTEs +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +WITH targq AS ( + SELECT * FROM v +) +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +ROLLBACK; + +-- RETURNING +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE +RETURNING *; +ROLLBACK; + +-- EXPLAIN +CREATE TABLE ex_mtarget (a int, b int) + WITH (autovacuum_enabled=off); +CREATE TABLE ex_msource (a int, b int) + WITH (autovacuum_enabled=off); +SELECT citus_add_local_table_to_metadata('ex_mtarget'); +SELECT citus_add_local_table_to_metadata('ex_msource'); +INSERT INTO ex_mtarget SELECT i, i*10 FROM generate_series(1,100,2) i; +INSERT INTO ex_msource SELECT i, i*10 FROM generate_series(1,100,1) i; + +CREATE FUNCTION explain_merge(query text) RETURNS SETOF text +LANGUAGE plpgsql AS +$$ +DECLARE ln text; +BEGIN + FOR ln IN + EXECUTE 'explain (analyze, timing off, summary off, costs off) ' || + query + LOOP + ln := regexp_replace(ln, '(Memory( Usage)?|Buckets|Batches): \S*', '\1: xxx', 'g'); + RETURN NEXT ln; + END LOOP; +END; +$$; + +-- only updates +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = t.b + 1'); + +-- only updates to selected tuples +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1'); + +-- updates + deletes +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1 +WHEN MATCHED AND t.a >= 10 AND t.a <= 20 THEN + DELETE'); + +-- only inserts +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN NOT MATCHED AND s.a < 10 THEN + INSERT VALUES (a, b)'); + +-- all three +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1 +WHEN MATCHED AND t.a >= 30 AND t.a <= 40 THEN + DELETE +WHEN NOT MATCHED AND s.a < 20 THEN + INSERT VALUES (a, b)'); + +-- nothing +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a AND t.a < -1000 +WHEN MATCHED AND t.a < 10 THEN + DO NOTHING'); + +DROP TABLE ex_msource, ex_mtarget; +DROP FUNCTION explain_merge(text); + +-- Subqueries +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED THEN + UPDATE SET balance = (SELECT count(*) FROM sq_target); +SELECT * FROM sq_target WHERE tid = 1; +ROLLBACK; + +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND (SELECT count(*) > 0 FROM sq_target) THEN + UPDATE SET balance = 42; +SELECT * FROM sq_target WHERE tid = 1; +ROLLBACK; + +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid AND (SELECT count(*) > 0 FROM sq_target) +WHEN MATCHED THEN + UPDATE SET balance = 42; +SELECT * FROM sq_target WHERE tid = 1; +ROLLBACK; + +DROP TABLE sq_target, sq_source CASCADE; + +CREATE TABLE pa_target (tid integer, balance float, val text) + PARTITION BY LIST (tid); + +CREATE TABLE part1 PARTITION OF pa_target FOR VALUES IN (1,4) + WITH (autovacuum_enabled=off); +CREATE TABLE part2 PARTITION OF pa_target FOR VALUES IN (2,5,6) + WITH (autovacuum_enabled=off); +CREATE TABLE part3 PARTITION OF pa_target FOR VALUES IN (3,8,9) + WITH (autovacuum_enabled=off); +CREATE TABLE part4 PARTITION OF pa_target DEFAULT + WITH (autovacuum_enabled=off); + +CREATE TABLE pa_source (sid integer, delta float); +-- insert many rows to the source table +INSERT INTO pa_source SELECT id, id * 10 FROM generate_series(1,14) AS id; +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT id, id * 100, 'initial' FROM generate_series(1,14,2) AS id; + +SELECT citus_add_local_table_to_metadata('pa_target'); +SELECT citus_add_local_table_to_metadata('pa_source'); + +-- try simple MERGE +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +-- same with a constant qual +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid AND tid = 1 + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +-- try updating the partition key column +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET tid = tid + 1, balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +DROP TABLE pa_target CASCADE; + +-- The target table is partitioned in the same way, but this time by attaching +-- partitions which have columns in different order, dropped columns etc. +CREATE TABLE pa_target (tid integer, balance float, val text) + PARTITION BY LIST (tid); + +CREATE TABLE part1 (tid integer, balance float, val text) + WITH (autovacuum_enabled=off); +CREATE TABLE part2 (balance float, tid integer, val text) + WITH (autovacuum_enabled=off); +CREATE TABLE part3 (tid integer, balance float, val text) + WITH (autovacuum_enabled=off); +CREATE TABLE part4 (extraid text, tid integer, balance float, val text) + WITH (autovacuum_enabled=off); +ALTER TABLE part4 DROP COLUMN extraid; + +ALTER TABLE pa_target ATTACH PARTITION part1 FOR VALUES IN (1,4); +ALTER TABLE pa_target ATTACH PARTITION part2 FOR VALUES IN (2,5,6); +ALTER TABLE pa_target ATTACH PARTITION part3 FOR VALUES IN (3,8,9); +ALTER TABLE pa_target ATTACH PARTITION part4 DEFAULT; + +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT id, id * 100, 'initial' FROM generate_series(1,14,2) AS id; + +-- try simple MERGE +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +-- same with a constant qual +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid AND tid IN (1, 5) + WHEN MATCHED AND tid % 5 = 0 THEN DELETE + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +-- try updating the partition key column +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET tid = tid + 1, balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +DROP TABLE pa_source; +DROP TABLE pa_target CASCADE; + +-- Sub-partitioning +SET citus.use_citus_managed_tables to false; + +CREATE TABLE pa_target (logts timestamp, tid integer, balance float, val text) + PARTITION BY RANGE (logts); + +CREATE TABLE part_m01 PARTITION OF pa_target + FOR VALUES FROM ('2017-01-01') TO ('2017-02-01') + PARTITION BY LIST (tid); + +SET citus.use_citus_managed_tables to true; + +CREATE TABLE part_m01_odd PARTITION OF part_m01 + FOR VALUES IN (1,3,5,7,9) WITH (autovacuum_enabled=off); +CREATE TABLE part_m01_even PARTITION OF part_m01 + FOR VALUES IN (2,4,6,8) WITH (autovacuum_enabled=off); +CREATE TABLE part_m02 PARTITION OF pa_target + FOR VALUES FROM ('2017-02-01') TO ('2017-03-01') + PARTITION BY LIST (tid); +CREATE TABLE part_m02_odd PARTITION OF part_m02 + FOR VALUES IN (1,3,5,7,9) WITH (autovacuum_enabled=off); +CREATE TABLE part_m02_even PARTITION OF part_m02 + FOR VALUES IN (2,4,6,8) WITH (autovacuum_enabled=off); + +CREATE TABLE pa_source (sid integer, delta float) + WITH (autovacuum_enabled=off); +-- insert many rows to the source table +INSERT INTO pa_source SELECT id, id * 10 FROM generate_series(1,14) AS id; +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT '2017-01-31', id, id * 100, 'initial' FROM generate_series(1,9,3) AS id; +INSERT INTO pa_target SELECT '2017-02-28', id, id * 100, 'initial' FROM generate_series(2,9,3) AS id; + +-- try simple MERGE +SET client_min_messages TO DEBUG1; +BEGIN; +MERGE INTO pa_target t + USING (SELECT '2017-01-15' AS slogts, * FROM pa_source WHERE sid < 10) s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (slogts::timestamp, sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; +RESET client_min_messages; + +DROP TABLE pa_source; +DROP TABLE pa_target CASCADE; + +-- some complex joins on the source side + +CREATE TABLE cj_target (tid integer, balance float, val text) + WITH (autovacuum_enabled=off); +CREATE TABLE cj_source1 (sid1 integer, scat integer, delta integer) + WITH (autovacuum_enabled=off); +CREATE TABLE cj_source2 (sid2 integer, sval text) + WITH (autovacuum_enabled=off); +INSERT INTO cj_source1 VALUES (1, 10, 100); +INSERT INTO cj_source1 VALUES (1, 20, 200); +INSERT INTO cj_source1 VALUES (2, 20, 300); +INSERT INTO cj_source1 VALUES (3, 10, 400); +INSERT INTO cj_source2 VALUES (1, 'initial source2'); +INSERT INTO cj_source2 VALUES (2, 'initial source2'); +INSERT INTO cj_source2 VALUES (3, 'initial source2'); + +-- source relation is an unaliased join +MERGE INTO cj_target t +USING cj_source1 s1 + INNER JOIN cj_source2 s2 ON sid1 = sid2 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid1, delta, sval); + +-- try accessing columns from either side of the source join +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 AND scat = 20 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid2, delta, sval) +WHEN MATCHED THEN + DELETE; + +-- some simple expressions in INSERT targetlist +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid2, delta + scat, sval) +WHEN MATCHED THEN + UPDATE SET val = val || ' updated by merge'; + +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 AND scat = 20 +ON t.tid = sid1 +WHEN MATCHED THEN + UPDATE SET val = val || ' ' || delta::text; + +SELECT * FROM cj_target; + +ALTER TABLE cj_source1 RENAME COLUMN sid1 TO sid; +ALTER TABLE cj_source2 RENAME COLUMN sid2 TO sid; + +TRUNCATE cj_target; + +MERGE INTO cj_target t +USING cj_source1 s1 + INNER JOIN cj_source2 s2 ON s1.sid = s2.sid +ON t.tid = s1.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s2.sid, delta, sval); + +DROP TABLE cj_source2, cj_source1, cj_target; + +-- Function scans +CREATE TABLE fs_target (a int, b int, c text) + WITH (autovacuum_enabled=off); +MERGE INTO fs_target t +USING generate_series(1,100,1) AS id +ON t.a = id +WHEN MATCHED THEN + UPDATE SET b = b + id +WHEN NOT MATCHED THEN + INSERT VALUES (id, -1); + +MERGE INTO fs_target t +USING generate_series(1,100,2) AS id +ON t.a = id +WHEN MATCHED THEN + UPDATE SET b = b + id, c = 'updated '|| id.*::text +WHEN NOT MATCHED THEN + INSERT VALUES (id, -1, 'inserted ' || id.*::text); + +SELECT count(*) FROM fs_target; +DROP TABLE fs_target; + +-- SERIALIZABLE test +-- handled in isolation tests + + +-- Inheritance-based partitioning +SET citus.use_citus_managed_tables to false; +CREATE TABLE measurement ( + city_id int not null, + logdate date not null, + peaktemp int, + unitsales int +) WITH (autovacuum_enabled=off); +CREATE TABLE measurement_y2006m02 ( + CHECK ( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' ) +) INHERITS (measurement) WITH (autovacuum_enabled=off); +CREATE TABLE measurement_y2006m03 ( + CHECK ( logdate >= DATE '2006-03-01' AND logdate < DATE '2006-04-01' ) +) INHERITS (measurement) WITH (autovacuum_enabled=off); +CREATE TABLE measurement_y2007m01 ( + filler text, + peaktemp int, + logdate date not null, + city_id int not null, + unitsales int + CHECK ( logdate >= DATE '2007-01-01' AND logdate < DATE '2007-02-01') +) WITH (autovacuum_enabled=off); +ALTER TABLE measurement_y2007m01 DROP COLUMN filler; +ALTER TABLE measurement_y2007m01 INHERIT measurement; + +SET citus.use_citus_managed_tables to true; + +CREATE OR REPLACE FUNCTION measurement_insert_trigger() +RETURNS TRIGGER AS $$ +BEGIN + IF ( NEW.logdate >= DATE '2006-02-01' AND + NEW.logdate < DATE '2006-03-01' ) THEN + INSERT INTO measurement_y2006m02 VALUES (NEW.*); + ELSIF ( NEW.logdate >= DATE '2006-03-01' AND + NEW.logdate < DATE '2006-04-01' ) THEN + INSERT INTO measurement_y2006m03 VALUES (NEW.*); + ELSIF ( NEW.logdate >= DATE '2007-01-01' AND + NEW.logdate < DATE '2007-02-01' ) THEN + INSERT INTO measurement_y2007m01 (city_id, logdate, peaktemp, unitsales) + VALUES (NEW.*); + ELSE + RAISE EXCEPTION 'Date out of range. Fix the measurement_insert_trigger() function!'; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql ; +CREATE TRIGGER insert_measurement_trigger + BEFORE INSERT ON measurement + FOR EACH ROW EXECUTE PROCEDURE measurement_insert_trigger(); +INSERT INTO measurement VALUES (1, '2006-02-10', 35, 10); +INSERT INTO measurement VALUES (1, '2006-02-16', 45, 20); +INSERT INTO measurement VALUES (1, '2006-03-17', 25, 10); +INSERT INTO measurement VALUES (1, '2006-03-27', 15, 40); +INSERT INTO measurement VALUES (1, '2007-01-15', 10, 10); +INSERT INTO measurement VALUES (1, '2007-01-17', 10, 10); + +SELECT tableoid::regclass, * FROM measurement ORDER BY city_id, logdate; + + +CREATE TABLE new_measurement (LIKE measurement) WITH (autovacuum_enabled=off); +INSERT INTO new_measurement VALUES (1, '2006-03-01', 20, 10); +INSERT INTO new_measurement VALUES (1, '2006-02-16', 50, 10); +INSERT INTO new_measurement VALUES (2, '2006-02-10', 20, 20); +INSERT INTO new_measurement VALUES (1, '2006-03-27', NULL, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-17', NULL, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-15', 5, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-16', 10, 10); + +SET client_min_messages TO DEBUG1; +MERGE into measurement m + USING new_measurement nm ON + (m.city_id = nm.city_id and m.logdate=nm.logdate) +WHEN MATCHED AND nm.peaktemp IS NULL THEN DELETE +WHEN MATCHED THEN UPDATE + SET peaktemp = greatest(m.peaktemp, nm.peaktemp), + unitsales = m.unitsales + coalesce(nm.unitsales, 0) +WHEN NOT MATCHED THEN INSERT + (city_id, logdate, peaktemp, unitsales) + VALUES (city_id, logdate, peaktemp, unitsales); +RESET client_min_messages; + +SELECT tableoid::regclass, * FROM measurement ORDER BY city_id, logdate; +DROP TABLE measurement, new_measurement CASCADE; +DROP FUNCTION measurement_insert_trigger(); + +-- prepare + +RESET SESSION AUTHORIZATION; +SET citus.use_citus_managed_tables to false; +REVOKE ALL ON SCHEMA pgmerge_schema FROM regress_merge_privs; +REVOKE ALL ON SCHEMA pgmerge_schema FROM regress_merge_no_privs; +DROP SCHEMA pgmerge_schema CASCADE; +DROP USER regress_merge_privs; +DROP USER regress_merge_no_privs; +SELECT 1 FROM master_remove_node('localhost', :master_port);