From: Simon Riggs Date: Tue, 3 Apr 2018 09:22:21 +0000 (+0100) Subject: New files for MERGE X-Git-Tag: REL_11_BETA1~391 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=83454e3c2b28141c0db01c7d2027e01040df5249;p=postgresql New files for MERGE --- diff --git a/doc/src/sgml/ref/merge.sgml b/doc/src/sgml/ref/merge.sgml new file mode 100644 index 0000000000..a7d44a39b6 --- /dev/null +++ b/doc/src/sgml/ref/merge.sgml @@ -0,0 +1,603 @@ + + + + + + MERGE + 7 + SQL - Language Statements + + + + MERGE + insert, update, or delete rows of a table based upon source data + + + + +MERGE INTO target_table_name [ [ AS ] target_alias ] +USING data_source +ON join_condition +when_clause [...] + +where data_source is + +{ source_table_name | + ( source_query ) +} +[ [ AS ] source_alias ] + +and when_clause is + +{ WHEN MATCHED [ AND condition ] THEN { merge_update | merge_delete } | + WHEN NOT MATCHED [ AND condition ] THEN { merge_insert | DO NOTHING } +} + +and merge_insert is + +INSERT [( column_name [, ...] )] +[ OVERRIDING { SYSTEM | USER } VALUE ] +{ VALUES ( { expression | DEFAULT } [, ...] ) | DEFAULT VALUES } + +and merge_update is + +UPDATE SET { column_name = { expression | DEFAULT } | + ( column_name [, ...] ) = ( { expression | DEFAULT } [, ...] ) + } [, ...] + +and merge_delete is + +DELETE + + + + + Description + + + MERGE performs actions that modify rows in the + target_table_name, + using the data_source. + MERGE provides a single SQL + statement that can conditionally INSERT, + UPDATE or DELETE rows, a task + that would otherwise require multiple procedural language statements. + + + + First, the MERGE command performs a join + from data_source to + target_table_name + producing zero or more candidate change rows. For each candidate change + row the status of MATCHED or NOT MATCHED is set + just once, after which WHEN clauses are evaluated + in the order specified. If one of them is activated, the specified + action occurs. No more than one WHEN clause can be + activated for any candidate change row. + + + + MERGE actions have the same effect as + regular UPDATE, INSERT, or + DELETE commands of the same names. The syntax of + those commands is different, notably that there is no WHERE + clause and no tablename is specified. All actions refer to the + target_table_name, + though modifications to other tables may be made using triggers. + + + + When DO NOTHING action is specified, the source row is + skipped. Since actions are evaluated in the given order, DO + NOTHING can be handy to skip non-interesting source rows before + more fine-grained handling. + + + + There is no MERGE privilege. + You must have the UPDATE privilege on the column(s) + of the target_table_name + referred to in the SET clause + if you specify an update action, the INSERT privilege + on the target_table_name + if you specify an insert action and/or the DELETE + privilege on the target_table_name + if you specify a delete action on the + target_table_name. + Privileges are tested once at statement start and are checked + whether or not particular WHEN clauses are activated + during the subsequent execution. + You will require the SELECT privilege on the + data_source and any column(s) + of the target_table_name + referred to in a condition. + + + + MERGE is not supported if the target_table_name has + RULES defined on it. + See for more information about RULES. + + + + + Parameters + + + + target_table_name + + + The name (optionally schema-qualified) of the target table to merge into. + + + + + + target_alias + + + A substitute name for the target table. When an alias is + provided, it completely hides the actual name of the table. For + example, given MERGE foo AS f, the remainder of the + MERGE statement must refer to this table as + f not foo. + + + + + + source_table_name + + + The name (optionally schema-qualified) of the source table, view or + transition table. + + + + + + source_query + + + A query (SELECT statement or VALUES + statement) that supplies the rows to be merged into the + target_table_name. + Refer to the + statement or + statement for a description of the syntax. + + + + + + source_alias + + + A substitute name for the data source. When an alias is + provided, it completely hides whether table or query was specified. + + + + + + join_condition + + + join_condition is + an expression resulting in a value of type + boolean (similar to a WHERE + clause) that specifies which rows in the + data_source + match rows in the + target_table_name. + + + + Only columns from target_table_name + that attempt to match data_source + rows should appear in join_condition. + join_condition subexpressions that + only reference target_table_name + columns can only affect which action is taken, often in surprising ways. + + + + + + + when_clause + + + At least one WHEN clause is required. + + + If the WHEN clause specifies WHEN MATCHED + and the candidate change row matches a row in the + target_table_name + the WHEN clause is activated if the + condition is + absent or is present and evaluates to true. + If the WHEN clause specifies WHEN NOT MATCHED + and the candidate change row does not match a row in the + target_table_name + the WHEN clause is activated if the + condition is + absent or is present and evaluates to true. + + + + + + condition + + + An expression that returns a value of type boolean. + If this expression returns true then the WHEN + clause will be activated and the corresponding action will occur for + that row. The expression may not contain functions that possibly performs + writes to the database. + + + A condition on a WHEN MATCHED clause can refer to columns + in both the source and the target relation. A condition on a + WHEN NOT MATCHED clause can only refer to columns from + the source relation, since by definition there is no matching target row. + Only the system attributes from the target table are accessible. + + + + + + merge_insert + + + The specification of an INSERT action that inserts + one row into the target table. + The target column names can be listed in any order. If no list of + column names is given at all, the default is all the columns of the + table in their declared order. + + + Each column not present in the explicit or implicit column list will be + filled with a default value, either its declared default value + or null if there is none. + + + If the expression for any column is not of the correct data type, + automatic type conversion will be attempted. + + + If target_table_name + is a partitioned table, each row is routed to the appropriate partition + and inserted into it. + If target_table_name + is a partition, an error will occur if one of the input rows violates + the partition constraint. + + + Column names may not be specified more than once. + INSERT actions cannot contain sub-selects. + + + The VALUES clause can only refer to columns from + the source relation, since by definition there is no matching target row. + + + + + + merge_update + + + The specification of an UPDATE action that updates + the current row of the target_table_name. + Column names may not be specified more than once. + + + Do not include the table name, as you would normally do with an + command. + For example, UPDATE tab SET col = 1 is invalid. Also, + do not include a WHERE clause, since only the current + row can be updated. For example, + UPDATE SET col = 1 WHERE key = 57 is invalid. + + + + + + merge_delete + + + Specifies a DELETE action that deletes the current row + of the target_table_name. + Do not include the tablename or any other clauses, as you would normally + do with an command. + + + + + + column_name + + + The name of a column in the target_table_name. The column name + can be qualified with a subfield name or array subscript, if + needed. (Inserting into only some fields of a composite + column leaves the other fields null.) When referencing a + column, do not include the table's name in the specification + of a target column. + + + + + + OVERRIDING SYSTEM VALUE + + + Without this clause, it is an error to specify an explicit value + (other than DEFAULT) for an identity column defined + as GENERATED ALWAYS. This clause overrides that + restriction. + + + + + + OVERRIDING USER VALUE + + + If this clause is specified, then any values supplied for identity + columns defined as GENERATED BY DEFAULT are ignored + and the default sequence-generated values are applied. + + + + + + DEFAULT VALUES + + + All columns will be filled with their default values. + (An OVERRIDING clause is not permitted in this + form.) + + + + + + expression + + + An expression to assign to the column. The expression can use the + old values of this and other columns in the table. + + + + + + DEFAULT + + + Set the column to its default value (which will be NULL if no + specific default expression has been assigned to it). + + + + + + + + + Outputs + + + On successful completion, a MERGE command returns a command + tag of the form + +MERGE total-count + + The total-count is the total + number of rows changed (whether inserted, updated, or deleted). + If total-count is 0, no rows + were changed in any way. + + + + + + Execution + + + The following steps take place during the execution of + MERGE. + + + + Perform any BEFORE STATEMENT triggers for all actions specified, whether or + not their WHEN clauses are activated during execution. + + + + + Perform a join from source to target table. + The resulting query will be optimized normally and will produce + a set of candidate change row. For each candidate change row + + + + Evaluate whether each row is MATCHED or NOT MATCHED. + + + + + Test each WHEN condition in the order specified until one activates. + + + + + When activated, perform the following actions + + + + Perform any BEFORE ROW triggers that fire for the action's event type. + + + + + Apply the action specified, invoking any check constraints on the + target table. + However, it will not invoke rules. + + + + + Perform any AFTER ROW triggers that fire for the action's event type. + + + + + + + + + + + Perform any AFTER STATEMENT triggers for actions specified, whether or + not they actually occur. This is similar to the behavior of an + UPDATE statement that modifies no rows. + + + + In summary, statement triggers for an event type (say, INSERT) will + be fired whenever we specify an action of that kind. Row-level + triggers will fire only for the one event type activated. + So a MERGE might fire statement triggers for both + UPDATE and INSERT, even though only + UPDATE row triggers were fired. + + + + You should ensure that the join produces at most one candidate change row + for each target row. In other words, a target row shouldn't join to more + than one data source row. If it does, then only one of the candidate change + rows will be used to modify the target row, later attempts to modify will + cause an error. This can also occur if row triggers make changes to the + target table which are then subsequently modified by MERGE. + If the repeated action is an INSERT this will + cause a uniqueness violation while a repeated UPDATE or + DELETE will cause a cardinality violation; the latter behavior + is required by the SQL Standard. This differs from + historical PostgreSQL behavior of joins in + UPDATE and DELETE statements where second and + subsequent attempts to modify are simply ignored. + + + + If a WHEN clause omits an AND clause it becomes + the final reachable clause of that kind (MATCHED or + NOT MATCHED). If a later WHEN clause of that kind + is specified it would be provably unreachable and an error is raised. + If a final reachable clause is omitted it is possible that no action + will be taken for a candidate change row. + + + + + Notes + + + The order in which rows are generated from the data source is indeterminate + by default. A source_query + can be used to specify a consistent ordering, if required, which might be + needed to avoid deadlocks between concurrent transactions. + + + + There is no RETURNING clause with MERGE. + Actions of INSERT, UPDATE and DELETE + cannot contain RETURNING or WITH clauses. + + + + + You may also wish to consider using INSERT ... ON CONFLICT as an + alternative statement which offers the ability to run an UPDATE + if a concurrent INSERT occurs. There are a variety of + differences and restrictions between the two statement types and they are not + interchangeable. + + + + + + Examples + + + Perform maintenance on CustomerAccounts based upon new Transactions. + + +MERGE CustomerAccount CA +USING RecentTransactions T +ON T.CustomerId = CA.CustomerId +WHEN MATCHED THEN + UPDATE SET Balance = Balance + TransactionValue +WHEN NOT MATCHED THEN + INSERT (CustomerId, Balance) + VALUES (T.CustomerId, T.TransactionValue); + + + notice that this would be exactly equivalent to the following + statement because the MATCHED result does not change + during execution + + +MERGE CustomerAccount CA +USING (Select CustomerId, TransactionValue From RecentTransactions) AS T +ON CA.CustomerId = T.CustomerId +WHEN NOT MATCHED THEN + INSERT (CustomerId, Balance) + VALUES (T.CustomerId, T.TransactionValue) +WHEN MATCHED THEN + UPDATE SET Balance = Balance + TransactionValue; + + + + + Attempt to insert a new stock item along with the quantity of stock. If + the item already exists, instead update the stock count of the existing + item. Don't allow entries that have zero stock. + +MERGE INTO wines w +USING wine_stock_changes s +ON s.winename = w.winename +WHEN NOT MATCHED AND s.stock_delta > 0 THEN + INSERT VALUES(s.winename, s.stock_delta) +WHEN MATCHED AND w.stock + s.stock_delta > 0 THEN + UPDATE SET stock = w.stock + s.stock_delta; +WHEN MATCHED THEN + DELETE; + + + The wine_stock_changes table might be, for example, a temporary table + recently loaded into the database. + + + + + + Compatibility + + This command conforms to the SQL standard. + + + The DO NOTHING action is an extension to the SQL standard. + + + diff --git a/src/backend/executor/nodeMerge.c b/src/backend/executor/nodeMerge.c new file mode 100644 index 0000000000..0e0d0795d4 --- /dev/null +++ b/src/backend/executor/nodeMerge.c @@ -0,0 +1,575 @@ +/*------------------------------------------------------------------------- + * + * nodeMerge.c + * routines to handle Merge nodes relating to the MERGE command + * + * Portions Copyright (c) 1996-2018, PostgreSQL Global Development Group + * Portions Copyright (c) 1994, Regents of the University of California + * + * + * IDENTIFICATION + * src/backend/executor/nodeMerge.c + * + *------------------------------------------------------------------------- + */ + + +#include "postgres.h" + +#include "access/htup_details.h" +#include "access/xact.h" +#include "commands/trigger.h" +#include "executor/execPartition.h" +#include "executor/executor.h" +#include "executor/nodeModifyTable.h" +#include "executor/nodeMerge.h" +#include "miscadmin.h" +#include "nodes/nodeFuncs.h" +#include "storage/bufmgr.h" +#include "storage/lmgr.h" +#include "utils/builtins.h" +#include "utils/memutils.h" +#include "utils/rel.h" +#include "utils/tqual.h" + + +/* + * Check and execute the first qualifying MATCHED action. The current target + * tuple is identified by tupleid. + * + * We start from the first WHEN MATCHED action and check if the WHEN AND quals + * pass, if any. If the WHEN AND quals for the first action do not pass, we + * check the second, then the third and so on. If we reach to the end, no + * action is taken and we return true, indicating that no further action is + * required for this tuple. + * + * If we do find a qualifying action, then we attempt to execute the action. + * + * If the tuple is concurrently updated, EvalPlanQual is run with the updated + * tuple to recheck the join quals. Note that the additional quals associated + * with individual actions are evaluated separately by the MERGE code, while + * EvalPlanQual checks for the join quals. If EvalPlanQual tells us that the + * updated tuple still passes the join quals, then we restart from the first + * action to look for a qualifying action. Otherwise, we return false meaning + * that a NOT MATCHED action must now be executed for the current source tuple. + */ +static bool +ExecMergeMatched(ModifyTableState *mtstate, EState *estate, + TupleTableSlot *slot, JunkFilter *junkfilter, + ItemPointer tupleid) +{ + ExprContext *econtext = mtstate->ps.ps_ExprContext; + bool isNull; + List *mergeMatchedActionStates = NIL; + HeapUpdateFailureData hufd; + bool tuple_updated, + tuple_deleted; + Buffer buffer; + HeapTupleData tuple; + EPQState *epqstate = &mtstate->mt_epqstate; + ResultRelInfo *saved_resultRelInfo; + ResultRelInfo *resultRelInfo = estate->es_result_relation_info; + ListCell *l; + TupleTableSlot *saved_slot = slot; + + if (mtstate->mt_partition_tuple_routing) + { + Datum datum; + Oid tableoid = InvalidOid; + int leaf_part_index; + PartitionTupleRouting *proute = mtstate->mt_partition_tuple_routing; + + /* + * In case of partitioned table, we fetch the tableoid while performing + * MATCHED MERGE action. + */ + datum = ExecGetJunkAttribute(slot, junkfilter->jf_otherJunkAttNo, + &isNull); + Assert(!isNull); + tableoid = DatumGetObjectId(datum); + + /* + * If we're dealing with a MATCHED tuple, then tableoid must have been + * set correctly. In case of partitioned table, we must now fetch the + * correct result relation corresponding to the child table emitting + * the matching target row. For normal table, there is just one result + * relation and it must be the one emitting the matching row. + */ + leaf_part_index = ExecFindPartitionByOid(proute, tableoid); + + resultRelInfo = proute->partitions[leaf_part_index]; + if (resultRelInfo == NULL) + { + resultRelInfo = ExecInitPartitionInfo(mtstate, + mtstate->resultRelInfo, + proute, estate, leaf_part_index); + Assert(resultRelInfo != NULL); + } + } + + /* + * Save the current information and work with the correct result relation. + */ + saved_resultRelInfo = resultRelInfo; + estate->es_result_relation_info = resultRelInfo; + + /* + * And get the correct action lists. + */ + mergeMatchedActionStates = + resultRelInfo->ri_mergeState->matchedActionStates; + + /* + * If there are not WHEN MATCHED actions, we are done. + */ + if (mergeMatchedActionStates == NIL) + return true; + + /* + * Make tuple and any needed join variables available to ExecQual and + * ExecProject. The target's existing tuple is installed in the scantuple. + * Again, this target relation's slot is required only in the case of a + * MATCHED tuple and UPDATE/DELETE actions. + */ + if (mtstate->mt_partition_tuple_routing) + ExecSetSlotDescriptor(mtstate->mt_existing, + resultRelInfo->ri_RelationDesc->rd_att); + econtext->ecxt_scantuple = mtstate->mt_existing; + econtext->ecxt_innertuple = slot; + econtext->ecxt_outertuple = NULL; + +lmerge_matched:; + slot = saved_slot; + + /* + * UPDATE/DELETE is only invoked for matched rows. And we must have found + * the tupleid of the target row in that case. We fetch using SnapshotAny + * because we might get called again after EvalPlanQual returns us a new + * tuple. This tuple may not be visible to our MVCC snapshot. + */ + Assert(tupleid != NULL); + + tuple.t_self = *tupleid; + if (!heap_fetch(resultRelInfo->ri_RelationDesc, SnapshotAny, &tuple, + &buffer, true, NULL)) + elog(ERROR, "Failed to fetch the target tuple"); + + /* Store target's existing tuple in the state's dedicated slot */ + ExecStoreTuple(&tuple, mtstate->mt_existing, buffer, false); + + foreach(l, mergeMatchedActionStates) + { + MergeActionState *action = (MergeActionState *) lfirst(l); + + /* + * Test condition, if any + * + * In the absence of a condition we perform the action unconditionally + * (no need to check separately since ExecQual() will return true if + * there are no conditions to evaluate). + */ + if (!ExecQual(action->whenqual, econtext)) + continue; + + /* + * Check if the existing target tuple meet the USING checks of + * UPDATE/DELETE RLS policies. If those checks fail, we throw an + * error. + * + * The WITH CHECK quals are applied in ExecUpdate() and hence we need + * not do anything special to handle them. + * + * NOTE: We must do this after WHEN quals are evaluated so that we + * check policies only when they matter. + */ + if (resultRelInfo->ri_WithCheckOptions) + { + ExecWithCheckOptions(action->commandType == CMD_UPDATE ? + WCO_RLS_MERGE_UPDATE_CHECK : WCO_RLS_MERGE_DELETE_CHECK, + resultRelInfo, + mtstate->mt_existing, + mtstate->ps.state); + } + + /* Perform stated action */ + switch (action->commandType) + { + case CMD_UPDATE: + + /* + * We set up the projection earlier, so all we do here is + * Project, no need for any other tasks prior to the + * ExecUpdate. + */ + if (mtstate->mt_partition_tuple_routing) + ExecSetSlotDescriptor(mtstate->mt_mergeproj, action->tupDesc); + ExecProject(action->proj); + + /* + * We don't call ExecFilterJunk() because the projected tuple + * using the UPDATE action's targetlist doesn't have a junk + * attribute. + */ + slot = ExecUpdate(mtstate, tupleid, NULL, + mtstate->mt_mergeproj, + slot, epqstate, estate, + &tuple_updated, &hufd, + action, mtstate->canSetTag); + break; + + case CMD_DELETE: + /* Nothing to Project for a DELETE action */ + slot = ExecDelete(mtstate, tupleid, NULL, + slot, epqstate, estate, + &tuple_deleted, false, &hufd, action, + mtstate->canSetTag); + + break; + + default: + elog(ERROR, "unknown action in MERGE WHEN MATCHED clause"); + + } + + /* + * Check for any concurrent update/delete operation which may have + * prevented our update/delete. We also check for situations where we + * might be trying to update/delete the same tuple twice. + */ + if ((action->commandType == CMD_UPDATE && !tuple_updated) || + (action->commandType == CMD_DELETE && !tuple_deleted)) + + { + switch (hufd.result) + { + case HeapTupleMayBeUpdated: + break; + case HeapTupleInvisible: + + /* + * This state should never be reached since the underlying + * JOIN runs with a MVCC snapshot and should only return + * rows visible to us. + */ + elog(ERROR, "unexpected invisible tuple"); + break; + + case HeapTupleSelfUpdated: + + /* + * SQLStandard disallows this for MERGE. + */ + if (TransactionIdIsCurrentTransactionId(hufd.xmax)) + ereport(ERROR, + (errcode(ERRCODE_CARDINALITY_VIOLATION), + errmsg("MERGE command cannot affect row a second time"), + errhint("Ensure that not more than one source row matches any one target row"))); + /* This shouldn't happen */ + elog(ERROR, "attempted to update or delete invisible tuple"); + break; + + case HeapTupleUpdated: + + /* + * The target tuple was concurrently updated/deleted by + * some other transaction. + * + * If the current tuple is that last tuple in the update + * chain, then we know that the tuple was concurrently + * deleted. Just return and let the caller try NOT MATCHED + * actions. + * + * If the current tuple was concurrently updated, then we + * must run the EvalPlanQual() with the new version of the + * tuple. If EvalPlanQual() does not return a tuple then + * we switch to the NOT MATCHED list of actions. + * If it does return a tuple and the join qual is + * still satisfied, then we just need to recheck the + * MATCHED actions, starting from the top, and execute the + * first qualifying action. + */ + if (!ItemPointerEquals(tupleid, &hufd.ctid)) + { + TupleTableSlot *epqslot; + + /* + * Since we generate a JOIN query with a target table + * RTE different than the result relation RTE, we must + * pass in the RTI of the relation used in the join + * query and not the one from result relation. + */ + Assert(resultRelInfo->ri_mergeTargetRTI > 0); + epqslot = EvalPlanQual(estate, + epqstate, + resultRelInfo->ri_RelationDesc, + GetEPQRangeTableIndex(resultRelInfo), + LockTupleExclusive, + &hufd.ctid, + hufd.xmax); + + if (!TupIsNull(epqslot)) + { + (void) ExecGetJunkAttribute(epqslot, + resultRelInfo->ri_junkFilter->jf_junkAttNo, + &isNull); + + /* + * A non-NULL ctid means that we are still dealing + * with MATCHED case. But we must retry from the + * start with the updated tuple to ensure that the + * first qualifying WHEN MATCHED action is + * executed. + * + * We don't use the new slot returned by + * EvalPlanQual because we anyways re-install the + * new target tuple in econtext->ecxt_scantuple + * before re-evaluating WHEN AND conditions and + * re-projecting the update targetlists. The + * source side tuple does not change and hence we + * can safely continue to use the old slot. + */ + if (!isNull) + { + /* + * Must update *tupleid to the TID of the + * newer tuple found in the update chain. + */ + *tupleid = hufd.ctid; + ReleaseBuffer(buffer); + goto lmerge_matched; + } + } + } + + /* + * Tell the caller about the updated TID, restore the + * state back and return. + */ + *tupleid = hufd.ctid; + estate->es_result_relation_info = saved_resultRelInfo; + ReleaseBuffer(buffer); + return false; + + default: + break; + + } + } + + if (action->commandType == CMD_UPDATE && tuple_updated) + InstrCountFiltered2(&mtstate->ps, 1); + if (action->commandType == CMD_DELETE && tuple_deleted) + InstrCountFiltered3(&mtstate->ps, 1); + + /* + * We've activated one of the WHEN clauses, so we don't search + * further. This is required behaviour, not an optimization. + */ + estate->es_result_relation_info = saved_resultRelInfo; + break; + } + + ReleaseBuffer(buffer); + + /* + * Successfully executed an action or no qualifying action was found. + */ + return true; +} + +/* + * Execute the first qualifying NOT MATCHED action. + */ +static void +ExecMergeNotMatched(ModifyTableState *mtstate, EState *estate, + TupleTableSlot *slot) +{ + PartitionTupleRouting *proute = mtstate->mt_partition_tuple_routing; + ExprContext *econtext = mtstate->ps.ps_ExprContext; + List *mergeNotMatchedActionStates = NIL; + ResultRelInfo *resultRelInfo; + ListCell *l; + TupleTableSlot *myslot; + + /* + * We are dealing with NOT MATCHED tuple. Since for MERGE, partition tree + * is not expanded for the result relation, we continue to work with the + * currently active result relation, which should be of the root of the + * partition tree. + */ + resultRelInfo = mtstate->resultRelInfo; + + /* + * For INSERT actions, root relation's merge action is OK since the + * INSERT's targetlist and the WHEN conditions can only refer to the + * source relation and hence it does not matter which result relation we + * work with. + */ + mergeNotMatchedActionStates = + resultRelInfo->ri_mergeState->notMatchedActionStates; + + /* + * Make source tuple available to ExecQual and ExecProject. We don't need + * the target tuple since the WHEN quals and the targetlist can't refer to + * the target columns. + */ + econtext->ecxt_scantuple = NULL; + econtext->ecxt_innertuple = slot; + econtext->ecxt_outertuple = NULL; + + foreach(l, mergeNotMatchedActionStates) + { + MergeActionState *action = (MergeActionState *) lfirst(l); + + /* + * Test condition, if any + * + * In the absence of a condition we perform the action unconditionally + * (no need to check separately since ExecQual() will return true if + * there are no conditions to evaluate). + */ + if (!ExecQual(action->whenqual, econtext)) + continue; + + /* Perform stated action */ + switch (action->commandType) + { + case CMD_INSERT: + + /* + * We set up the projection earlier, so all we do here is + * Project, no need for any other tasks prior to the + * ExecInsert. + */ + if (mtstate->mt_partition_tuple_routing) + ExecSetSlotDescriptor(mtstate->mt_mergeproj, action->tupDesc); + ExecProject(action->proj); + + /* + * ExecPrepareTupleRouting may modify the passed-in slot. Hence + * pass a local reference so that action->slot is not modified. + */ + myslot = mtstate->mt_mergeproj; + + /* Prepare for tuple routing if needed. */ + if (proute) + myslot = ExecPrepareTupleRouting(mtstate, estate, proute, + resultRelInfo, myslot); + slot = ExecInsert(mtstate, myslot, slot, + estate, action, + mtstate->canSetTag); + /* Revert ExecPrepareTupleRouting's state change. */ + if (proute) + estate->es_result_relation_info = resultRelInfo; + InstrCountFiltered1(&mtstate->ps, 1); + break; + case CMD_NOTHING: + /* Do Nothing */ + break; + default: + elog(ERROR, "unknown action in MERGE WHEN NOT MATCHED clause"); + } + + break; + } +} + +/* + * Perform MERGE. + */ +void +ExecMerge(ModifyTableState *mtstate, EState *estate, TupleTableSlot *slot, + JunkFilter *junkfilter, ResultRelInfo *resultRelInfo) +{ + ExprContext *econtext = mtstate->ps.ps_ExprContext; + ItemPointer tupleid; + ItemPointerData tuple_ctid; + bool matched = false; + char relkind; + Datum datum; + bool isNull; + + relkind = resultRelInfo->ri_RelationDesc->rd_rel->relkind; + Assert(relkind == RELKIND_RELATION || + relkind == RELKIND_PARTITIONED_TABLE); + + /* + * Reset per-tuple memory context to free any expression evaluation + * storage allocated in the previous cycle. + */ + ResetExprContext(econtext); + + /* + * We run a JOIN between the target relation and the source relation to + * find a set of candidate source rows that has matching row in the target + * table and a set of candidate source rows that does not have matching + * row in the target table. If the join returns us a tuple with target + * relation's tid set, that implies that the join found a matching row for + * the given source tuple. This case triggers the WHEN MATCHED clause of + * the MERGE. Whereas a NULL in the target relation's ctid column + * indicates a NOT MATCHED case. + */ + datum = ExecGetJunkAttribute(slot, junkfilter->jf_junkAttNo, &isNull); + + if (!isNull) + { + matched = true; + tupleid = (ItemPointer) DatumGetPointer(datum); + tuple_ctid = *tupleid; /* be sure we don't free ctid!! */ + tupleid = &tuple_ctid; + } + else + { + matched = false; + tupleid = NULL; /* we don't need it for INSERT actions */ + } + + /* + * If we are dealing with a WHEN MATCHED case, we execute the first action + * for which the additional WHEN MATCHED AND quals pass. If an action + * without quals is found, that action is executed. + * + * Similarly, if we are dealing with WHEN NOT MATCHED case, we look at the + * given WHEN NOT MATCHED actions in sequence until one passes. + * + * Things get interesting in case of concurrent update/delete of the + * target tuple. Such concurrent update/delete is detected while we are + * executing a WHEN MATCHED action. + * + * A concurrent update can: + * + * 1. modify the target tuple so that it no longer satisfies the + * additional quals attached to the current WHEN MATCHED action OR + * + * In this case, we are still dealing with a WHEN MATCHED case, but + * we should recheck the list of WHEN MATCHED actions and choose the first + * one that satisfies the new target tuple. + * + * 2. modify the target tuple so that the join quals no longer pass and + * hence the source tuple no longer has a match. + * + * In the second case, the source tuple no longer matches the target tuple, + * so we now instead find a qualifying WHEN NOT MATCHED action to execute. + * + * A concurrent delete, changes a WHEN MATCHED case to WHEN NOT MATCHED. + * + * ExecMergeMatched takes care of following the update chain and + * re-finding the qualifying WHEN MATCHED action, as long as the updated + * target tuple still satisfies the join quals i.e. it still remains a + * WHEN MATCHED case. If the tuple gets deleted or the join quals fail, it + * returns and we try ExecMergeNotMatched. Given that ExecMergeMatched + * always make progress by following the update chain and we never switch + * from ExecMergeNotMatched to ExecMergeMatched, there is no risk of a + * livelock. + */ + if (matched) + matched = ExecMergeMatched(mtstate, estate, slot, junkfilter, tupleid); + + /* + * Either we were dealing with a NOT MATCHED tuple or ExecMergeNotMatched() + * returned "false", indicating the previously MATCHED tuple is no longer a + * matching tuple. + */ + if (!matched) + ExecMergeNotMatched(mtstate, estate, slot); +} diff --git a/src/backend/parser/parse_merge.c b/src/backend/parser/parse_merge.c new file mode 100644 index 0000000000..d6d6876961 --- /dev/null +++ b/src/backend/parser/parse_merge.c @@ -0,0 +1,660 @@ +/*------------------------------------------------------------------------- + * + * parse_merge.c + * handle merge-statement in parser + * + * Portions Copyright (c) 1996-2018, PostgreSQL Global Development Group + * Portions Copyright (c) 1994, Regents of the University of California + * + * + * IDENTIFICATION + * src/backend/parser/parse_merge.c + * + *------------------------------------------------------------------------- + */ + +#include "postgres.h" + +#include "miscadmin.h" + +#include "access/sysattr.h" +#include "nodes/makefuncs.h" +#include "parser/analyze.h" +#include "parser/parse_collate.h" +#include "parser/parsetree.h" +#include "parser/parser.h" +#include "parser/parse_clause.h" +#include "parser/parse_merge.h" +#include "parser/parse_relation.h" +#include "parser/parse_target.h" +#include "utils/rel.h" +#include "utils/relcache.h" + +static int transformMergeJoinClause(ParseState *pstate, Node *merge, + List **mergeSourceTargetList); +static void setNamespaceForMergeAction(ParseState *pstate, + MergeAction *action); +static void setNamespaceVisibilityForRTE(List *namespace, RangeTblEntry *rte, + bool rel_visible, + bool cols_visible); +static List *expandSourceTL(ParseState *pstate, RangeTblEntry *rte, + int rtindex); + +/* + * Special handling for MERGE statement is required because we assemble + * the query manually. This is similar to setTargetTable() followed + * by transformFromClause() but with a few less steps. + * + * Process the FROM clause and add items to the query's range table, + * joinlist, and namespace. + * + * A special targetlist comprising of the columns from the right-subtree of + * the join is populated and returned. Note that when the JoinExpr is + * setup by transformMergeStmt, the left subtree has the target result + * relation and the right subtree has the source relation. + * + * Returns the rangetable index of the target relation. + */ +static int +transformMergeJoinClause(ParseState *pstate, Node *merge, + List **mergeSourceTargetList) +{ + RangeTblEntry *rte, + *rt_rte; + List *namespace; + int rtindex, + rt_rtindex; + Node *n; + int mergeTarget_relation = list_length(pstate->p_rtable) + 1; + Var *var; + TargetEntry *te; + + n = transformFromClauseItem(pstate, merge, + &rte, + &rtindex, + &rt_rte, + &rt_rtindex, + &namespace); + + pstate->p_joinlist = list_make1(n); + + /* + * We created an internal join between the target and the source relation + * to carry out the MERGE actions. Normally such an unaliased join hides + * the joining relations, unless the column references are qualified. + * Also, any unqualified column references are resolved to the Join RTE, if + * there is a matching entry in the targetlist. But the way MERGE + * execution is later setup, we expect all column references to resolve to + * either the source or the target relation. Hence we must not add the + * Join RTE to the namespace. + * + * The last entry must be for the top-level Join RTE. We don't want to + * resolve any references to the Join RTE. So discard that. + * + * We also do not want to resolve any references from the leftside of the + * Join since that corresponds to the target relation. References to the + * columns of the target relation must be resolved from the result + * relation and not the one that is used in the join. So the + * mergeTarget_relation is marked invisible to both qualified as well as + * unqualified references. + */ + Assert(list_length(namespace) > 1); + namespace = list_truncate(namespace, list_length(namespace) - 1); + pstate->p_namespace = list_concat(pstate->p_namespace, namespace); + + setNamespaceVisibilityForRTE(pstate->p_namespace, + rt_fetch(mergeTarget_relation, pstate->p_rtable), false, false); + + /* + * Expand the right relation and add its columns to the + * mergeSourceTargetList. Note that the right relation can either be a + * plain relation or a subquery or anything that can have a + * RangeTableEntry. + */ + *mergeSourceTargetList = expandSourceTL(pstate, rt_rte, rt_rtindex); + + /* + * Add a whole-row-Var entry to support references to "source.*". + */ + var = makeWholeRowVar(rt_rte, rt_rtindex, 0, false); + te = makeTargetEntry((Expr *) var, list_length(*mergeSourceTargetList) + 1, + NULL, true); + *mergeSourceTargetList = lappend(*mergeSourceTargetList, te); + + return mergeTarget_relation; +} + +/* + * Make appropriate changes to the namespace visibility while transforming + * individual action's quals and targetlist expressions. In particular, for + * INSERT actions we must only see the source relation (since INSERT action is + * invoked for NOT MATCHED tuples and hence there is no target tuple to deal + * with). On the other hand, UPDATE and DELETE actions can see both source and + * target relations. + * + * Also, since the internal Join node can hide the source and target + * relations, we must explicitly make the respective relation as visible so + * that columns can be referenced unqualified from these relations. + */ +static void +setNamespaceForMergeAction(ParseState *pstate, MergeAction *action) +{ + RangeTblEntry *targetRelRTE, + *sourceRelRTE; + + /* Assume target relation is at index 1 */ + targetRelRTE = rt_fetch(1, pstate->p_rtable); + + /* + * Assume that the top-level join RTE is at the end. The source relation + * is just before that. + */ + sourceRelRTE = rt_fetch(list_length(pstate->p_rtable) - 1, pstate->p_rtable); + + switch (action->commandType) + { + case CMD_INSERT: + + /* + * Inserts can't see target relation, but they can see source + * relation. + */ + setNamespaceVisibilityForRTE(pstate->p_namespace, + targetRelRTE, false, false); + setNamespaceVisibilityForRTE(pstate->p_namespace, + sourceRelRTE, true, true); + break; + + case CMD_UPDATE: + case CMD_DELETE: + + /* + * Updates and deletes can see both target and source relations. + */ + setNamespaceVisibilityForRTE(pstate->p_namespace, + targetRelRTE, true, true); + setNamespaceVisibilityForRTE(pstate->p_namespace, + sourceRelRTE, true, true); + break; + + case CMD_NOTHING: + break; + default: + elog(ERROR, "unknown action in MERGE WHEN clause"); + } +} + +/* + * transformMergeStmt - + * transforms a MERGE statement + */ +Query * +transformMergeStmt(ParseState *pstate, MergeStmt *stmt) +{ + Query *qry = makeNode(Query); + ListCell *l; + AclMode targetPerms = ACL_NO_RIGHTS; + bool is_terminal[2]; + JoinExpr *joinexpr; + RangeTblEntry *resultRelRTE, *mergeRelRTE; + + /* There can't be any outer WITH to worry about */ + Assert(pstate->p_ctenamespace == NIL); + + qry->commandType = CMD_MERGE; + + /* + * Check WHEN clauses for permissions and sanity + */ + is_terminal[0] = false; + is_terminal[1] = false; + foreach(l, stmt->mergeActionList) + { + MergeAction *action = (MergeAction *) lfirst(l); + int when_type = (action->matched ? 0 : 1); + + /* + * Collect action types so we can check Target permissions + */ + switch (action->commandType) + { + case CMD_INSERT: + { + InsertStmt *istmt = (InsertStmt *) action->stmt; + SelectStmt *selectStmt = (SelectStmt *) istmt->selectStmt; + + /* + * The grammar allows attaching ORDER BY, LIMIT, FOR + * UPDATE, or WITH to a VALUES clause and also multiple + * VALUES clauses. If we have any of those, ERROR. + */ + if (selectStmt && (selectStmt->valuesLists == NIL || + selectStmt->sortClause != NIL || + selectStmt->limitOffset != NULL || + selectStmt->limitCount != NULL || + selectStmt->lockingClause != NIL || + selectStmt->withClause != NULL)) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("SELECT not allowed in MERGE INSERT statement"))); + + if (selectStmt && list_length(selectStmt->valuesLists) > 1) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("Multiple VALUES clauses not allowed in MERGE INSERT statement"))); + + targetPerms |= ACL_INSERT; + } + break; + case CMD_UPDATE: + targetPerms |= ACL_UPDATE; + break; + case CMD_DELETE: + targetPerms |= ACL_DELETE; + break; + case CMD_NOTHING: + break; + default: + elog(ERROR, "unknown action in MERGE WHEN clause"); + } + + /* + * Check for unreachable WHEN clauses + */ + if (action->condition == NULL) + is_terminal[when_type] = true; + else if (is_terminal[when_type]) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("unreachable WHEN clause specified after unconditional WHEN clause"))); + } + + /* + * Construct a query of the form + * SELECT relation.ctid --junk attribute + * ,relation.tableoid --junk attribute + * ,source_relation. + * ,relation. + * FROM relation RIGHT JOIN source_relation + * ON join_condition; -- no WHERE clause - all conditions are applied in + * executor + * + * stmt->relation is the target relation, given as a RangeVar + * stmt->source_relation is a RangeVar or subquery + * + * We specify the join as a RIGHT JOIN as a simple way of forcing the + * first (larg) RTE to refer to the target table. + * + * The MERGE query's join can be tuned in some cases, see below for these + * special case tweaks. + * + * We set QSRC_PARSER to show query constructed in parse analysis + * + * Note that we have only one Query for a MERGE statement and the planner + * is called only once. That query is executed once to produce our stream + * of candidate change rows, so the query must contain all of the columns + * required by each of the targetlist or conditions for each action. + * + * As top-level statements INSERT, UPDATE and DELETE have a Query, whereas + * with MERGE the individual actions do not require separate planning, + * only different handling in the executor. See nodeModifyTable handling + * of commandType CMD_MERGE. + * + * A sub-query can include the Target, but otherwise the sub-query cannot + * reference the outermost Target table at all. + */ + qry->querySource = QSRC_PARSER; + + /* + * Setup the target table. Unlike regular UPDATE/DELETE, we don't expand + * inheritance for the target relation in case of MERGE. + * + * This special arrangement is required for handling partitioned tables + * because we perform an JOIN between the target and the source relation to + * identify the matching and not-matching rows. If we take the usual path + * of expanding the target table's inheritance and create one subplan per + * partition, then we we won't be able to correctly identify the matching + * and not-matching rows since for a given source row, there may not be a + * matching row in one partition, but it may exists in some other + * partition. So we must first append all the qualifying rows from all the + * partitions and then do the matching. + * + * Once a target row is returned by the underlying join, we find the + * correct partition and setup required state to carry out UPDATE/DELETE. + * All of this happens during execution. + */ + qry->resultRelation = setTargetTable(pstate, stmt->relation, + false, /* do not expand inheritance */ + true, targetPerms); + + /* + * Create a JOIN between the target and the source relation. + */ + joinexpr = makeNode(JoinExpr); + joinexpr->isNatural = false; + joinexpr->alias = NULL; + joinexpr->usingClause = NIL; + joinexpr->quals = stmt->join_condition; + joinexpr->larg = (Node *) stmt->relation; + joinexpr->rarg = (Node *) stmt->source_relation; + + /* + * Simplify the MERGE query as much as possible + * + * These seem like things that could go into Optimizer, but they are + * semantic simplifications rather than optimizations, per se. + * + * If there are no INSERT actions we won't be using the non-matching + * candidate rows for anything, so no need for an outer join. We do still + * need an inner join for UPDATE and DELETE actions. + */ + if (targetPerms & ACL_INSERT) + joinexpr->jointype = JOIN_RIGHT; + else + joinexpr->jointype = JOIN_INNER; + + /* + * We use a special purpose transformation here because the normal + * routines don't quite work right for the MERGE case. + * + * A special mergeSourceTargetList is setup by transformMergeJoinClause(). + * It refers to all the attributes provided by the source relation. This + * is later used by set_plan_refs() to fix the UPDATE/INSERT target lists + * to so that they can correctly fetch the attributes from the source + * relation. + * + * The target relation when used in the underlying join, gets a new RTE + * with rte->inh set to true. We remember this RTE (and later pass on to + * the planner and executor) for two main reasons: + * + * 1. If we ever need to run EvalPlanQual while performing MERGE, we must + * make the modified tuple available to the underlying join query, which is + * using a different RTE from the resultRelation RTE. + * + * 2. rewriteTargetListMerge() requires the RTE of the underlying join in + * order to add junk CTID and TABLEOID attributes. + */ + qry->mergeTarget_relation = transformMergeJoinClause(pstate, (Node *) joinexpr, + &qry->mergeSourceTargetList); + + /* + * The target table referenced in the MERGE is looked up twice; once while + * setting it up as the result relation and again when it's used in the + * underlying the join query. In some rare situations, it may happen that + * these lookups return different results, for example, if a new relation + * with the same name gets created in a schema which is ahead in the + * search_path, in between the two lookups. + * + * It's a very narrow case, but nevertheless we guard against it by simply + * checking if the OIDs returned by the two lookups is the same. If not, we + * just throw an error. + */ + Assert(qry->resultRelation > 0); + Assert(qry->mergeTarget_relation > 0); + + /* Fetch both the RTEs */ + resultRelRTE = rt_fetch(qry->resultRelation, pstate->p_rtable); + mergeRelRTE = rt_fetch(qry->mergeTarget_relation, pstate->p_rtable); + + if (resultRelRTE->relid != mergeRelRTE->relid) + ereport(ERROR, + (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), + errmsg("relation referenced by MERGE statement has changed"))); + + /* + * This query should just provide the source relation columns. Later, in + * preprocess_targetlist(), we shall also add "ctid" attribute of the + * target relation to ensure that the target tuple can be fetched + * correctly. + */ + qry->targetList = qry->mergeSourceTargetList; + + /* qry has no WHERE clause so absent quals are shown as NULL */ + qry->jointree = makeFromExpr(pstate->p_joinlist, NULL); + qry->rtable = pstate->p_rtable; + + /* + * XXX MERGE is unsupported in various cases + */ + if (!(pstate->p_target_relation->rd_rel->relkind == RELKIND_RELATION || + pstate->p_target_relation->rd_rel->relkind == RELKIND_PARTITIONED_TABLE)) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("MERGE is not supported for this relation type"))); + + if (pstate->p_target_relation->rd_rel->relkind != RELKIND_PARTITIONED_TABLE && + pstate->p_target_relation->rd_rel->relhassubclass) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("MERGE is not supported for relations with inheritance"))); + + if (pstate->p_target_relation->rd_rel->relhasrules) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("MERGE is not supported for relations with rules"))); + + /* + * We now have a good query shape, so now look at the when conditions and + * action targetlists. + * + * Overall, the MERGE Query's targetlist is NIL. + * + * Each individual action has its own targetlist that needs separate + * transformation. These transforms don't do anything to the overall + * targetlist, since that is only used for resjunk columns. + * + * We can reference any column in Target or Source, which is OK because + * both of those already have RTEs. There is nothing like the EXCLUDED + * pseudo-relation for INSERT ON CONFLICT. + */ + foreach(l, stmt->mergeActionList) + { + MergeAction *action = (MergeAction *) lfirst(l); + + /* + * Set namespace for the specific action. This must be done before + * analyzing the WHEN quals and the action targetlisst. + */ + setNamespaceForMergeAction(pstate, action); + + /* + * Transform the when condition. + * + * Note that these quals are NOT added to the join quals; instead they + * are evaluated separately during execution to decide which of the + * WHEN MATCHED or WHEN NOT MATCHED actions to execute. + */ + action->qual = transformWhereClause(pstate, action->condition, + EXPR_KIND_MERGE_WHEN_AND, "WHEN"); + + /* + * Transform target lists for each INSERT and UPDATE action stmt + */ + switch (action->commandType) + { + case CMD_INSERT: + { + InsertStmt *istmt = (InsertStmt *) action->stmt; + SelectStmt *selectStmt = (SelectStmt *) istmt->selectStmt; + List *exprList = NIL; + ListCell *lc; + RangeTblEntry *rte; + ListCell *icols; + ListCell *attnos; + List *icolumns; + List *attrnos; + + pstate->p_is_insert = true; + + icolumns = checkInsertTargets(pstate, istmt->cols, &attrnos); + Assert(list_length(icolumns) == list_length(attrnos)); + + /* + * Handle INSERT much like in transformInsertStmt + */ + if (selectStmt == NULL) + { + /* + * We have INSERT ... DEFAULT VALUES. We can handle + * this case by emitting an empty targetlist --- all + * columns will be defaulted when the planner expands + * the targetlist. + */ + exprList = NIL; + } + else + { + /* + * Process INSERT ... VALUES with a single VALUES + * sublist. We treat this case separately for + * efficiency. The sublist is just computed directly + * as the Query's targetlist, with no VALUES RTE. So + * it works just like a SELECT without any FROM. + */ + List *valuesLists = selectStmt->valuesLists; + + Assert(list_length(valuesLists) == 1); + Assert(selectStmt->intoClause == NULL); + + /* + * Do basic expression transformation (same as a ROW() + * expr, but allow SetToDefault at top level) + */ + exprList = transformExpressionList(pstate, + (List *) linitial(valuesLists), + EXPR_KIND_VALUES_SINGLE, + true); + + /* Prepare row for assignment to target table */ + exprList = transformInsertRow(pstate, exprList, + istmt->cols, + icolumns, attrnos, + false); + } + + /* + * Generate action's target list using the computed list + * of expressions. Also, mark all the target columns as + * needing insert permissions. + */ + rte = pstate->p_target_rangetblentry; + icols = list_head(icolumns); + attnos = list_head(attrnos); + foreach(lc, exprList) + { + Expr *expr = (Expr *) lfirst(lc); + ResTarget *col; + AttrNumber attr_num; + TargetEntry *tle; + + col = lfirst_node(ResTarget, icols); + attr_num = (AttrNumber) lfirst_int(attnos); + + tle = makeTargetEntry(expr, + attr_num, + col->name, + false); + action->targetList = lappend(action->targetList, tle); + + rte->insertedCols = bms_add_member(rte->insertedCols, + attr_num - FirstLowInvalidHeapAttributeNumber); + + icols = lnext(icols); + attnos = lnext(attnos); + } + } + break; + case CMD_UPDATE: + { + UpdateStmt *ustmt = (UpdateStmt *) action->stmt; + + pstate->p_is_insert = false; + action->targetList = transformUpdateTargetList(pstate, ustmt->targetList); + } + break; + case CMD_DELETE: + break; + + case CMD_NOTHING: + action->targetList = NIL; + break; + default: + elog(ERROR, "unknown action in MERGE WHEN clause"); + } + } + + qry->mergeActionList = stmt->mergeActionList; + + /* XXX maybe later */ + qry->returningList = NULL; + + qry->hasTargetSRFs = false; + qry->hasSubLinks = pstate->p_hasSubLinks; + + assign_query_collations(pstate, qry); + + return qry; +} + +static void +setNamespaceVisibilityForRTE(List *namespace, RangeTblEntry *rte, + bool rel_visible, + bool cols_visible) +{ + ListCell *lc; + + foreach(lc, namespace) + { + ParseNamespaceItem *nsitem = (ParseNamespaceItem *) lfirst(lc); + + if (nsitem->p_rte == rte) + { + nsitem->p_rel_visible = rel_visible; + nsitem->p_cols_visible = cols_visible; + break; + } + } + +} + +/* + * Expand the source relation to include all attributes of this RTE. + * + * This function is very similar to expandRelAttrs except that we don't mark + * columns for SELECT privileges. That will be decided later when we transform + * the action targetlists and the WHEN quals for actual references to the + * source relation. + */ +static List * +expandSourceTL(ParseState *pstate, RangeTblEntry *rte, int rtindex) +{ + List *names, + *vars; + ListCell *name, + *var; + List *te_list = NIL; + + expandRTE(rte, rtindex, 0, -1, false, &names, &vars); + + /* + * Require read access to the table. + */ + rte->requiredPerms |= ACL_SELECT; + + forboth(name, names, var, vars) + { + char *label = strVal(lfirst(name)); + Var *varnode = (Var *) lfirst(var); + TargetEntry *te; + + te = makeTargetEntry((Expr *) varnode, + (AttrNumber) pstate->p_next_resno++, + label, + false); + te_list = lappend(te_list, te); + } + + Assert(name == NULL && var == NULL); /* lists not the same length? */ + + return te_list; +} diff --git a/src/include/executor/nodeMerge.h b/src/include/executor/nodeMerge.h new file mode 100644 index 0000000000..c222e9ee65 --- /dev/null +++ b/src/include/executor/nodeMerge.h @@ -0,0 +1,22 @@ +/*------------------------------------------------------------------------- + * + * nodeMerge.h + * + * + * Portions Copyright (c) 1996-2018, PostgreSQL Global Development Group + * Portions Copyright (c) 1994, Regents of the University of California + * + * src/include/executor/nodeMerge.h + * + *------------------------------------------------------------------------- + */ +#ifndef NODEMERGE_H +#define NODEMERGE_H + +#include "nodes/execnodes.h" + +extern void +ExecMerge(ModifyTableState *mtstate, EState *estate, TupleTableSlot *slot, + JunkFilter *junkfilter, ResultRelInfo *resultRelInfo); + +#endif /* NODEMERGE_H */ diff --git a/src/include/parser/parse_merge.h b/src/include/parser/parse_merge.h new file mode 100644 index 0000000000..0151809e09 --- /dev/null +++ b/src/include/parser/parse_merge.h @@ -0,0 +1,19 @@ +/*------------------------------------------------------------------------- + * + * parse_merge.h + * handle merge-stmt in parser + * + * + * Portions Copyright (c) 1996-2018, PostgreSQL Global Development Group + * Portions Copyright (c) 1994, Regents of the University of California + * + * src/include/parser/parse_merge.h + * + *------------------------------------------------------------------------- + */ +#ifndef PARSE_MERGE_H +#define PARSE_MERGE_H + +#include "parser/parse_node.h" +extern Query *transformMergeStmt(ParseState *pstate, MergeStmt *stmt); +#endif diff --git a/src/test/isolation/expected/merge-delete.out b/src/test/isolation/expected/merge-delete.out new file mode 100644 index 0000000000..40e62901b7 --- /dev/null +++ b/src/test/isolation/expected/merge-delete.out @@ -0,0 +1,97 @@ +Parsed test spec with 2 sessions + +starting permutation: delete c1 select2 c2 +step delete: DELETE FROM target t WHERE t.key = 1; +step c1: COMMIT; +step select2: SELECT * FROM target; +key val + +step c2: COMMIT; + +starting permutation: merge_delete c1 select2 c2 +step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; +step c1: COMMIT; +step select2: SELECT * FROM target; +key val + +step c2: COMMIT; + +starting permutation: delete c1 update1 select2 c2 +step delete: DELETE FROM target t WHERE t.key = 1; +step c1: COMMIT; +step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; +step select2: SELECT * FROM target; +key val + +step c2: COMMIT; + +starting permutation: merge_delete c1 update1 select2 c2 +step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; +step c1: COMMIT; +step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; +step select2: SELECT * FROM target; +key val + +step c2: COMMIT; + +starting permutation: delete c1 merge2 select2 c2 +step delete: DELETE FROM target t WHERE t.key = 1; +step c1: COMMIT; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +step select2: SELECT * FROM target; +key val + +1 merge2a +step c2: COMMIT; + +starting permutation: merge_delete c1 merge2 select2 c2 +step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; +step c1: COMMIT; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +step select2: SELECT * FROM target; +key val + +1 merge2a +step c2: COMMIT; + +starting permutation: delete update1 c1 select2 c2 +step delete: DELETE FROM target t WHERE t.key = 1; +step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; +step c1: COMMIT; +step update1: <... completed> +step select2: SELECT * FROM target; +key val + +step c2: COMMIT; + +starting permutation: merge_delete update1 c1 select2 c2 +step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; +step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; +step c1: COMMIT; +step update1: <... completed> +step select2: SELECT * FROM target; +key val + +step c2: COMMIT; + +starting permutation: delete merge2 c1 select2 c2 +step delete: DELETE FROM target t WHERE t.key = 1; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +step c1: COMMIT; +step merge2: <... completed> +step select2: SELECT * FROM target; +key val + +1 merge2a +step c2: COMMIT; + +starting permutation: merge_delete merge2 c1 select2 c2 +step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +step c1: COMMIT; +step merge2: <... completed> +step select2: SELECT * FROM target; +key val + +1 merge2a +step c2: COMMIT; diff --git a/src/test/isolation/expected/merge-insert-update.out b/src/test/isolation/expected/merge-insert-update.out new file mode 100644 index 0000000000..317fa16a3d --- /dev/null +++ b/src/test/isolation/expected/merge-insert-update.out @@ -0,0 +1,84 @@ +Parsed test spec with 2 sessions + +starting permutation: merge1 c1 select2 c2 +step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; +step c1: COMMIT; +step select2: SELECT * FROM target; +key val + +1 merge1 +step c2: COMMIT; + +starting permutation: merge1 c1 merge2 select2 c2 +step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; +step c1: COMMIT; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step select2: SELECT * FROM target; +key val + +1 merge1 updated by merge2 +step c2: COMMIT; + +starting permutation: insert1 merge2 c1 select2 c2 +step insert1: INSERT INTO target VALUES (1, 'insert1'); +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step c1: COMMIT; +step merge2: <... completed> +error in steps c1 merge2: ERROR: duplicate key value violates unique constraint "target_pkey" +step select2: SELECT * FROM target; +ERROR: current transaction is aborted, commands ignored until end of transaction block +step c2: COMMIT; + +starting permutation: merge1 merge2 c1 select2 c2 +step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step c1: COMMIT; +step merge2: <... completed> +error in steps c1 merge2: ERROR: duplicate key value violates unique constraint "target_pkey" +step select2: SELECT * FROM target; +ERROR: current transaction is aborted, commands ignored until end of transaction block +step c2: COMMIT; + +starting permutation: merge1 merge2 a1 select2 c2 +step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step a1: ABORT; +step merge2: <... completed> +step select2: SELECT * FROM target; +key val + +1 merge2 +step c2: COMMIT; + +starting permutation: delete1 insert1 c1 merge2 select2 c2 +step delete1: DELETE FROM target WHERE key = 1; +step insert1: INSERT INTO target VALUES (1, 'insert1'); +step c1: COMMIT; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step select2: SELECT * FROM target; +key val + +1 insert1 updated by merge2 +step c2: COMMIT; + +starting permutation: delete1 insert1 merge2 c1 select2 c2 +step delete1: DELETE FROM target WHERE key = 1; +step insert1: INSERT INTO target VALUES (1, 'insert1'); +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step c1: COMMIT; +step merge2: <... completed> +error in steps c1 merge2: ERROR: duplicate key value violates unique constraint "target_pkey" +step select2: SELECT * FROM target; +ERROR: current transaction is aborted, commands ignored until end of transaction block +step c2: COMMIT; + +starting permutation: delete1 insert1 merge2i c1 select2 c2 +step delete1: DELETE FROM target WHERE key = 1; +step insert1: INSERT INTO target VALUES (1, 'insert1'); +step merge2i: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step c1: COMMIT; +step select2: SELECT * FROM target; +key val + +1 insert1 +step c2: COMMIT; diff --git a/src/test/isolation/expected/merge-match-recheck.out b/src/test/isolation/expected/merge-match-recheck.out new file mode 100644 index 0000000000..96a9f45ac8 --- /dev/null +++ b/src/test/isolation/expected/merge-match-recheck.out @@ -0,0 +1,106 @@ +Parsed test spec with 2 sessions + +starting permutation: update1 merge_status c2 select1 c1 +step update1: UPDATE target t SET balance = balance + 10, val = t.val || ' updated by update1' WHERE t.key = 1; +step merge_status: + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND status = 's1' THEN + UPDATE SET status = 's2', val = t.val || ' when1' + WHEN MATCHED AND status = 's2' THEN + UPDATE SET status = 's3', val = t.val || ' when2' + WHEN MATCHED AND status = 's3' THEN + UPDATE SET status = 's4', val = t.val || ' when3'; + +step c2: COMMIT; +step merge_status: <... completed> +step select1: SELECT * FROM target; +key balance status val + +1 170 s2 setup updated by update1 when1 +step c1: COMMIT; + +starting permutation: update2 merge_status c2 select1 c1 +step update2: UPDATE target t SET status = 's2', val = t.val || ' updated by update2' WHERE t.key = 1; +step merge_status: + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND status = 's1' THEN + UPDATE SET status = 's2', val = t.val || ' when1' + WHEN MATCHED AND status = 's2' THEN + UPDATE SET status = 's3', val = t.val || ' when2' + WHEN MATCHED AND status = 's3' THEN + UPDATE SET status = 's4', val = t.val || ' when3'; + +step c2: COMMIT; +step merge_status: <... completed> +step select1: SELECT * FROM target; +key balance status val + +1 160 s3 setup updated by update2 when2 +step c1: COMMIT; + +starting permutation: update3 merge_status c2 select1 c1 +step update3: UPDATE target t SET status = 's3', val = t.val || ' updated by update3' WHERE t.key = 1; +step merge_status: + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND status = 's1' THEN + UPDATE SET status = 's2', val = t.val || ' when1' + WHEN MATCHED AND status = 's2' THEN + UPDATE SET status = 's3', val = t.val || ' when2' + WHEN MATCHED AND status = 's3' THEN + UPDATE SET status = 's4', val = t.val || ' when3'; + +step c2: COMMIT; +step merge_status: <... completed> +step select1: SELECT * FROM target; +key balance status val + +1 160 s4 setup updated by update3 when3 +step c1: COMMIT; + +starting permutation: update5 merge_status c2 select1 c1 +step update5: UPDATE target t SET status = 's5', val = t.val || ' updated by update5' WHERE t.key = 1; +step merge_status: + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND status = 's1' THEN + UPDATE SET status = 's2', val = t.val || ' when1' + WHEN MATCHED AND status = 's2' THEN + UPDATE SET status = 's3', val = t.val || ' when2' + WHEN MATCHED AND status = 's3' THEN + UPDATE SET status = 's4', val = t.val || ' when3'; + +step c2: COMMIT; +step merge_status: <... completed> +step select1: SELECT * FROM target; +key balance status val + +1 160 s5 setup updated by update5 +step c1: COMMIT; + +starting permutation: update_bal1 merge_bal c2 select1 c1 +step update_bal1: UPDATE target t SET balance = 50, val = t.val || ' updated by update_bal1' WHERE t.key = 1; +step merge_bal: + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND balance < 100 THEN + UPDATE SET balance = balance * 2, val = t.val || ' when1' + WHEN MATCHED AND balance < 200 THEN + UPDATE SET balance = balance * 4, val = t.val || ' when2' + WHEN MATCHED AND balance < 300 THEN + UPDATE SET balance = balance * 8, val = t.val || ' when3'; + +step c2: COMMIT; +step merge_bal: <... completed> +step select1: SELECT * FROM target; +key balance status val + +1 100 s1 setup updated by update_bal1 when1 +step c1: COMMIT; diff --git a/src/test/isolation/expected/merge-update.out b/src/test/isolation/expected/merge-update.out new file mode 100644 index 0000000000..60ae42ebd0 --- /dev/null +++ b/src/test/isolation/expected/merge-update.out @@ -0,0 +1,213 @@ +Parsed test spec with 2 sessions + +starting permutation: merge1 c1 select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step select2: SELECT * FROM target; +key val + +2 setup1 updated by merge1 +step c2: COMMIT; + +starting permutation: merge1 c1 merge2a select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step merge2a: + MERGE INTO target t + USING (SELECT 1 as key, 'merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step select2: SELECT * FROM target; +key val + +2 setup1 updated by merge1 +1 merge2a +step c2: COMMIT; + +starting permutation: merge1 merge2a c1 select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step merge2a: + MERGE INTO target t + USING (SELECT 1 as key, 'merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step merge2a: <... completed> +step select2: SELECT * FROM target; +key val + +2 setup1 updated by merge1 +1 merge2a +step c2: COMMIT; + +starting permutation: merge1 merge2a a1 select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step merge2a: + MERGE INTO target t + USING (SELECT 1 as key, 'merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step a1: ABORT; +step merge2a: <... completed> +step select2: SELECT * FROM target; +key val + +2 setup1 updated by merge2a +step c2: COMMIT; + +starting permutation: merge1 merge2b c1 select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step merge2b: + MERGE INTO target t + USING (SELECT 1 as key, 'merge2b' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED AND t.key < 2 THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step merge2b: <... completed> +step select2: SELECT * FROM target; +key val + +2 setup1 updated by merge1 +1 merge2b +step c2: COMMIT; + +starting permutation: merge1 merge2c c1 select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step merge2c: + MERGE INTO target t + USING (SELECT 1 as key, 'merge2c' as val) s + ON s.key = t.key AND t.key < 2 + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step merge2c: <... completed> +step select2: SELECT * FROM target; +key val + +2 setup1 updated by merge1 +1 merge2c +step c2: COMMIT; + +starting permutation: pa_merge1 pa_merge2a c1 pa_select2 c2 +step pa_merge1: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set val = t.val || ' updated by ' || s.val; + +step pa_merge2a: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step pa_merge2a: <... completed> +step pa_select2: SELECT * FROM pa_target; +key val + +2 initial +2 initial updated by pa_merge2a +step c2: COMMIT; + +starting permutation: pa_merge2 pa_merge2a c1 pa_select2 c2 +step pa_merge2: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step pa_merge2a: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step pa_merge2a: <... completed> +step pa_select2: SELECT * FROM pa_target; +key val + +1 pa_merge2a +2 initial +2 initial updated by pa_merge1 +step c2: COMMIT; diff --git a/src/test/isolation/specs/merge-delete.spec b/src/test/isolation/specs/merge-delete.spec new file mode 100644 index 0000000000..656954f847 --- /dev/null +++ b/src/test/isolation/specs/merge-delete.spec @@ -0,0 +1,51 @@ +# MERGE DELETE +# +# This test looks at the interactions involving concurrent deletes +# comparing the behavior of MERGE, DELETE and UPDATE + +setup +{ + CREATE TABLE target (key int primary key, val text); + INSERT INTO target VALUES (1, 'setup1'); +} + +teardown +{ + DROP TABLE target; +} + +session "s1" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "delete" { DELETE FROM target t WHERE t.key = 1; } +step "merge_delete" { MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; } +step "c1" { COMMIT; } +step "a1" { ABORT; } + +session "s2" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "update1" { UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; } +step "merge2" { MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; } +step "select2" { SELECT * FROM target; } +step "c2" { COMMIT; } + +# Basic effects +permutation "delete" "c1" "select2" "c2" +permutation "merge_delete" "c1" "select2" "c2" + +# One after the other, no concurrency +permutation "delete" "c1" "update1" "select2" "c2" +permutation "merge_delete" "c1" "update1" "select2" "c2" +permutation "delete" "c1" "merge2" "select2" "c2" +permutation "merge_delete" "c1" "merge2" "select2" "c2" + +# Now with concurrency +permutation "delete" "update1" "c1" "select2" "c2" +permutation "merge_delete" "update1" "c1" "select2" "c2" +permutation "delete" "merge2" "c1" "select2" "c2" +permutation "merge_delete" "merge2" "c1" "select2" "c2" diff --git a/src/test/isolation/specs/merge-insert-update.spec b/src/test/isolation/specs/merge-insert-update.spec new file mode 100644 index 0000000000..704492be1f --- /dev/null +++ b/src/test/isolation/specs/merge-insert-update.spec @@ -0,0 +1,52 @@ +# MERGE INSERT UPDATE +# +# This looks at how we handle concurrent INSERTs, illustrating how the +# behavior differs from INSERT ... ON CONFLICT + +setup +{ + CREATE TABLE target (key int primary key, val text); +} + +teardown +{ + DROP TABLE target; +} + +session "s1" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "merge1" { MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; } +step "delete1" { DELETE FROM target WHERE key = 1; } +step "insert1" { INSERT INTO target VALUES (1, 'insert1'); } +step "c1" { COMMIT; } +step "a1" { ABORT; } + +session "s2" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "merge2" { MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; } + +step "merge2i" { MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; } + +step "select2" { SELECT * FROM target; } +step "c2" { COMMIT; } +step "a2" { ABORT; } + +# Basic effects +permutation "merge1" "c1" "select2" "c2" +permutation "merge1" "c1" "merge2" "select2" "c2" + +# check concurrent inserts +permutation "insert1" "merge2" "c1" "select2" "c2" +permutation "merge1" "merge2" "c1" "select2" "c2" +permutation "merge1" "merge2" "a1" "select2" "c2" + +# check how we handle when visible row has been concurrently deleted, then same key re-inserted +permutation "delete1" "insert1" "c1" "merge2" "select2" "c2" +permutation "delete1" "insert1" "merge2" "c1" "select2" "c2" +permutation "delete1" "insert1" "merge2i" "c1" "select2" "c2" diff --git a/src/test/isolation/specs/merge-match-recheck.spec b/src/test/isolation/specs/merge-match-recheck.spec new file mode 100644 index 0000000000..193033da17 --- /dev/null +++ b/src/test/isolation/specs/merge-match-recheck.spec @@ -0,0 +1,79 @@ +# MERGE MATCHED RECHECK +# +# This test looks at what happens when we have complex +# WHEN MATCHED AND conditions and a concurrent UPDATE causes a +# recheck of the AND condition on the new row + +setup +{ + CREATE TABLE target (key int primary key, balance integer, status text, val text); + INSERT INTO target VALUES (1, 160, 's1', 'setup'); +} + +teardown +{ + DROP TABLE target; +} + +session "s1" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "merge_status" +{ + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND status = 's1' THEN + UPDATE SET status = 's2', val = t.val || ' when1' + WHEN MATCHED AND status = 's2' THEN + UPDATE SET status = 's3', val = t.val || ' when2' + WHEN MATCHED AND status = 's3' THEN + UPDATE SET status = 's4', val = t.val || ' when3'; +} + +step "merge_bal" +{ + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND balance < 100 THEN + UPDATE SET balance = balance * 2, val = t.val || ' when1' + WHEN MATCHED AND balance < 200 THEN + UPDATE SET balance = balance * 4, val = t.val || ' when2' + WHEN MATCHED AND balance < 300 THEN + UPDATE SET balance = balance * 8, val = t.val || ' when3'; +} + +step "select1" { SELECT * FROM target; } +step "c1" { COMMIT; } +step "a1" { ABORT; } + +session "s2" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "update1" { UPDATE target t SET balance = balance + 10, val = t.val || ' updated by update1' WHERE t.key = 1; } +step "update2" { UPDATE target t SET status = 's2', val = t.val || ' updated by update2' WHERE t.key = 1; } +step "update3" { UPDATE target t SET status = 's3', val = t.val || ' updated by update3' WHERE t.key = 1; } +step "update5" { UPDATE target t SET status = 's5', val = t.val || ' updated by update5' WHERE t.key = 1; } +step "update_bal1" { UPDATE target t SET balance = 50, val = t.val || ' updated by update_bal1' WHERE t.key = 1; } +step "select2" { SELECT * FROM target; } +step "c2" { COMMIT; } + +# merge_status sees concurrently updated row and rechecks WHEN conditions, but recheck passes and final status = 's2' +permutation "update1" "merge_status" "c2" "select1" "c1" + +# merge_status sees concurrently updated row and rechecks WHEN conditions, recheck fails, so final status = 's3' not 's2' +permutation "update2" "merge_status" "c2" "select1" "c1" + +# merge_status sees concurrently updated row and rechecks WHEN conditions, recheck fails, so final status = 's4' not 's2' +permutation "update3" "merge_status" "c2" "select1" "c1" + +# merge_status sees concurrently updated row and rechecks WHEN conditions, recheck fails, but we skip update and MERGE does nothing +permutation "update5" "merge_status" "c2" "select1" "c1" + +# merge_bal sees concurrently updated row and rechecks WHEN conditions, recheck fails, so final balance = 100 not 640 +permutation "update_bal1" "merge_bal" "c2" "select1" "c1" diff --git a/src/test/isolation/specs/merge-update.spec b/src/test/isolation/specs/merge-update.spec new file mode 100644 index 0000000000..64e849966e --- /dev/null +++ b/src/test/isolation/specs/merge-update.spec @@ -0,0 +1,132 @@ +# MERGE UPDATE +# +# This test exercises atypical cases +# 1. UPDATEs of PKs that change the join in the ON clause +# 2. UPDATEs with WHEN AND conditions that would fail after concurrent update +# 3. UPDATEs with extra ON conditions that would fail after concurrent update + +setup +{ + CREATE TABLE target (key int primary key, val text); + INSERT INTO target VALUES (1, 'setup1'); + + CREATE TABLE pa_target (key integer, val text) + PARTITION BY LIST (key); + CREATE TABLE part1 (key integer, val text); + CREATE TABLE part2 (val text, key integer); + CREATE TABLE part3 (key integer, val text); + + 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 DEFAULT; + + INSERT INTO pa_target VALUES (1, 'initial'); + INSERT INTO pa_target VALUES (2, 'initial'); +} + +teardown +{ + DROP TABLE target; + DROP TABLE pa_target CASCADE; +} + +session "s1" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "merge1" +{ + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "pa_merge1" +{ + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set val = t.val || ' updated by ' || s.val; +} +step "pa_merge2" +{ + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "c1" { COMMIT; } +step "a1" { ABORT; } + +session "s2" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "merge2a" +{ + MERGE INTO target t + USING (SELECT 1 as key, 'merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "merge2b" +{ + MERGE INTO target t + USING (SELECT 1 as key, 'merge2b' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED AND t.key < 2 THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "merge2c" +{ + MERGE INTO target t + USING (SELECT 1 as key, 'merge2c' as val) s + ON s.key = t.key AND t.key < 2 + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "pa_merge2a" +{ + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "select2" { SELECT * FROM target; } +step "pa_select2" { SELECT * FROM pa_target; } +step "c2" { COMMIT; } + +# Basic effects +permutation "merge1" "c1" "select2" "c2" + +# One after the other, no concurrency +permutation "merge1" "c1" "merge2a" "select2" "c2" + +# Now with concurrency +permutation "merge1" "merge2a" "c1" "select2" "c2" +permutation "merge1" "merge2a" "a1" "select2" "c2" +permutation "merge1" "merge2b" "c1" "select2" "c2" +permutation "merge1" "merge2c" "c1" "select2" "c2" +permutation "pa_merge1" "pa_merge2a" "c1" "pa_select2" "c2" +permutation "pa_merge2" "pa_merge2a" "c1" "pa_select2" "c2" diff --git a/src/test/regress/expected/merge.out b/src/test/regress/expected/merge.out new file mode 100644 index 0000000000..b7e42515e2 --- /dev/null +++ b/src/test/regress/expected/merge.out @@ -0,0 +1,1673 @@ +-- +-- MERGE +-- +--\set VERBOSITY verbose +--set debug_print_rewritten = true; +--set debug_print_parse = true; +--set debug_print_pretty = true; +CREATE USER merge_privs; +CREATE USER 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); +CREATE TABLE source (sid integer, delta integer); --no index +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 merge_privs; +ALTER TABLE source OWNER TO merge_privs; +CREATE TABLE target2 (tid integer, balance integer); +CREATE TABLE source2 (sid integer, delta integer); +ALTER TABLE target2 OWNER TO merge_no_privs; +ALTER TABLE source2 OWNER TO merge_no_privs; +GRANT INSERT ON target TO merge_no_privs; +SET SESSION AUTHORIZATION merge_privs; +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE +; + QUERY PLAN +------------------------------------------ + Merge on target t + -> Merge Join + Merge Cond: (t_1.tid = s.sid) + -> Sort + Sort Key: t_1.tid + -> Seq Scan on target t_1 + -> Sort + Sort Key: s.sid + -> Seq Scan on source s +(9 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" +LINE 1: MERGE INTO target t 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" +LINE 5: 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 +; +ERROR: syntax error at or near "INTO" +LINE 5: 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); +ERROR: Multiple VALUES clauses not allowed in MERGE INSERT statement +; +-- 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" +LINE 5: 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 +; +ERROR: syntax error at or near "UPDATE" +LINE 5: 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 +; +ERROR: syntax error at or near "target" +LINE 5: UPDATE target SET balance = 0 + ^ +-- 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: MERGE is not supported for this relation type +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: MERGE is not supported for this relation type +DROP MATERIALIZED VIEW mv; +-- inherited table +CREATE TABLE inhp (tid int, balance int); +CREATE TABLE child1() INHERITS (inhp); +CREATE TABLE child2() INHERITS (child1); +MERGE INTO inhp t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: MERGE is not supported for relations with inheritance +MERGE INTO child1 t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: MERGE is not supported for relations with inheritance +-- this should be ok +MERGE INTO child2 t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +DROP TABLE inhp, child1, child2; +-- 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 merge_no_privs; +SET SESSION AUTHORIZATION 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 merge_privs; +SET SESSION AUTHORIZATION 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" +LINE 2: USING (SELECT * FROM source WHERE t.tid > sid) s + ^ +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 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 +------------------------------------------ + Merge on target t + -> Hash Join + Hash Cond: (s.sid = t_1.tid) + -> Seq Scan on source s + -> Hash + -> Seq Scan on target t_1 +(6 rows) + +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE +; + QUERY PLAN +------------------------------------------ + Merge on target t + -> Hash Join + Hash Cond: (s.sid = t_1.tid) + -> Seq Scan on source s + -> Hash + -> Seq Scan on target t_1 +(6 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 +------------------------------------------ + Merge on target t + -> Hash Left Join + Hash Cond: (s.sid = t_1.tid) + -> Seq Scan on source s + -> Hash + -> Seq Scan on target t_1 +(6 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 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; +-- correct 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) + +-- remove constraints +alter table target drop CONSTRAINT target_pkey; +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 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" +LINE 5: INSERT (tid, balance) VALUES (t.tid, s.delta) + ^ +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" +LINE 5: INSERT (tid, balance) VALUES (t.tid, s.delta) + ^ +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); +CREATE TABLE wq_source (balance integer, sid integer); +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" +LINE 3: WHEN NOT MATCHED AND t.balance = 100 THEN + ^ +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 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: system column "xmin" reference in WHEN AND condition is invalid +LINE 3: WHEN MATCHED AND t.xmin = t.xmax THEN + ^ +ALTER TABLE wq_target SET WITH OIDS; +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | 399 +(1 row) + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.oid >= 0 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | 499 +(1 row) + +-- test preventing WHEN AND 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 +$$ +BEGIN + RAISE NOTICE '% % % trigger', TG_WHEN, TG_OP, TG_LEVEL; + 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 +NOTICE: AFTER UPDATE ROW trigger +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 INSERT ROW trigger +NOTICE: BEFORE DELETE ROW trigger +NOTICE: BEFORE UPDATE ROW trigger +NOTICE: AFTER INSERT ROW trigger +NOTICE: AFTER DELETE ROW trigger +NOTICE: AFTER UPDATE ROW trigger +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 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 +NOTICE: BEFORE UPDATE ROW trigger +NOTICE: AFTER UPDATE ROW trigger +NOTICE: AFTER UPDATE ROW trigger +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 +NOTICE: AFTER INSERT ROW trigger +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 +NOTICE: AFTER INSERT ROW trigger +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 +NOTICE: AFTER INSERT ROW trigger +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 +NOTICE: BEFORE UPDATE ROW trigger +NOTICE: BEFORE UPDATE ROW trigger +NOTICE: AFTER UPDATE ROW trigger +NOTICE: AFTER UPDATE ROW trigger +NOTICE: AFTER UPDATE ROW trigger +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 +NOTICE: AFTER INSERT ROW trigger +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 +NOTICE: AFTER UPDATE ROW trigger +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 +NOTICE: AFTER UPDATE ROW trigger +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 +NOTICE: AFTER UPDATE ROW trigger +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); +CREATE TABLE sq_source (delta integer, sid integer, balance integer DEFAULT 0); +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 +LINE 5: UPDATE SET balance = balance + delta + ^ +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 +; +ERROR: syntax error at or near "MERGE" +LINE 4: MERGE INTO sq_target t + ^ +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" +LINE 10: RETURNING * + ^ +ROLLBACK; +-- EXPLAIN +CREATE TABLE ex_mtarget (a int, b int); +CREATE TABLE ex_msource (a int, b int); +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; +-- only updates +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +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 +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +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 +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +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 +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +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 +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +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); +DROP TABLE ex_msource, ex_mtarget; +-- 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); +CREATE TABLE part2 PARTITION OF pa_target FOR VALUES IN (2,5,6); +CREATE TABLE part3 PARTITION OF pa_target FOR VALUES IN (3,8,9); +CREATE TABLE part4 PARTITION OF pa_target DEFAULT; +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; +-- 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); +CREATE TABLE part2 (balance float, tid integer, val text); +CREATE TABLE part3 (tid integer, balance float, val text); +CREATE TABLE part4 (extraid text, tid integer, balance float, val text); +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 = 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_source; +DROP TABLE pa_target CASCADE; +-- Sub-partitionin +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); +CREATE TABLE part_m01_odd PARTITION OF part_m01 + FOR VALUES IN (1,3,5,7,9); +CREATE TABLE part_m01_even PARTITION OF part_m01 + FOR VALUES IN (2,4,6,8); +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); +CREATE TABLE part_m02_even PARTITION OF part_m02 + FOR VALUES IN (2,4,6,8); +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 '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 +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; + 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; +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); +CREATE TABLE cj_source1 (sid1 integer, scat integer, delta integer); +CREATE TABLE cj_source2 (sid2 integer, sval text); +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 unalised 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); +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 +-- prepare +RESET SESSION AUTHORIZATION; +DROP TABLE target, target2; +DROP TABLE source, source2; +DROP FUNCTION merge_trigfunc(); +DROP USER merge_privs; +DROP USER merge_no_privs; diff --git a/src/test/regress/sql/merge.sql b/src/test/regress/sql/merge.sql new file mode 100644 index 0000000000..f6ef6a9aca --- /dev/null +++ b/src/test/regress/sql/merge.sql @@ -0,0 +1,1173 @@ +-- +-- MERGE +-- +--\set VERBOSITY verbose + +--set debug_print_rewritten = true; +--set debug_print_parse = true; +--set debug_print_pretty = true; + + +CREATE USER merge_privs; +CREATE USER merge_no_privs; +DROP TABLE IF EXISTS target; +DROP TABLE IF EXISTS source; +CREATE TABLE target (tid integer, balance integer); +CREATE TABLE source (sid integer, delta integer); --no index +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 merge_privs; +ALTER TABLE source OWNER TO merge_privs; + +CREATE TABLE target2 (tid integer, balance integer); +CREATE TABLE source2 (sid integer, delta integer); + +ALTER TABLE target2 OWNER TO merge_no_privs; +ALTER TABLE source2 OWNER TO merge_no_privs; + +GRANT INSERT ON target TO merge_no_privs; + +SET SESSION AUTHORIZATION 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 +; + +-- 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; + +-- inherited table +CREATE TABLE inhp (tid int, balance int); +CREATE TABLE child1() INHERITS (inhp); +CREATE TABLE child2() INHERITS (child1); + +MERGE INTO inhp t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; + +MERGE INTO child1 t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; + +-- this should be ok +MERGE INTO child2 t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +DROP TABLE inhp, child1, child2; + +-- permissions + +MERGE INTO target +USING source2 +ON target.tid = source2.sid +WHEN MATCHED THEN + UPDATE SET balance = 0 +; + +GRANT INSERT ON target TO merge_no_privs; +SET SESSION AUTHORIZATION 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 merge_privs; +SET SESSION AUTHORIZATION 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 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 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; + +-- correct 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; + +-- remove constraints +alter table target drop CONSTRAINT target_pkey; +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 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); +CREATE TABLE wq_source (balance integer, sid integer); + +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 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; + +ALTER TABLE wq_target SET WITH OIDS; +SELECT * FROM wq_target; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.oid >= 0 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +-- test preventing WHEN AND 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 +$$ +BEGIN + RAISE NOTICE '% % % trigger', TG_WHEN, TG_OP, TG_LEVEL; + 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 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); +CREATE TABLE sq_source (delta integer, sid integer, balance integer DEFAULT 0); + +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); +CREATE TABLE ex_msource (a int, b int); +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; + +-- only updates +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +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 +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +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 +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +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 +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +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 +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +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); + +DROP TABLE ex_msource, ex_mtarget; + +-- 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); +CREATE TABLE part2 PARTITION OF pa_target FOR VALUES IN (2,5,6); +CREATE TABLE part3 PARTITION OF pa_target FOR VALUES IN (3,8,9); +CREATE TABLE part4 PARTITION OF pa_target DEFAULT; + +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; + +-- 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); +CREATE TABLE part2 (balance float, tid integer, val text); +CREATE TABLE part3 (tid integer, balance float, val text); +CREATE TABLE part4 (extraid text, tid integer, balance float, val text); +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 = 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_source; +DROP TABLE pa_target CASCADE; + +-- Sub-partitionin +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); +CREATE TABLE part_m01_odd PARTITION OF part_m01 + FOR VALUES IN (1,3,5,7,9); +CREATE TABLE part_m01_even PARTITION OF part_m01 + FOR VALUES IN (2,4,6,8); +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); +CREATE TABLE part_m02_even PARTITION OF part_m02 + FOR VALUES IN (2,4,6,8); + +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 '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 +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; + +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); +CREATE TABLE cj_source1 (sid1 integer, scat integer, delta integer); +CREATE TABLE cj_source2 (sid2 integer, sval text); +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 unalised 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); +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 + +-- prepare + +RESET SESSION AUTHORIZATION; +DROP TABLE target, target2; +DROP TABLE source, source2; +DROP FUNCTION merge_trigfunc(); +DROP USER merge_privs; +DROP USER merge_no_privs;