int joinrti;
List *vars;
RangeTblRef *rtr;
+ FromExpr *target;
+ Node *source;
+ int sourcerti;
if (parse->commandType != CMD_MERGE)
return;
* parse->jointree->quals are restrictions on the target relation (if the
* target relation is an auto-updatable view).
*/
+ /* target rel, with any quals */
rtr = makeNode(RangeTblRef);
rtr->rtindex = parse->mergeTargetRelation;
+ target = makeFromExpr(list_make1(rtr), parse->jointree->quals);
+
+ /* source rel (expect exactly one -- see transformMergeStmt()) */
+ Assert(list_length(parse->jointree->fromlist) == 1);
+ source = linitial(parse->jointree->fromlist);
+
+ /*
+ * index of source rel (expect either a RangeTblRef or a JoinExpr -- see
+ * transformFromClauseItem()).
+ */
+ if (IsA(source, RangeTblRef))
+ sourcerti = ((RangeTblRef *) source)->rtindex;
+ else if (IsA(source, JoinExpr))
+ sourcerti = ((JoinExpr *) source)->rtindex;
+ else
+ {
+ elog(ERROR, "unrecognized source node type: %d",
+ (int) nodeTag(source));
+ sourcerti = 0; /* keep compiler quiet */
+ }
+
+ /* Join the source and target */
joinexpr = makeNode(JoinExpr);
joinexpr->jointype = jointype;
joinexpr->isNatural = false;
- joinexpr->larg = (Node *) makeFromExpr(list_make1(rtr), parse->jointree->quals);
- joinexpr->rarg = linitial(parse->jointree->fromlist); /* source rel */
+ joinexpr->larg = (Node *) target;
+ joinexpr->rarg = source;
joinexpr->usingClause = NIL;
joinexpr->join_using_alias = NULL;
joinexpr->quals = parse->mergeJoinCondition;
* use the join condition to distinguish between MATCHED and NOT MATCHED
* BY SOURCE cases. Otherwise, it's no longer needed, and we set it to
* NULL, saving cycles during planning and execution.
- */
- if (!have_action[MERGE_WHEN_NOT_MATCHED_BY_SOURCE])
- parse->mergeJoinCondition = NULL;
+ *
+ * We need to be careful though: the executor evaluates this condition
+ * using the output of the join subplan node, which nulls the output from
+ * the source relation when the join condition doesn't match. That risks
+ * producing incorrect results when rechecking using a "non-strict" join
+ * condition, such as "src.col IS NOT DISTINCT FROM tgt.col". To guard
+ * against that, we add an additional "src IS NOT NULL" check to the join
+ * condition, so that it does the right thing when performing a recheck
+ * based on the output of the join subplan.
+ */
+ if (have_action[MERGE_WHEN_NOT_MATCHED_BY_SOURCE])
+ {
+ Var *var;
+ NullTest *ntest;
+
+ /* source wholerow Var (nullable by the new join) */
+ var = makeWholeRowVar(rt_fetch(sourcerti, parse->rtable),
+ sourcerti, 0, false);
+ var->varnullingrels = bms_make_singleton(joinrti);
+
+ /* "src IS NOT NULL" check */
+ ntest = makeNode(NullTest);
+ ntest->arg = (Expr *) var;
+ ntest->nulltesttype = IS_NOT_NULL;
+ ntest->argisrow = false;
+ ntest->location = -1;
+
+ /* combine it with the original join condition */
+ parse->mergeJoinCondition =
+ (Node *) make_and_qual((Node *) ntest, parse->mergeJoinCondition);
+ }
+ else
+ parse->mergeJoinCondition = NULL; /* join condition not needed */
}
/*
drop cascades to table measurement_y2006m03
drop cascades to table measurement_y2007m01
DROP FUNCTION measurement_insert_trigger();
+--
+-- test non-strict join clause
+--
+CREATE TABLE src (a int, b text);
+INSERT INTO src VALUES (1, 'src row');
+CREATE TABLE tgt (a int, b text);
+INSERT INTO tgt VALUES (NULL, 'tgt row');
+MERGE INTO tgt USING src ON tgt.a IS NOT DISTINCT FROM src.a
+ WHEN MATCHED THEN UPDATE SET a = src.a, b = src.b
+ WHEN NOT MATCHED BY SOURCE THEN DELETE
+ RETURNING merge_action(), src.*, tgt.*;
+ merge_action | a | b | a | b
+--------------+---+---+---+---------
+ DELETE | | | | tgt row
+(1 row)
+
+SELECT * FROM tgt;
+ a | b
+---+---
+(0 rows)
+
+DROP TABLE src, tgt;
-- prepare
RESET SESSION AUTHORIZATION;
-- try a system catalog
DROP TABLE measurement, new_measurement CASCADE;
DROP FUNCTION measurement_insert_trigger();
+--
+-- test non-strict join clause
+--
+CREATE TABLE src (a int, b text);
+INSERT INTO src VALUES (1, 'src row');
+
+CREATE TABLE tgt (a int, b text);
+INSERT INTO tgt VALUES (NULL, 'tgt row');
+
+MERGE INTO tgt USING src ON tgt.a IS NOT DISTINCT FROM src.a
+ WHEN MATCHED THEN UPDATE SET a = src.a, b = src.b
+ WHEN NOT MATCHED BY SOURCE THEN DELETE
+ RETURNING merge_action(), src.*, tgt.*;
+
+SELECT * FROM tgt;
+
+DROP TABLE src, tgt;
+
-- prepare
RESET SESSION AUTHORIZATION;