BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

Started by PG Bug reporting formover 3 years ago35 messages
#1PG Bug reporting form
noreply@postgresql.org

The following bug has been logged on the website:

Bug reference: 17540
Logged by: William Duclot
Email address: william.duclot@gmail.com
PostgreSQL version: 14.4
Operating system: GNU/Linux (Red Hat 8.5.0)
Description:

My application uses prepared statements. This section of the documentation
is going to be very relevant to the rest of this report:
https://www.postgresql.org/docs/current/sql-prepare.html#SQL-PREPARE-NOTES.

This is a minimal reproduction of the problem I observe, which I will
explain below:
https://dbfiddle.uk/?rdbms=postgres_14&fiddle=6b01d161da27379844e7602a16543626

Scenario:
- I create a fairly simple table (id + timestamp). Timestamp is indexed.
- I create a simple-ish prepared statement for `SELECT MIN(id), MAX(id) from
relation_tuple_transaction WHERE timestamp >= $1;`
- I execute the prepared statement multiple times (> 5 times)

From the 6th time onwards, the query plan used by Postgres changes, which
isn't fully unexpected as the documentation linked above does make it clear
that Postgres might decide to change the query plan for a generic query plan
after the 5th execution. And indeed, the estimated "cost" of the generic
plan is lower than the custom plan's: therefore the query planner behaves
correctly according to the documentation.

Now, the problem: the execution of the generic plan is multiple orders of
magnitude slower than the custom query plan ("actual time" for the generic
plan is over 6500x slower), yet Postgres decides to stick with the generic
plan. Very unexpected for me: I was very happy with the first 5 plans, yet
Postgres decides to change the plan for another that's enormously slower and
stick with it.
Giving a different parameter passed to the prepared statement (eg `now() -
interval '5 days'`) does give a "slow" custom plan (similar to the generic
plan). This means that the query planner does not realise that the actual
parameter value matters a lot, and that the parameters used _in practice_
result in a faster plan than the generic plan (100% of the first 5
executions), and that therefore it shouldn't stick to the generic plan.

It is particularly insidious as actually I wasn't even aware I was using
prepared statements. Like most applications I use a database driver (pgx, in
Go) which I learnt uses `PQexecPrepared` under the hood, which creates a
sort of "unnamed prepared statement" behaving the same as this minimal
reproduction without me ever being aware that prepared statements are
involved anywhere between my code and the database. This makes debugging
very complex as there's no reason to suspect anything
prepared-statement-related and a manual EXPLAIN ANALYZE outside of a
prepared statement won't show the problem.

Note: setting `plan_cache_mode = force_custom_plan` database-wide solved the
immediate problem but is a workaround. It was a very welcome workaround,
though.

#2David G. Johnston
david.g.johnston@gmail.com
In reply to: PG Bug reporting form (#1)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Wed, Jul 6, 2022 at 2:41 PM PG Bug reporting form <noreply@postgresql.org>
wrote:

The following bug has been logged on the website:

Bug reference: 17540
Logged by: William Duclot
Email address: william.duclot@gmail.com
PostgreSQL version: 14.4
Operating system: GNU/Linux (Red Hat 8.5.0)
Description:

This means that the query planner does not realise that the actual
parameter value matters a lot, and that the parameters used _in practice_
result in a faster plan than the generic plan (100% of the first 5
executions), and that therefore it shouldn't stick to the generic plan.

I mean, it is the planner and so, no, it doesn't understand that the
executor encountered an issue.

It is particularly insidious as actually I wasn't even aware I was using
prepared statements. Like most applications I use a database driver (pgx,
in
Go) which I learnt uses `PQexecPrepared` under the hood, which creates a
sort of "unnamed prepared statement" behaving the same as this minimal
reproduction without me ever being aware that prepared statements are
involved anywhere between my code and the database.

Yep, and the core project pretty much says that if you don't like this you
need to complain to the driver writer and ask them to provide you an
interface to the unnamed parse-bind-execute API which lets you perform
parameterization without memory, just safety.

PostgreSQL has built the needed tools to make this less problematic, and
has made solid attempts to improve matters in the current state of things.
There doesn't seem to be a bug here. There is potentially room for
improvement but no one presently is working on things in this area.

David J.

#3David Rowley
dgrowleyml@gmail.com
In reply to: PG Bug reporting form (#1)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

(On Thu, 7 Jul 2022 at 09:41, PG Bug reporting form
<noreply@postgresql.org> wrote:

Scenario:
- I create a fairly simple table (id + timestamp). Timestamp is indexed.
- I create a simple-ish prepared statement for `SELECT MIN(id), MAX(id) from
relation_tuple_transaction WHERE timestamp >= $1;`
- I execute the prepared statement multiple times (> 5 times)

From the 6th time onwards, the query plan used by Postgres changes, which
isn't fully unexpected as the documentation linked above does make it clear
that Postgres might decide to change the query plan for a generic query plan
after the 5th execution. And indeed, the estimated "cost" of the generic
plan is lower than the custom plan's: therefore the query planner behaves
correctly according to the documentation.

It's a pretty narrow fix for a fairly generic problem, but I think the
planner wouldn't have picked the pk_rttx index if build_minmax_path()
hadn't added the "id IS NOT NULL" qual.

I know that Andy Fan has been proposing a patch to add a Bitmapset
field to RelOptInfo to record the non-NULLable columns. That's a
fairly lightweight patch, so it might be worth adding that just so
build_minmax_path() can skip adding the NULL test if the column is a
NOT NULL column.

I see that preprocess_minmax_aggregates() won't touch anything that's
not a query to a single relation, so the Var can't be NULLable from
being on the outside of an outer join. So it looks like to plumb in
Andy's patch, build_minmax_path() would need to be modified to check
if mminfo->target is a plain Var and then test if that Var is NOT
NULLable then skip adding the NullTest.

All seems fairly trivial. It's just a fairly narrow fix to side-step a
more generic costing problem we have for Params. I just don't have
any bright ideas on how to fix the more generic problem right now.

I've been looking for a good excuse to commit Andy's NOT NULL patch so
that he has some more foundations for the other work he's doing. This
might be that excuse.

Does anyone think differently?

David

[1]: /messages/by-id/CAKU4AWoZrFaWAkTn9tE2_dd4RYnUiQUiX8xc=ryUywhBWQv89w@mail.gmail.com

#4David Rowley
dgrowleyml@gmail.com
In reply to: David Rowley (#3)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower
#5Andres Freund
andres@anarazel.de
In reply to: David G. Johnston (#2)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

Hi,

On 2022-07-06 15:07:46 -0700, David G. Johnston wrote:

On Wed, Jul 6, 2022 at 2:41 PM PG Bug reporting form <noreply@postgresql.org>
wrote:

It is particularly insidious as actually I wasn't even aware I was using
prepared statements. Like most applications I use a database driver (pgx,
in
Go) which I learnt uses `PQexecPrepared` under the hood, which creates a
sort of "unnamed prepared statement" behaving the same as this minimal
reproduction without me ever being aware that prepared statements are
involved anywhere between my code and the database.

Yep, and the core project pretty much says that if you don't like this you
need to complain to the driver writer and ask them to provide you an
interface to the unnamed parse-bind-execute API which lets you perform
parameterization without memory, just safety.

PostgreSQL has built the needed tools to make this less problematic, and
has made solid attempts to improve matters in the current state of things.
There doesn't seem to be a bug here. There is potentially room for
improvement but no one presently is working on things in this area.

I think the cost for the slow plan being so much cheaper can almost be
qualified as bug.

The slow plan seems pretty nonsensical to me. ISTM that something in the
costing there is at least almost broken.

Result (cost=1.06..1.07 rows=1 width=16) (actual time=148.732..148.734 rows=1 loops=1)
Buffers: shared hit=4935
InitPlan 1 (returns $0)
-> Limit (cost=0.42..0.53 rows=1 width=8) (actual time=73.859..73.860 rows=0 loops=1)
Buffers: shared hit=2113
-> Index Scan using pk_rttx on relation_tuple_transaction (cost=0.42..9445.44 rows=86400 width=8) (actual time=73.857..73.858 rows=0 loops=1)
Index Cond: (id IS NOT NULL)
Filter: ("timestamp" >= $1)
Rows Removed by Filter: 259201
Buffers: shared hit=2113
InitPlan 2 (returns $1)
-> Limit (cost=0.42..0.53 rows=1 width=8) (actual time=74.869..74.870 rows=0 loops=1)
Buffers: shared hit=2822
-> Index Scan Backward using pk_rttx on relation_tuple_transaction relation_tuple_transaction_1 (cost=0.42..9445.44 rows=86400 width=8) (actual time=74.868..74.868 rows=0 loops=1)
Index Cond: (id IS NOT NULL)
Filter: ("timestamp" >= $1)
Rows Removed by Filter: 259201
Buffers: shared hit=2822
Planning Time: 0.224 ms
Execution Time: 148.781 ms

The planner assumes the table has 259201 rows. Somehow we end up
assuming that a estimate-less filter reduces the number of rows to 86400
both on a backward and a forward scan.

And for some reason we don't take the filter clause into account *at
all* for the cost of returning the first row.

SET enable_seqscan = false;
EXPLAIN SELECT * FROM relation_tuple_transaction WHERE id IS NOT NULL LIMIT 1;
┌─────────────────────────────────────────────────────────────────────────────────────────────────────────┐
│ QUERY PLAN │
├─────────────────────────────────────────────────────────────────────────────────────────────────────────┤
│ Limit (cost=0.42..0.45 rows=1 width=16) │
│ -> Index Scan using pk_rttx on relation_tuple_transaction (cost=0.42..8797.44 rows=259201 width=16) │
│ Index Cond: (id IS NOT NULL) │
└─────────────────────────────────────────────────────────────────────────────────────────────────────────┘
(3 rows)

It's also pointless that we use "Index Cond: (id IS NOT NULL)" for a
primary key index, but that's a minor thing.

Greetings,

Andres Freund

#6David Rowley
dgrowleyml@gmail.com
In reply to: Andres Freund (#5)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Thu, 7 Jul 2022 at 12:46, Andres Freund <andres@anarazel.de> wrote:

I think the cost for the slow plan being so much cheaper can almost be
qualified as bug.

The slow plan seems pretty nonsensical to me. ISTM that something in the
costing there is at least almost broken.

I forgot to mention what the "generic problem" is when I posted my
reply. I should have mentioned that this is how we cost LIMIT. We
assume that we'll find the LIMIT 1 row after incurring the scan cost
multiplied by (1 / 259201).

For the plan with WHERE timestamp >= $1, the seqscan plan looks pretty
cheap for fetching DEFAULT_INEQ_SEL of the 259201 rows considering the
LIMIT multiples the cost of the scan by (1 / 86400).

David

#7Tom Lane
tgl@sss.pgh.pa.us
In reply to: David Rowley (#3)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

David Rowley <dgrowleyml@gmail.com> writes:

I've been looking for a good excuse to commit Andy's NOT NULL patch so
that he has some more foundations for the other work he's doing. This
might be that excuse.

Does anyone think differently?

While I don't have any problem with tracking column NOT NULL flags
in RelOptInfo once the planner has a use for that info, I'm not sure
that we have a solid use-case for it quite yet. In particular, the
fact that the table column is marked NOT NULL doesn't mean that any
particular occurrence of that column's Var can be freely assumed to be
non-null. The patch I'm working on to label Vars that have possibly
been nulled by outer joins [1]/messages/by-id/830269.1656693747@sss.pgh.pa.us seems like essential infrastructure for
doing anything very useful with the info.

Maybe that objection doesn't apply to build_minmax_path's usage in
particular, but that's an awfully narrow use-case.

regards, tom lane

[1]: /messages/by-id/830269.1656693747@sss.pgh.pa.us

#8Tom Lane
tgl@sss.pgh.pa.us
In reply to: Andres Freund (#5)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

Andres Freund <andres@anarazel.de> writes:

I think the cost for the slow plan being so much cheaper can almost be
qualified as bug.
The slow plan seems pretty nonsensical to me. ISTM that something in the
costing there is at least almost broken.

I think this is probably an instance of the known problem that a generic
plan is made without knowledge of the actual parameter values, and that
can lead us to make statistical assumptions that are not valid for the
actual values, but nonetheless make one plan look cheaper than another
even though the opposite is true given the actual values. In essence,
comparing the cost estimate for the generic plan to the cost estimate
for a custom plan is not really logically valid, because those estimates
are founded on different statistics. I don't know how to fix that :-(.

regards, tom lane

#9David Rowley
dgrowleyml@gmail.com
In reply to: Tom Lane (#7)
2 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Thu, 7 Jul 2022 at 15:07, Tom Lane <tgl@sss.pgh.pa.us> wrote:

While I don't have any problem with tracking column NOT NULL flags
in RelOptInfo once the planner has a use for that info, I'm not sure
that we have a solid use-case for it quite yet. In particular, the
fact that the table column is marked NOT NULL doesn't mean that any
particular occurrence of that column's Var can be freely assumed to be
non-null. The patch I'm working on to label Vars that have possibly
been nulled by outer joins [1] seems like essential infrastructure for
doing anything very useful with the info.

I was aware that you'd done that work. I'm interested in it, but just
not found the time to look yet.

Maybe that objection doesn't apply to build_minmax_path's usage in
particular, but that's an awfully narrow use-case.

I thought I'd quickly put the idea together and fairly quickly noticed
that we do preprocess_minmax_aggregates() in grouping_planner(), which
is long before we load the RelOptInfo data in
add_base_rels_to_query(), which is called in query_planner(). I
considered if we could move the preprocess_minmax_aggregates(), but
that does not seem right, although, surprisingly, no tests seem to
fail from doing so. I'd have expected at least some EXPLAIN outputs to
have changed from the no-longer-present IS NOT NULL quals.

I imagine a much less narrow case would be to check for redundant
RestrictInfos in distribute_restrictinfo_to_rels(). That would also
catch cases such as WHERE non_nullable_col IS NULL, provided that qual
made it down to baserestrictinfo. When I realised that, I thought I
might be starting to overlap with your work in the link below.

[1] /messages/by-id/830269.1656693747@sss.pgh.pa.us

The 2 attached patches do fix the bad reported plan, it's just that
it's a very roundabout way of fixing it

Anyway, I've no current plans to take the attached any further. I
think it'll be better to pursue your NULLable-Var stuff and see if we
can do something more generic like remove provably redundant NullTests
from baserestrictinfo.

David

Attachments:

v1-0001-Track-NOT-NULL-columns-in-RelOptInfo-for-base-rel.patchtext/plain; charset=US-ASCII; name=v1-0001-Track-NOT-NULL-columns-in-RelOptInfo-for-base-rel.patchDownload
From 0372cba1ea87d6eb10e21133461c1db525dbcf06 Mon Sep 17 00:00:00 2001
From: David Rowley <dgrowley@gmail.com>
Date: Thu, 7 Jul 2022 13:02:29 +1200
Subject: [PATCH v1 1/2] Track NOT NULL columns in RelOptInfo for base
 relations

Author: Andy Fan
Discussion: https://postgr.es/m/CAKU4AWpUA8dyVSU1nfCJz71mu6VEjbGS1uy8azrt5CdyoZqGQA%40mail.gmail.com
---
 src/backend/optimizer/util/plancat.c | 10 ++++++++++
 src/backend/optimizer/util/relnode.c |  2 ++
 src/include/nodes/pathnodes.h        |  2 ++
 3 files changed, 14 insertions(+)

diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 5012bfe142..7111284221 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -472,6 +472,16 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	if (inhparent && relation->rd_rel->relkind == RELKIND_PARTITIONED_TABLE)
 		set_relation_partition_info(root, rel, relation);
 
+	Assert(rel->notnullattrs == NULL);
+	for(int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull && !attr->attisdropped)
+			rel->notnullattrs = bms_add_member(rel->notnullattrs,
+											   attr->attnum - FirstLowInvalidHeapAttributeNumber);
+	}
+
 	table_close(relation, NoLock);
 
 	/*
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 520409f4ba..f7be6548ef 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -227,6 +227,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
+	rel->notnullattrs = NULL;
 	rel->pages = 0;
 	rel->tuples = 0;
 	rel->allvisfrac = 0;
@@ -641,6 +642,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->lateral_referencers = NULL;
 	joinrel->indexlist = NIL;
 	joinrel->statlist = NIL;
+	joinrel->notnullattrs = NULL;
 	joinrel->pages = 0;
 	joinrel->tuples = 0;
 	joinrel->allvisfrac = 0;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index b88cfb8dc0..5f81ecc3b5 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -758,6 +758,8 @@ typedef struct RelOptInfo
 	List	   *indexlist;
 	/* list of StatisticExtInfo */
 	List	   *statlist;
+	/* NOT NULL attributes offset by FirstLowInvalidHeapAttributeNumber */
+	Bitmapset	   *notnullattrs;
 	/* size estimates derived from pg_class */
 	BlockNumber pages;
 	Cardinality tuples;
-- 
2.35.1.windows.2

v1-0002-Don-t-add-is-NOT-NULL-clause-to-MinMaxAggInfo-tra.patchtext/plain; charset=US-ASCII; name=v1-0002-Don-t-add-is-NOT-NULL-clause-to-MinMaxAggInfo-tra.patchDownload
From ec42c5a6537d64071d08fb0f5f06f6321d1129c2 Mon Sep 17 00:00:00 2001
From: David Rowley <dgrowley@gmail.com>
Date: Thu, 7 Jul 2022 15:11:56 +1200
Subject: [PATCH v1 2/2] Don't add is NOT NULL clause to MinMaxAggInfo
 transformed queries

... when the column is already non-NULLable.

This is not quite there yet. The fact that I had to shuffle
preprocess_minmax_aggregates() around makes me think it's wrong.
---
 src/backend/optimizer/plan/planagg.c  | 31 ++++++++++++++++-----------
 src/backend/optimizer/plan/planmain.c |  8 +++++++
 src/backend/optimizer/plan/planner.c  |  9 --------
 3 files changed, 27 insertions(+), 21 deletions(-)

diff --git a/src/backend/optimizer/plan/planagg.c b/src/backend/optimizer/plan/planagg.c
index 9330908cbf..afb3747acc 100644
--- a/src/backend/optimizer/plan/planagg.c
+++ b/src/backend/optimizer/plan/planagg.c
@@ -327,6 +327,7 @@ build_minmax_path(PlannerInfo *root, MinMaxAggInfo *mminfo,
 	Path	   *sorted_path;
 	Cost		path_cost;
 	double		path_fraction;
+	Var		   *var_target = (Var *) mminfo->target;
 
 	/*
 	 * We are going to construct what is effectively a sub-SELECT query, so
@@ -382,18 +383,24 @@ build_minmax_path(PlannerInfo *root, MinMaxAggInfo *mminfo,
 	parse->hasDistinctOn = false;
 	parse->hasAggs = false;
 
-	/* Build "target IS NOT NULL" expression */
-	ntest = makeNode(NullTest);
-	ntest->nulltesttype = IS_NOT_NULL;
-	ntest->arg = copyObject(mminfo->target);
-	/* we checked it wasn't a rowtype in find_minmax_aggs_walker */
-	ntest->argisrow = false;
-	ntest->location = -1;
-
-	/* User might have had that in WHERE already */
-	if (!list_member((List *) parse->jointree->quals, ntest))
-		parse->jointree->quals = (Node *)
-			lcons(ntest, (List *) parse->jointree->quals);
+	/* Check for non-Vars or NULLable Vars and add a NOT NULL tests */
+	if (!IsA(var_target, Var) ||
+		!bms_is_member(var_target->varattno - FirstLowInvalidHeapAttributeNumber,
+					   root->simple_rel_array[var_target->varno]->notnullattrs))
+	{
+		/* Build "target IS NOT NULL" expression */
+		ntest = makeNode(NullTest);
+		ntest->nulltesttype = IS_NOT_NULL;
+		ntest->arg = copyObject(mminfo->target);
+		/* we checked it wasn't a rowtype in find_minmax_aggs_walker */
+		ntest->argisrow = false;
+		ntest->location = -1;
+
+		/* User might have had that in WHERE already */
+		if (!list_member((List *) parse->jointree->quals, ntest))
+			parse->jointree->quals = (Node *)
+				lcons(ntest, (List *) parse->jointree->quals);
+	}
 
 	/* Build suitable ORDER BY clause */
 	sortcl = makeNode(SortGroupClause);
diff --git a/src/backend/optimizer/plan/planmain.c b/src/backend/optimizer/plan/planmain.c
index c92ddd27ed..f375cac7fd 100644
--- a/src/backend/optimizer/plan/planmain.c
+++ b/src/backend/optimizer/plan/planmain.c
@@ -165,6 +165,14 @@ query_planner(PlannerInfo *root,
 	 */
 	add_base_rels_to_query(root, (Node *) parse->jointree);
 
+	/*
+	 * Preprocess MIN/MAX aggregates, if any.  XXX what are the actual
+	 * repercussions of moving this out of grouping_planner() into
+	 * query_planner()?
+	 */
+	if (parse->hasAggs)
+		preprocess_minmax_aggregates(root);
+
 	/*
 	 * Examine the targetlist and join tree, adding entries to baserel
 	 * targetlists for all referenced Vars, and generating PlaceHolderInfo
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index 06ad856eac..f6c6c4b8b4 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -1425,15 +1425,6 @@ grouping_planner(PlannerInfo *root, double tuple_fraction)
 				parse->hasWindowFuncs = false;
 		}
 
-		/*
-		 * Preprocess MIN/MAX aggregates, if any.  Note: be careful about
-		 * adding logic between here and the query_planner() call.  Anything
-		 * that is needed in MIN/MAX-optimizable cases will have to be
-		 * duplicated in planagg.c.
-		 */
-		if (parse->hasAggs)
-			preprocess_minmax_aggregates(root);
-
 		/*
 		 * Figure out whether there's a hard limit on the number of rows that
 		 * query_planner's result subplan needs to return.  Even if we know a
-- 
2.35.1.windows.2

#10Tom Lane
tgl@sss.pgh.pa.us
In reply to: David Rowley (#9)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

David Rowley <dgrowleyml@gmail.com> writes:

Anyway, I've no current plans to take the attached any further. I
think it'll be better to pursue your NULLable-Var stuff and see if we
can do something more generic like remove provably redundant NullTests
from baserestrictinfo.

Yeah, I suspect that the way forward is to allow
preprocess_minmax_aggregates to do what it does now, and then
remove the IS NOT NULL clause again later when we have the
info available to let us do that in a generic way.

In any case, as you said, it's just a band-aid that happens to
help in this exact scenario. It's not doing much for the bad
cost estimation that's the root of the problem.

regards, tom lane

#11Andres Freund
andres@anarazel.de
In reply to: Tom Lane (#8)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

Hi,

On 2022-07-06 23:13:18 -0400, Tom Lane wrote:

Andres Freund <andres@anarazel.de> writes:

I think the cost for the slow plan being so much cheaper can almost be
qualified as bug.
The slow plan seems pretty nonsensical to me. ISTM that something in the
costing there is at least almost broken.

I think this is probably an instance of the known problem that a generic
plan is made without knowledge of the actual parameter values, and that
can lead us to make statistical assumptions that are not valid for the
actual values, but nonetheless make one plan look cheaper than another
even though the opposite is true given the actual values. In essence,
comparing the cost estimate for the generic plan to the cost estimate
for a custom plan is not really logically valid, because those estimates
are founded on different statistics. I don't know how to fix that :-(.

I think there's something more fundamentally wrong - somehow we end up with
assuming > 50% selectivity on both the min and the max initplan, for the same
condition! And afaics (although it's a bit hard to see with the precision
explain prints floating point values as) don't charge cpu_operator_cost /
cpu_tuple_cost. And this is on a table where we can know, despite not know the
parameter value, that the column being compared has a correlation of 1.

In this case the whole generic plan part seems like a red herring. The generic
plan is *awful* and would still be awful if the value were known, but
somewhere around the middle of the value range.

Here's the op's tables + query, but without the prepared statement part:

CREATE TABLE relation_tuple_transaction (
id BIGSERIAL NOT NULL UNIQUE,
timestamp TIMESTAMP WITHOUT TIME ZONE NOT NULL UNIQUE,
CONSTRAINT pk_rttx PRIMARY KEY (id)
);
CREATE INDEX ix_relation_tuple_transaction_by_timestamp on relation_tuple_transaction(timestamp);
INSERT INTO relation_tuple_transaction(timestamp) SELECT * FROM generate_series
( now() - interval '3 days'
, now()
, '1 second'::interval) dd
;
vacuum freeze analyze;
EXPLAIN ANALYZE SELECT MIN(id), MAX(id) from relation_tuple_transaction WHERE timestamp >= (now() - interval '1.5 days');

postgres[631148][1]=# EXPLAIN ANALYZE SELECT MIN(id), MAX(id) from relation_tuple_transaction WHERE timestamp >= (now() - interval '1.5 days');;

Result (cost=1.01..1.02 rows=1 width=16) (actual time=113.379..113.381 rows=1 loops=1)
InitPlan 1 (returns $0)
-> Limit (cost=0.42..0.50 rows=1 width=8) (actual time=113.347..113.348 rows=1 loops=1)
-> Index Scan using pk_rttx on relation_tuple_transaction (cost=0.42..10741.45 rows=127009 width=8) (actual time=113.345..113.345 rows=1 loops=1)
Index Cond: (id IS NOT NULL)
Filter: ("timestamp" >= (now() - '1 day 12:00:00'::interval))
Rows Removed by Filter: 129746
InitPlan 2 (returns $1)
-> Limit (cost=0.42..0.50 rows=1 width=8) (actual time=0.024..0.024 rows=1 loops=1)
-> Index Scan Backward using pk_rttx on relation_tuple_transaction relation_tuple_transaction_1 (cost=0.42..10741.45 rows=127009 width=8) (actual time=0.023..0.023 rows=1 loops=1)
Index Cond: (id IS NOT NULL)
Filter: ("timestamp" >= (now() - '1 day 12:00:00'::interval))
Planning Time: 0.370 ms
Execution Time: 113.441 ms
(14 rows)

We're pretty much by definition scanning half the table via the index scans,
and end up with a cost of 1.02 (yes, aware that the paths are costed
separately).

FWIW, manually writing the min/max as ORDER BY timestamp ASC/DESC LIMIT 1
queries yields a *vastly* better plan:

EXPLAIN ANALYZE SELECT (SELECT id FROM relation_tuple_transaction WHERE timestamp >= (now() - interval '1.5 days') ORDER BY timestamp ASC LIMIT 1), (SELECT id FROM relation_tuple_transaction WHERE timestamp >= (now() - interval '1.5 days') ORDER BY timestamp DESC LIMIT 1);

Result (cost=0.92..0.93 rows=1 width=16) (actual time=0.110..0.111 rows=1 loops=1)
InitPlan 1 (returns $0)
-> Limit (cost=0.42..0.46 rows=1 width=16) (actual time=0.079..0.079 rows=1 loops=1)
-> Index Scan using ix_relation_tuple_transaction_by_timestamp on relation_tuple_transaction (cost=0.42..4405.46 rows=129602 width=16) (actual time=0.077..0.078 rows=1 loops=1)
Index Cond: ("timestamp" >= (now() - '1 day 12:00:00'::interval))
InitPlan 2 (returns $1)
-> Limit (cost=0.42..0.46 rows=1 width=16) (actual time=0.028..0.028 rows=1 loops=1)
-> Index Scan Backward using ix_relation_tuple_transaction_by_timestamp on relation_tuple_transaction relation_tuple_transaction_1 (cost=0.42..4405.46 rows=129602 width=16) (actual time=0.027..0.027 rows=1 loops=1)
Index Cond: ("timestamp" >= (now() - '1 day 12:00:00'::interval))
Planning Time: 0.270 ms
Execution Time: 0.159 ms (11 rows)

And it stays sane even if you add a (redundantly evaluated) AND id IS NOT NULL.

EXPLAIN SELECT id FROM relation_tuple_transaction WHERE timestamp >= (now() - interval '1.5 days') AND id IS NOT NULL ORDER BY timestamp ASC LIMIT 1;
QUERY PLAN
Limit (cost=0.42..0.46 rows=1 width=16)
-> Index Scan using ix_relation_tuple_transaction_by_timestamp on relation_tuple_transaction (cost=0.42..4405.46 rows=129602 width=16)
Index Cond: ("timestamp" >= (now() - '1 day 12:00:00'::interval))
Filter: (id IS NOT NULL)
(4 rows)

EXPLAIN SELECT min(id) FROM relation_tuple_transaction WHERE timestamp >= (now() - interval '1.5 days');
QUERY PLAN
Result (cost=0.50..0.51 rows=1 width=8)
InitPlan 1 (returns $0)
-> Limit (cost=0.42..0.50 rows=1 width=8)
-> Index Scan using pk_rttx on relation_tuple_transaction (cost=0.42..10741.45 rows=129602 width=8)
Index Cond: (id IS NOT NULL)
Filter: ("timestamp" >= (now() - '1 day 12:00:00'::interval))
(6 rows)

Greetings,

Andres Freund

#12Tom Lane
tgl@sss.pgh.pa.us
In reply to: Andres Freund (#11)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

Andres Freund <andres@anarazel.de> writes:

On 2022-07-06 23:13:18 -0400, Tom Lane wrote:

comparing the cost estimate for the generic plan to the cost estimate
for a custom plan is not really logically valid, because those estimates
are founded on different statistics. I don't know how to fix that :-(.

I think there's something more fundamentally wrong - somehow we end up with
assuming > 50% selectivity on both the min and the max initplan, for the same
condition!

Well, sure, because it *is* the same condition. AFAICS this is operating
as designed. Do I wish it were better? Sure, but there is no simple fix
here.

The reasoning that's being applied in the generic plan is

(1) default selectivity estimate for a scalar inequality is
#define DEFAULT_INEQ_SEL 0.3333333333333333

(2) therefore, the filter condition on the indexscan will select a random
one-third of the table;

(3) therefore, the LIMIT will be able to stop after about three rows,
whichever direction we scan in.

The information that is lacking is that the "id" and "timestamp"
columns are heavily correlated, so that we may have to scan far more
than three rows in "id" order before finding a row satisfying the
inequality on "timestamp". This is a problem we've understood for
a long time --- I recall talking about it at PGCon a decade ago.

The extended stats machinery provides a framework wherein we could
calculate and save the ordering correlation between the two columns,
but I don't believe it actually calculates that number yet --- I think
the functional-dependency stuff is close but not the right thing.
Even if we had the stats, it's not very clear where to fit this
type of consideration into the planner's estimates.

In this case the whole generic plan part seems like a red herring. The generic
plan is *awful* and would still be awful if the value were known, but
somewhere around the middle of the value range.

If the value were somewhere around the middle (which is more or less
what we're assuming for the generic plan), then an indexscan on the
timestamp column isn't going to be that great either; you'd still
be scanning half the table.

FWIW, manually writing the min/max as ORDER BY timestamp ASC/DESC LIMIT 1
queries yields a *vastly* better plan:

Those queries give the wrong answers. We're looking for the min or max
id, not the id associated with the min or max timestamp. (They're
accidentally the same with this toy dataset.)

regards, tom lane

#13David Rowley
dgrowleyml@gmail.com
In reply to: Tom Lane (#10)
1 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Thu, 7 Jul 2022 at 15:50, Tom Lane <tgl@sss.pgh.pa.us> wrote:

David Rowley <dgrowleyml@gmail.com> writes:

Anyway, I've no current plans to take the attached any further. I
think it'll be better to pursue your NULLable-Var stuff and see if we
can do something more generic like remove provably redundant NullTests
from baserestrictinfo.

Yeah, I suspect that the way forward is to allow
preprocess_minmax_aggregates to do what it does now, and then
remove the IS NOT NULL clause again later when we have the
info available to let us do that in a generic way.

I started looking at a more generic way to fix this. In the attached
I'm catching quals being added to baserestrictinfo in
distribute_restrictinfo_to_rels() and checking for IS NOT NULL quals
on columns defined with NOT NULL.

I did this by adding a new function add_baserestrictinfo_to_rel()
which can be the place where we add any future logic to ignore other
always-true quals. Perhaps in the future, we can add some logic there
to look for quals on partitions which are always true based on the
partition constraint.

I also took the opportunity here to slightly modernised the Bitmapset
code in this area. We previously called bms_membership() and then
bms_singleton_member(), which is not quite optimal. We invented
bms_get_singleton_member() as a more efficient way of getting that.
The empty set case can just be handled more easily now since you
changed empty sets to always be NULL. If it's not an empty set and not
a singleton, then it must contain multiple members.

I'm quite keen to see some forward progress on improving things for
this bug report. It would be good to take some more measures to stop
the planner being tricked into making silly mistakes. This is one
example of somewhere we could do better.

David

Attachments:

ignore_is_not_null_base_quals_on_not_null_columns.patchtext/plain; charset=US-ASCII; name=ignore_is_not_null_base_quals_on_not_null_columns.patchDownload
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index b31d892121..277314c8cb 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,50 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_baserestrictinfo_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted by
+ *		'relid' with some prechecks to try to determine if the qual is always
+ *		true, in which case we ignore it rather than add it.
+ */
+static void
+add_baserestrictinfo_to_rel(PlannerInfo *root, Index relid,
+							RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Any IS NOT NULL qual on a NOT NULL column is always true */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest *nulltest = (NullTest *) restrictinfo->clause;
+
+		if (nulltest->nulltesttype == IS_NOT_NULL && IsA(nulltest->arg, Var))
+		{
+			Var *var = (Var *) nulltest->arg;
+
+			Assert(var->varno == rel->relid);
+
+			/* don't add the qual as system columns cannot be NULL */
+			if (var->varattno < 0)
+				return;
+
+			/* don't add the IS NOT NULL when the column is defined NOT NULL */
+			if (var->varattno > 0 &&
+				bms_is_member(var->varattno, rel->notnullattnums))
+				return;
+		}
+	}
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2633,57 +2677,39 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 {
 	Relids		relids = restrictinfo->required_relids;
 	RelOptInfo *rel;
+	int			relid;
 
-	switch (bms_membership(relids))
+	if (relids == NULL)
 	{
-		case BMS_SINGLETON:
-
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, bms_singleton_member(relids));
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-			break;
-		case BMS_MULTIPLE:
-
-			/*
-			 * The clause is a join clause, since there is more than one rel
-			 * in its relid set.
-			 */
-
-			/*
-			 * Check for hashjoinable operators.  (We don't bother setting the
-			 * hashjoin info except in true join clauses.)
-			 */
-			check_hashjoinable(restrictinfo);
+		/*
+		 * clause references no rels, and therefore we have no place to
+		 * attach it.  Shouldn't get here if callers are working properly.
+		 */
+		elog(ERROR, "cannot cope with variable-free clause");
+	}
+	else if (bms_get_singleton_member(relids, &relid))
+		add_baserestrictinfo_to_rel(root, relid, restrictinfo);
+	else
+	{
+		/*
+		 * The clause is a join clause, since there is more than one rel in
+		 * its relid set.
+		 */
 
-			/*
-			 * Likewise, check if the clause is suitable to be used with a
-			 * Memoize node to cache inner tuples during a parameterized
-			 * nested loop.
-			 */
-			check_memoizable(restrictinfo);
+		/*
+		 * Check for hashjoinable operators.  (We don't bother setting the
+		 * hashjoin info except in true join clauses.)
+		 */
+		check_hashjoinable(restrictinfo);
 
-			/*
-			 * Add clause to the join lists of all the relevant relations.
-			 */
-			add_join_clause_to_rels(root, restrictinfo, relids);
-			break;
-		default:
+		/*
+		 * Likewise, check if the clause is suitable to be used with a Memoize
+		 * node to cache inner tuples during a parameterized nested loop.
+		 */
+		check_memoizable(restrictinfo);
 
-			/*
-			 * clause references no rels, and therefore we have no place to
-			 * attach it.  Shouldn't get here if callers are working properly.
-			 */
-			elog(ERROR, "cannot cope with variable-free clause");
-			break;
+		/* Add clause to the join lists of all the relevant relations. */
+		add_join_clause_to_rels(root, restrictinfo, relids);
 	}
 }
 
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 39932d3c2d..d810ad8127 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,15 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+			rel->notnullattnums = bms_add_member(rel->notnullattnums, attr->attnum);
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index c17b53f7ad..851a4513a9 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
#14Richard Guo
guofenglinux@gmail.com
In reply to: David Rowley (#13)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Thu, Jul 6, 2023 at 7:55 AM David Rowley <dgrowleyml@gmail.com> wrote:

On Thu, 7 Jul 2022 at 15:50, Tom Lane <tgl@sss.pgh.pa.us> wrote:

David Rowley <dgrowleyml@gmail.com> writes:

Anyway, I've no current plans to take the attached any further. I
think it'll be better to pursue your NULLable-Var stuff and see if we
can do something more generic like remove provably redundant NullTests
from baserestrictinfo.

Yeah, I suspect that the way forward is to allow
preprocess_minmax_aggregates to do what it does now, and then
remove the IS NOT NULL clause again later when we have the
info available to let us do that in a generic way.

I started looking at a more generic way to fix this. In the attached
I'm catching quals being added to baserestrictinfo in
distribute_restrictinfo_to_rels() and checking for IS NOT NULL quals
on columns defined with NOT NULL.

I did this by adding a new function add_baserestrictinfo_to_rel()
which can be the place where we add any future logic to ignore other
always-true quals. Perhaps in the future, we can add some logic there
to look for quals on partitions which are always true based on the
partition constraint.

I think this is a good start. Maybe we can extend it with little effort
to cover OR clauses. For an OR clause, we can test its sub-clauses and
if one of them is IS NOT NULL qual on a NOT NULL column then we can know
that the OR clause is always true.

Maybe we can also test if the qual is always true according to the
applicable constraint expressions of the given relation, something that
is like the opposite of relation_excluded_by_constraints(). Of course
that would require much more efforts.

Another thing I'm wondering is that since we already have the
outer-join-aware-Var infrastructure, maybe we can also test whether a IS
NOT NULL qual in join clauses is always true. I imagine we need to test
whether the Var in the IS NOT NULL qual has an empty varnullingrels
besides that the Var is a NOT NULL column.

BTW, with this patch the variable ‘rel’ in function
distribute_restrictinfo_to_rels is unused.

Thanks
Richard

#15Richard Guo
guofenglinux@gmail.com
In reply to: Richard Guo (#14)
1 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Thu, Jul 6, 2023 at 5:26 PM Richard Guo <guofenglinux@gmail.com> wrote:

On Thu, Jul 6, 2023 at 7:55 AM David Rowley <dgrowleyml@gmail.com> wrote:

I started looking at a more generic way to fix this. In the attached
I'm catching quals being added to baserestrictinfo in
distribute_restrictinfo_to_rels() and checking for IS NOT NULL quals
on columns defined with NOT NULL.

I did this by adding a new function add_baserestrictinfo_to_rel()
which can be the place where we add any future logic to ignore other
always-true quals. Perhaps in the future, we can add some logic there
to look for quals on partitions which are always true based on the
partition constraint.

I think this is a good start. Maybe we can extend it with little effort
to cover OR clauses. For an OR clause, we can test its sub-clauses and
if one of them is IS NOT NULL qual on a NOT NULL column then we can know
that the OR clause is always true.

Maybe we can also test if the qual is always true according to the
applicable constraint expressions of the given relation, something that
is like the opposite of relation_excluded_by_constraints(). Of course
that would require much more efforts.

Another thing I'm wondering is that since we already have the
outer-join-aware-Var infrastructure, maybe we can also test whether a IS
NOT NULL qual in join clauses is always true. I imagine we need to test
whether the Var in the IS NOT NULL qual has an empty varnullingrels
besides that the Var is a NOT NULL column.

BTW, with this patch the variable ‘rel’ in function
distribute_restrictinfo_to_rels is unused.

Attached is what I have in mind. The patch extends the logic from two
points.

* it also checks OR clauses to see if it is always true.

* it also checks for join clauses by additionally testing if the nulling
bitmap is empty.

I did not try the logic about testing a qual against the relation's
constraints though.

Thanks
Richard

Attachments:

v2-0001-ignore-is-not-null-quals-on-not-null-columns.patchapplication/octet-stream; name=v2-0001-ignore-is-not-null-quals-on-not-null-columns.patchDownload
From 0596cc0413c95c0150e82eb4d24d9bf7401642c8 Mon Sep 17 00:00:00 2001
From: Richard Guo <guofenglinux@gmail.com>
Date: Fri, 7 Jul 2023 14:42:21 +0800
Subject: [PATCH v2] ignore is not null quals on not null columns

---
 src/backend/optimizer/plan/initsplan.c | 179 ++++++++++++++++++-------
 src/backend/optimizer/util/joininfo.c  |   5 +
 src/backend/optimizer/util/plancat.c   |   9 ++
 src/include/nodes/pathnodes.h          |   2 +
 src/include/optimizer/planmain.h       |   2 +
 5 files changed, 150 insertions(+), 47 deletions(-)

diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index b31d892121..980429d469 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,110 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_baserestrictinfo_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted by
+ *		'relid' with some prechecks to try to determine if the qual is always
+ *		true, in which case we ignore it rather than add it.
+ */
+static void
+add_baserestrictinfo_to_rel(PlannerInfo *root, Index relid,
+							RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * nulltest_is_always_true
+ *	  Check to see if the NullTest qual is always true.
+ *
+ * If the NullTest is an IS_NOT_NULL qual on a NOT NULL column, and meanwhile
+ * its Var is not nulled by any outer joins, then we can know that it would be
+ * always true.
+ */
+static bool
+nulltest_is_always_true(PlannerInfo *root, NullTest *nulltest)
+{
+	RelOptInfo *rel;
+	Var		   *var;
+
+	Assert(IsA(nulltest, NullTest));
+
+	/* is this NullTest an IS_NOT_NULL qual? */
+	if (nulltest->nulltesttype != IS_NOT_NULL)
+		return false;
+
+	if (!IsA(nulltest->arg, Var))
+		return false;
+
+	var = (Var *) nulltest->arg;
+
+	/* could the Var be nulled by any outer joins? */
+	if (!bms_is_empty(var->varnullingrels))
+		return false;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		return true;
+
+	/* is the column defined NOT NULL? */
+	rel = find_base_rel(root, var->varno);
+	if (var->varattno > 0 &&
+		bms_is_member(var->varattno, rel->notnullattnums))
+		return true;
+
+	return false;
+}
+
+/*
+ * restriction_is_always_true
+ *	  Check to see if the RestrictInfo is always true.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_true(PlannerInfo *root,
+						   RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+		return nulltest_is_always_true(root, (NullTest *) restrictinfo->clause);
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo))
+				continue;
+
+			if (restriction_is_always_true(root, (RestrictInfo *) orarg))
+				return true;
+		}
+	}
+
+	return false;
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,58 +2736,39 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
+	int			relid;
 
-	switch (bms_membership(relids))
+	if (relids == NULL)
 	{
-		case BMS_SINGLETON:
-
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, bms_singleton_member(relids));
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-			break;
-		case BMS_MULTIPLE:
-
-			/*
-			 * The clause is a join clause, since there is more than one rel
-			 * in its relid set.
-			 */
-
-			/*
-			 * Check for hashjoinable operators.  (We don't bother setting the
-			 * hashjoin info except in true join clauses.)
-			 */
-			check_hashjoinable(restrictinfo);
+		/*
+		 * clause references no rels, and therefore we have no place to
+		 * attach it.  Shouldn't get here if callers are working properly.
+		 */
+		elog(ERROR, "cannot cope with variable-free clause");
+	}
+	else if (bms_get_singleton_member(relids, &relid))
+		add_baserestrictinfo_to_rel(root, relid, restrictinfo);
+	else
+	{
+		/*
+		 * The clause is a join clause, since there is more than one rel in
+		 * its relid set.
+		 */
 
-			/*
-			 * Likewise, check if the clause is suitable to be used with a
-			 * Memoize node to cache inner tuples during a parameterized
-			 * nested loop.
-			 */
-			check_memoizable(restrictinfo);
+		/*
+		 * Check for hashjoinable operators.  (We don't bother setting the
+		 * hashjoin info except in true join clauses.)
+		 */
+		check_hashjoinable(restrictinfo);
 
-			/*
-			 * Add clause to the join lists of all the relevant relations.
-			 */
-			add_join_clause_to_rels(root, restrictinfo, relids);
-			break;
-		default:
+		/*
+		 * Likewise, check if the clause is suitable to be used with a Memoize
+		 * node to cache inner tuples during a parameterized nested loop.
+		 */
+		check_memoizable(restrictinfo);
 
-			/*
-			 * clause references no rels, and therefore we have no place to
-			 * attach it.  Shouldn't get here if callers are working properly.
-			 */
-			elog(ERROR, "cannot cope with variable-free clause");
-			break;
+		/* Add clause to the join lists of all the relevant relations. */
+		add_join_clause_to_rels(root, restrictinfo, relids);
 	}
 }
 
diff --git a/src/backend/optimizer/util/joininfo.c b/src/backend/optimizer/util/joininfo.c
index 968a5a488e..add124e395 100644
--- a/src/backend/optimizer/util/joininfo.c
+++ b/src/backend/optimizer/util/joininfo.c
@@ -17,6 +17,7 @@
 #include "optimizer/joininfo.h"
 #include "optimizer/pathnode.h"
 #include "optimizer/paths.h"
+#include "optimizer/planmain.h"
 
 
 /*
@@ -98,6 +99,10 @@ add_join_clause_to_rels(PlannerInfo *root,
 {
 	int			cur_relid;
 
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
 	cur_relid = -1;
 	while ((cur_relid = bms_next_member(join_relids, cur_relid)) >= 0)
 	{
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 39932d3c2d..d810ad8127 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,15 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+			rel->notnullattnums = bms_add_member(rel->notnullattnums, attr->attnum);
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index c17b53f7ad..851a4513a9 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index 5fc900737d..c8582792d4 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -75,6 +75,8 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern bool restriction_is_always_true(PlannerInfo *root,
+									   RestrictInfo *restrictinfo);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
-- 
2.31.0

#16David Rowley
dgrowleyml@gmail.com
In reply to: Richard Guo (#15)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Fri, 7 Jul 2023 at 19:03, Richard Guo <guofenglinux@gmail.com> wrote:

Attached is what I have in mind. The patch extends the logic from two
points.

* it also checks OR clauses to see if it is always true.

* it also checks for join clauses by additionally testing if the nulling
bitmap is empty.

Do you mind writing some regression tests for this?

I don't really see an existing test file that would suit, maybe it's
worth adding something like predicate.sql

David

#17Richard Guo
guofenglinux@gmail.com
In reply to: David Rowley (#16)
1 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Mon, Jul 10, 2023 at 10:14 AM David Rowley <dgrowleyml@gmail.com> wrote:

On Fri, 7 Jul 2023 at 19:03, Richard Guo <guofenglinux@gmail.com> wrote:

Attached is what I have in mind. The patch extends the logic from two
points.

* it also checks OR clauses to see if it is always true.

* it also checks for join clauses by additionally testing if the nulling
bitmap is empty.

Do you mind writing some regression tests for this?

I don't really see an existing test file that would suit, maybe it's
worth adding something like predicate.sql

Here is v3 patch with regression tests. I add the new test into the
group where stats test is in, but I'm not sure if this is the right
place.

Thanks
Richard

Attachments:

v3-0001-ignore-is-not-null-quals-on-not-null-columns.patchapplication/octet-stream; name=v3-0001-ignore-is-not-null-quals-on-not-null-columns.patchDownload
From a45cdbe1d440ab2642c8cc312dd609b4b9939ca8 Mon Sep 17 00:00:00 2001
From: Richard Guo <guofenglinux@gmail.com>
Date: Mon, 10 Jul 2023 14:24:42 +0800
Subject: [PATCH v3] ignore is not null quals on not null columns

---
 src/backend/optimizer/plan/initsplan.c  | 179 +++++++++++++++++-------
 src/backend/optimizer/util/joininfo.c   |   5 +
 src/backend/optimizer/util/plancat.c    |   9 ++
 src/backend/optimizer/util/relnode.c    |   2 +
 src/include/nodes/pathnodes.h           |   2 +
 src/include/optimizer/planmain.h        |   2 +
 src/test/regress/expected/predicate.out | 107 ++++++++++++++
 src/test/regress/parallel_schedule      |   2 +-
 src/test/regress/sql/predicate.sql      |  48 +++++++
 9 files changed, 308 insertions(+), 48 deletions(-)
 create mode 100644 src/test/regress/expected/predicate.out
 create mode 100644 src/test/regress/sql/predicate.sql

diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index b31d892121..980429d469 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,110 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_baserestrictinfo_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted by
+ *		'relid' with some prechecks to try to determine if the qual is always
+ *		true, in which case we ignore it rather than add it.
+ */
+static void
+add_baserestrictinfo_to_rel(PlannerInfo *root, Index relid,
+							RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * nulltest_is_always_true
+ *	  Check to see if the NullTest qual is always true.
+ *
+ * If the NullTest is an IS_NOT_NULL qual on a NOT NULL column, and meanwhile
+ * its Var is not nulled by any outer joins, then we can know that it would be
+ * always true.
+ */
+static bool
+nulltest_is_always_true(PlannerInfo *root, NullTest *nulltest)
+{
+	RelOptInfo *rel;
+	Var		   *var;
+
+	Assert(IsA(nulltest, NullTest));
+
+	/* is this NullTest an IS_NOT_NULL qual? */
+	if (nulltest->nulltesttype != IS_NOT_NULL)
+		return false;
+
+	if (!IsA(nulltest->arg, Var))
+		return false;
+
+	var = (Var *) nulltest->arg;
+
+	/* could the Var be nulled by any outer joins? */
+	if (!bms_is_empty(var->varnullingrels))
+		return false;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		return true;
+
+	/* is the column defined NOT NULL? */
+	rel = find_base_rel(root, var->varno);
+	if (var->varattno > 0 &&
+		bms_is_member(var->varattno, rel->notnullattnums))
+		return true;
+
+	return false;
+}
+
+/*
+ * restriction_is_always_true
+ *	  Check to see if the RestrictInfo is always true.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_true(PlannerInfo *root,
+						   RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+		return nulltest_is_always_true(root, (NullTest *) restrictinfo->clause);
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo))
+				continue;
+
+			if (restriction_is_always_true(root, (RestrictInfo *) orarg))
+				return true;
+		}
+	}
+
+	return false;
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,58 +2736,39 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
+	int			relid;
 
-	switch (bms_membership(relids))
+	if (relids == NULL)
 	{
-		case BMS_SINGLETON:
-
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, bms_singleton_member(relids));
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-			break;
-		case BMS_MULTIPLE:
-
-			/*
-			 * The clause is a join clause, since there is more than one rel
-			 * in its relid set.
-			 */
-
-			/*
-			 * Check for hashjoinable operators.  (We don't bother setting the
-			 * hashjoin info except in true join clauses.)
-			 */
-			check_hashjoinable(restrictinfo);
+		/*
+		 * clause references no rels, and therefore we have no place to
+		 * attach it.  Shouldn't get here if callers are working properly.
+		 */
+		elog(ERROR, "cannot cope with variable-free clause");
+	}
+	else if (bms_get_singleton_member(relids, &relid))
+		add_baserestrictinfo_to_rel(root, relid, restrictinfo);
+	else
+	{
+		/*
+		 * The clause is a join clause, since there is more than one rel in
+		 * its relid set.
+		 */
 
-			/*
-			 * Likewise, check if the clause is suitable to be used with a
-			 * Memoize node to cache inner tuples during a parameterized
-			 * nested loop.
-			 */
-			check_memoizable(restrictinfo);
+		/*
+		 * Check for hashjoinable operators.  (We don't bother setting the
+		 * hashjoin info except in true join clauses.)
+		 */
+		check_hashjoinable(restrictinfo);
 
-			/*
-			 * Add clause to the join lists of all the relevant relations.
-			 */
-			add_join_clause_to_rels(root, restrictinfo, relids);
-			break;
-		default:
+		/*
+		 * Likewise, check if the clause is suitable to be used with a Memoize
+		 * node to cache inner tuples during a parameterized nested loop.
+		 */
+		check_memoizable(restrictinfo);
 
-			/*
-			 * clause references no rels, and therefore we have no place to
-			 * attach it.  Shouldn't get here if callers are working properly.
-			 */
-			elog(ERROR, "cannot cope with variable-free clause");
-			break;
+		/* Add clause to the join lists of all the relevant relations. */
+		add_join_clause_to_rels(root, restrictinfo, relids);
 	}
 }
 
diff --git a/src/backend/optimizer/util/joininfo.c b/src/backend/optimizer/util/joininfo.c
index 968a5a488e..add124e395 100644
--- a/src/backend/optimizer/util/joininfo.c
+++ b/src/backend/optimizer/util/joininfo.c
@@ -17,6 +17,7 @@
 #include "optimizer/joininfo.h"
 #include "optimizer/pathnode.h"
 #include "optimizer/paths.h"
+#include "optimizer/planmain.h"
 
 
 /*
@@ -98,6 +99,10 @@ add_join_clause_to_rels(PlannerInfo *root,
 {
 	int			cur_relid;
 
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
 	cur_relid = -1;
 	while ((cur_relid = bms_next_member(join_relids, cur_relid)) >= 0)
 	{
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 39932d3c2d..d810ad8127 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,15 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+			rel->notnullattnums = bms_add_member(rel->notnullattnums, attr->attnum);
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 15e3910b79..9b2b390c46 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -221,6 +221,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->relid = relid;
 	rel->rtekind = rte->rtekind;
 	/* min_attr, max_attr, attr_needed, attr_widths are set below */
+	rel->notnullattnums = NULL;
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
@@ -707,6 +708,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index c17b53f7ad..a0b602c9be 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset  *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index 5fc900737d..c8582792d4 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -75,6 +75,8 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern bool restriction_is_always_true(PlannerInfo *root,
+									   RestrictInfo *restrictinfo);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
diff --git a/src/test/regress/expected/predicate.out b/src/test/regress/expected/predicate.out
new file mode 100644
index 0000000000..43c8985042
--- /dev/null
+++ b/src/test/regress/expected/predicate.out
@@ -0,0 +1,107 @@
+--
+-- Tests for predicate handling
+--
+--
+-- test that restrictions that are always true are ignored
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int);
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+        QUERY PLAN         
+---------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NOT NULL)
+(2 rows)
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NOT NULL) OR (a = 1))
+(2 rows)
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NOT NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NOT NULL) OR (t2.b = 1))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+drop table pred_tab;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index cf46fa3359..25f0596971 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr
 # The stats test resets stats, so nothing else needing stats access can be in
 # this group.
 # ----------
-test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
 
 # event_trigger cannot run concurrently with any test that runs DDL
 # oidjoins is read-only, though, and should run late for best coverage
diff --git a/src/test/regress/sql/predicate.sql b/src/test/regress/sql/predicate.sql
new file mode 100644
index 0000000000..0b2e4cd0a6
--- /dev/null
+++ b/src/test/regress/sql/predicate.sql
@@ -0,0 +1,48 @@
+--
+-- Tests for predicate handling
+--
+
+--
+-- test that restrictions that are always true are ignored
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int);
+
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+drop table pred_tab;
+
-- 
2.31.0

#18Richard Guo
guofenglinux@gmail.com
In reply to: Richard Guo (#17)
1 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Mon, Jul 10, 2023 at 2:39 PM Richard Guo <guofenglinux@gmail.com> wrote:

Here is v3 patch with regression tests. I add the new test into the
group where stats test is in, but I'm not sure if this is the right
place.

cfbot says there is a test failure in postgres_fdw. So update to v4 to
fix that.

Thanks
Richard

Attachments:

v4-0001-ignore-is-not-null-quals-on-not-null-columns.patchapplication/octet-stream; name=v4-0001-ignore-is-not-null-quals-on-not-null-columns.patchDownload
From a334c8765495670ea99b25729d3ee02483bd9dff Mon Sep 17 00:00:00 2001
From: Richard Guo <guofenglinux@gmail.com>
Date: Mon, 10 Jul 2023 14:24:42 +0800
Subject: [PATCH v4] ignore is not null quals on not null columns

---
 .../postgres_fdw/expected/postgres_fdw.out    |   8 +-
 contrib/postgres_fdw/sql/postgres_fdw.sql     |   2 +-
 src/backend/optimizer/plan/initsplan.c        | 179 +++++++++++++-----
 src/backend/optimizer/util/joininfo.c         |   5 +
 src/backend/optimizer/util/plancat.c          |   9 +
 src/backend/optimizer/util/relnode.c          |   2 +
 src/include/nodes/pathnodes.h                 |   2 +
 src/include/optimizer/planmain.h              |   2 +
 src/test/regress/expected/predicate.out       | 107 +++++++++++
 src/test/regress/parallel_schedule            |   2 +-
 src/test/regress/sql/predicate.sql            |  48 +++++
 11 files changed, 313 insertions(+), 53 deletions(-)
 create mode 100644 src/test/regress/expected/predicate.out
 create mode 100644 src/test/regress/sql/predicate.sql

diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 852b5b4707..e7c42114ef 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -664,12 +664,12 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- Nu
    Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
-                                             QUERY PLAN                                              
------------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
+                                            QUERY PLAN                                            
+--------------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NOT NULL))
 (3 rows)
 
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 2fe8abc7af..d2cb367cef 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -333,7 +333,7 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1;         -- Var, OpExpr(b), Const
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1;          -- OpExpr(l)
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index b31d892121..980429d469 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,110 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_baserestrictinfo_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted by
+ *		'relid' with some prechecks to try to determine if the qual is always
+ *		true, in which case we ignore it rather than add it.
+ */
+static void
+add_baserestrictinfo_to_rel(PlannerInfo *root, Index relid,
+							RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * nulltest_is_always_true
+ *	  Check to see if the NullTest qual is always true.
+ *
+ * If the NullTest is an IS_NOT_NULL qual on a NOT NULL column, and meanwhile
+ * its Var is not nulled by any outer joins, then we can know that it would be
+ * always true.
+ */
+static bool
+nulltest_is_always_true(PlannerInfo *root, NullTest *nulltest)
+{
+	RelOptInfo *rel;
+	Var		   *var;
+
+	Assert(IsA(nulltest, NullTest));
+
+	/* is this NullTest an IS_NOT_NULL qual? */
+	if (nulltest->nulltesttype != IS_NOT_NULL)
+		return false;
+
+	if (!IsA(nulltest->arg, Var))
+		return false;
+
+	var = (Var *) nulltest->arg;
+
+	/* could the Var be nulled by any outer joins? */
+	if (!bms_is_empty(var->varnullingrels))
+		return false;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		return true;
+
+	/* is the column defined NOT NULL? */
+	rel = find_base_rel(root, var->varno);
+	if (var->varattno > 0 &&
+		bms_is_member(var->varattno, rel->notnullattnums))
+		return true;
+
+	return false;
+}
+
+/*
+ * restriction_is_always_true
+ *	  Check to see if the RestrictInfo is always true.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_true(PlannerInfo *root,
+						   RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+		return nulltest_is_always_true(root, (NullTest *) restrictinfo->clause);
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo))
+				continue;
+
+			if (restriction_is_always_true(root, (RestrictInfo *) orarg))
+				return true;
+		}
+	}
+
+	return false;
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,58 +2736,39 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
+	int			relid;
 
-	switch (bms_membership(relids))
+	if (relids == NULL)
 	{
-		case BMS_SINGLETON:
-
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, bms_singleton_member(relids));
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-			break;
-		case BMS_MULTIPLE:
-
-			/*
-			 * The clause is a join clause, since there is more than one rel
-			 * in its relid set.
-			 */
-
-			/*
-			 * Check for hashjoinable operators.  (We don't bother setting the
-			 * hashjoin info except in true join clauses.)
-			 */
-			check_hashjoinable(restrictinfo);
+		/*
+		 * clause references no rels, and therefore we have no place to
+		 * attach it.  Shouldn't get here if callers are working properly.
+		 */
+		elog(ERROR, "cannot cope with variable-free clause");
+	}
+	else if (bms_get_singleton_member(relids, &relid))
+		add_baserestrictinfo_to_rel(root, relid, restrictinfo);
+	else
+	{
+		/*
+		 * The clause is a join clause, since there is more than one rel in
+		 * its relid set.
+		 */
 
-			/*
-			 * Likewise, check if the clause is suitable to be used with a
-			 * Memoize node to cache inner tuples during a parameterized
-			 * nested loop.
-			 */
-			check_memoizable(restrictinfo);
+		/*
+		 * Check for hashjoinable operators.  (We don't bother setting the
+		 * hashjoin info except in true join clauses.)
+		 */
+		check_hashjoinable(restrictinfo);
 
-			/*
-			 * Add clause to the join lists of all the relevant relations.
-			 */
-			add_join_clause_to_rels(root, restrictinfo, relids);
-			break;
-		default:
+		/*
+		 * Likewise, check if the clause is suitable to be used with a Memoize
+		 * node to cache inner tuples during a parameterized nested loop.
+		 */
+		check_memoizable(restrictinfo);
 
-			/*
-			 * clause references no rels, and therefore we have no place to
-			 * attach it.  Shouldn't get here if callers are working properly.
-			 */
-			elog(ERROR, "cannot cope with variable-free clause");
-			break;
+		/* Add clause to the join lists of all the relevant relations. */
+		add_join_clause_to_rels(root, restrictinfo, relids);
 	}
 }
 
diff --git a/src/backend/optimizer/util/joininfo.c b/src/backend/optimizer/util/joininfo.c
index 968a5a488e..add124e395 100644
--- a/src/backend/optimizer/util/joininfo.c
+++ b/src/backend/optimizer/util/joininfo.c
@@ -17,6 +17,7 @@
 #include "optimizer/joininfo.h"
 #include "optimizer/pathnode.h"
 #include "optimizer/paths.h"
+#include "optimizer/planmain.h"
 
 
 /*
@@ -98,6 +99,10 @@ add_join_clause_to_rels(PlannerInfo *root,
 {
 	int			cur_relid;
 
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
 	cur_relid = -1;
 	while ((cur_relid = bms_next_member(join_relids, cur_relid)) >= 0)
 	{
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 39932d3c2d..d810ad8127 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,15 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+			rel->notnullattnums = bms_add_member(rel->notnullattnums, attr->attnum);
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 76dad17e33..990335e078 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -221,6 +221,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->relid = relid;
 	rel->rtekind = rte->rtekind;
 	/* min_attr, max_attr, attr_needed, attr_widths are set below */
+	rel->notnullattnums = NULL;
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
@@ -707,6 +708,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index c17b53f7ad..a0b602c9be 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset  *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index 31c188176b..0d54c93cc0 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -75,6 +75,8 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern bool restriction_is_always_true(PlannerInfo *root,
+									   RestrictInfo *restrictinfo);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
diff --git a/src/test/regress/expected/predicate.out b/src/test/regress/expected/predicate.out
new file mode 100644
index 0000000000..43c8985042
--- /dev/null
+++ b/src/test/regress/expected/predicate.out
@@ -0,0 +1,107 @@
+--
+-- Tests for predicate handling
+--
+--
+-- test that restrictions that are always true are ignored
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int);
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+        QUERY PLAN         
+---------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NOT NULL)
+(2 rows)
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NOT NULL) OR (a = 1))
+(2 rows)
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NOT NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NOT NULL) OR (t2.b = 1))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+drop table pred_tab;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 4df9d8503b..3816efc7b3 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr
 # The stats test resets stats, so nothing else needing stats access can be in
 # this group.
 # ----------
-test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
 
 # event_trigger depends on create_am and cannot run concurrently with
 # any test that runs DDL
diff --git a/src/test/regress/sql/predicate.sql b/src/test/regress/sql/predicate.sql
new file mode 100644
index 0000000000..0b2e4cd0a6
--- /dev/null
+++ b/src/test/regress/sql/predicate.sql
@@ -0,0 +1,48 @@
+--
+-- Tests for predicate handling
+--
+
+--
+-- test that restrictions that are always true are ignored
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int);
+
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+drop table pred_tab;
+
-- 
2.31.0

#19David Rowley
dgrowleyml@gmail.com
In reply to: Richard Guo (#17)
1 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Mon, 10 Jul 2023 at 18:39, Richard Guo <guofenglinux@gmail.com> wrote:

Here is v3 patch with regression tests. I add the new test into the
group where stats test is in, but I'm not sure if this is the right
place.

Thanks for taking an interest in this.

I spent more time looking at the idea and I wondered why we should
just have it skip distributing IS NOT NULL quals to the relations.
Should we also be allow IS NULL quals on non-nullable Vars to be
detected as false?

I did some work on your v3 patch to see if that could be made to work.
I ended up just trying to make a new RestrictInfo with a "false"
clause, but quickly realised that it's not safe to go making new
RestrictInfos during deconstruct_distribute_oj_quals(). A comment
there mentions:

/*
* Each time we produce RestrictInfo(s) from these quals, reset the
* last_rinfo_serial counter, so that the RestrictInfos for the "same"
* qual condition get identical serial numbers. (This relies on the
* fact that we're not changing the qual list in any way that'd affect
* the number of RestrictInfos built from it.) This'll allow us to
* detect duplicative qual usage later.
*/

I ended up moving the function that looks for the NullTest quals in
the joinlist out so it's done after the quals have been distributed to
the relations. I'm not really that happy with this as if we ever
found some way to optimise quals that could be made part of an
EquivalenceClass then those quals would have already have been
processed to become EquivalenceClasses. I just don't see how to do it
earlier as deconstruct_distribute_oj_quals() calls
remove_nulling_relids() which changes the Var's varnullingrels causing
them to be empty during the processing of the NullTest qual.

It's also not so great that the RestrictInfo gets duplicated in:

CREATE TABLE t1 (a INT NOT NULL, b INT);
CREATE TABLE t2 (c INT NOT NULL, d INT);
CREATE TABLE t3 (e INT NOT NULL, f INT);

postgres=# EXPLAIN (costs off) SELECT * FROM t1 JOIN t2 ON t1.a = 1
LEFT JOIN t3 ON t2.c IS NULL AND t2.d = 1;
QUERY PLAN
-------------------------------------------------------
Nested Loop
-> Nested Loop Left Join
Join Filter: (false AND false AND (t2.d = 1))
-> Seq Scan on t2
-> Result
One-Time Filter: false
-> Materialize
-> Seq Scan on t1
Filter: (a = 1)
(9 rows)

Adjusting the code to build a new false clause and setting that in the
existing RestrictInfo rather than building a new RestrictInfo seems to
fix that. I wondered if the duplication was a result of the
rinfo_serial number changing.

Checking back to the original MinMaxAgg I'm not sure if this is all
getting more complex than it's worth or not.

I've attached what I've ended up with so far.

David

David

Attachments:

v4_transform_NullTest_quals.patchapplication/octet-stream; name=v4_transform_NullTest_quals.patchDownload
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index b31d892121..36bf47dc8e 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,225 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_baserestrictinfo_to_rel
+ *	  Add 'restrictinfo' as a baserestrictinfo to the base relation denoted by
+ *	  'relid'.  While here, attempt to determine if the given qual is always
+ *	  true or always false when evaluated as a base qual.  If we can determine
+ *	  that the qual needn't be evaluated by the executor, we replace the qual
+ *	  with a constant "true" or "false".
+ */
+static void
+add_baserestrictinfo_to_rel(PlannerInfo *root, Index relid,
+							RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+	Expr	   *newclause;
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	newclause = transform_clause(root, restrictinfo->clause);
+
+	if (newclause != restrictinfo->clause)
+	{
+		restrictinfo = make_restrictinfo(root,
+										 newclause,
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 restrictinfo->security_level,
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+	}
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * transform_nulltest
+ *	  Attempt to transform the given NullTest and into a constant "true" or
+ *	  "false".  This maybe possible when the column has a NOT NULL constraint
+ *	  which means an IS NOT NULL clause is always true or a IS NULL clause is
+ *	  always false.  If there is no NOT NULL constraint or if the column is
+ *	  NULLable by an outer join, or the NullTest's arg isn't a Var, then we
+ *	  return the input NullTest.
+ */
+static Expr *
+transform_nulltest(PlannerInfo *root, NullTest *nulltest)
+{
+	Var		   *var;
+	bool		notnull = false;
+
+	Assert(IsA(nulltest, NullTest));
+
+	/*
+	 * We only support Vars as there's no ability to have a NOT NULL constraint
+	 * on anything else.
+	 */
+	if (!IsA(nulltest->arg, Var))
+		return (Expr *) nulltest;
+
+	var = (Var *) nulltest->arg;
+
+	/* could the Var be nulled by any outer joins? */
+	if (var->varnullingrels != NULL)
+		return (Expr *) nulltest;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		notnull = true;
+	else if (var->varattno > 0)
+	{
+		/* is the column defined NOT NULL? */
+		RelOptInfo *rel = find_base_rel(root, var->varno);
+		
+		if (bms_is_member(var->varattno, rel->notnullattnums))
+			notnull = true;
+	}
+	else
+	{
+		RelOptInfo	   *rel = find_base_rel(root, var->varno);
+		Bitmapset	   *allattnums = bms_add_range(NULL, 1, rel->max_attr);
+
+		/*
+		 * Handle whole-row Vars.  The SQL standard defines IS [NOT] NULL for a
+		 * non-null rowtype argument as:
+		 *
+		 * "R IS NULL" is true if every field is the null value.
+		 *
+		 * "R IS NOT NULL" is true if no field is the null value.
+		 */
+
+		/*
+		 * XXX the IS NOT NULL won't work correctly if there are dropped columns.
+		 * Is it worth having another set in RelOptInfo to allow us to remove
+		 * dropped columns from allattnums before the bms_nonempty_difference?
+		 * XXX should we even bother handling whole-row Vars??
+		 */
+		if (nulltest->nulltesttype == IS_NOT_NULL)
+			notnull = !bms_nonempty_difference(allattnums,
+											   rel->notnullattnums);
+		else
+			notnull = bms_overlap(allattnums, rel->notnullattnums);
+		bms_free(allattnums);
+	}
+
+	/*
+	 * When the column cannot be NULL, we can transform IS NOT NULL quals to
+	 * "true" and IS NULL quals to "false".
+	 */
+	if (notnull)
+	{
+		bool	constexpr = (nulltest->nulltesttype == IS_NOT_NULL);
+
+		return (Expr *) makeBoolConst(constexpr, false);
+	}
+
+	return (Expr *) nulltest;
+}
+
+/*
+ * transform_clause
+ *	  Check and attempt to transform 'clause' into either a constant true or
+ *	  constant false if we're able to determine that the qual needn't be
+ *	  evaluated by the executor.
+ *
+ * Returns a newly allocated Expr if any tranformation was done, else returns
+ * the input Expr unmodified.
+ */
+Expr *
+transform_clause(PlannerInfo *root, Expr *clause)
+{
+	/*
+	 * Currently we only check for NullTest quals and OR clauses that include
+	 * NullTest quals.
+	 */
+
+	/* Check for NullTest qual */
+	if (IsA(clause, NullTest))
+		return transform_nulltest(root, (NullTest *) clause);
+
+	if (is_orclause(clause))
+	{
+		ListCell   *lc;
+		bool reeval_const = false;
+
+		/* If it's an OR, check its sub-clauses */
+		foreach (lc, ((BoolExpr *) clause)->args)
+		{
+			Expr   *orarg = (Expr *) lfirst(lc);
+
+			if (IsA(orarg, Const))
+				reeval_const = true;
+			else
+			{
+				Expr   *newexpr = transform_clause(root, orarg);
+
+				if (newexpr != orarg)
+				{
+					reeval_const = true;
+					lfirst(lc) = newexpr;
+				}
+			}
+		}
+
+		/*
+		 * If we managed to transform any clauses or found a Const in the OR clause
+		 * then let's try constant folding again as it may allow us to simplify (or
+		 * delete) the OR clause.
+		 */
+		if (reeval_const)
+			clause = (Expr *) eval_const_expressions(root, (Node *) clause);
+	}
+
+	return clause;
+}
+
+void
+transform_join_clauses(PlannerInfo *root)
+{
+	if (root->simple_rel_array_size == 1)
+		return;
+
+	for (int i = 1; i < root->simple_rel_array_size; i++)
+	{
+		RelOptInfo *rel = root->simple_rel_array[i];
+		ListCell *lc;
+
+		if (rel == NULL || rel->reloptkind != RELOPT_BASEREL)
+			continue;
+
+		foreach(lc, rel->joininfo)
+		{
+			RestrictInfo *restrictinfo = lfirst(lc);
+			Expr *newclause = transform_clause(root, restrictinfo->clause);
+
+			if (newclause != restrictinfo->clause)
+			{
+				restrictinfo =
+						make_restrictinfo(root,
+										  newclause,
+										  restrictinfo->is_pushed_down,
+										  restrictinfo->has_clone,
+										  restrictinfo->is_clone,
+										  restrictinfo->pseudoconstant,
+										  restrictinfo->security_level,
+										  restrictinfo->required_relids,
+										  restrictinfo->incompatible_relids,
+										  restrictinfo->outer_relids);
+				lfirst(lc) = restrictinfo;
+			}
+		}
+	}
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,58 +2851,39 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
+	int			relid;
 
-	switch (bms_membership(relids))
+	if (relids == NULL)
 	{
-		case BMS_SINGLETON:
-
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, bms_singleton_member(relids));
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-			break;
-		case BMS_MULTIPLE:
-
-			/*
-			 * The clause is a join clause, since there is more than one rel
-			 * in its relid set.
-			 */
-
-			/*
-			 * Check for hashjoinable operators.  (We don't bother setting the
-			 * hashjoin info except in true join clauses.)
-			 */
-			check_hashjoinable(restrictinfo);
+		/*
+		 * clause references no rels, and therefore we have no place to
+		 * attach it.  Shouldn't get here if callers are working properly.
+		 */
+		elog(ERROR, "cannot cope with variable-free clause");
+	}
+	else if (bms_get_singleton_member(relids, &relid))
+		add_baserestrictinfo_to_rel(root, relid, restrictinfo);
+	else
+	{
+		/*
+		 * The clause is a join clause, since there is more than one rel in
+		 * its relid set.
+		 */
 
-			/*
-			 * Likewise, check if the clause is suitable to be used with a
-			 * Memoize node to cache inner tuples during a parameterized
-			 * nested loop.
-			 */
-			check_memoizable(restrictinfo);
+		/*
+		 * Check for hashjoinable operators.  (We don't bother setting the
+		 * hashjoin info except in true join clauses.)
+		 */
+		check_hashjoinable(restrictinfo);
 
-			/*
-			 * Add clause to the join lists of all the relevant relations.
-			 */
-			add_join_clause_to_rels(root, restrictinfo, relids);
-			break;
-		default:
+		/*
+		 * Likewise, check if the clause is suitable to be used with a Memoize
+		 * node to cache inner tuples during a parameterized nested loop.
+		 */
+		check_memoizable(restrictinfo);
 
-			/*
-			 * clause references no rels, and therefore we have no place to
-			 * attach it.  Shouldn't get here if callers are working properly.
-			 */
-			elog(ERROR, "cannot cope with variable-free clause");
-			break;
+		/* Add clause to the join lists of all the relevant relations. */
+		add_join_clause_to_rels(root, restrictinfo, relids);
 	}
 }
 
diff --git a/src/backend/optimizer/plan/planmain.c b/src/backend/optimizer/plan/planmain.c
index fcc0eacd25..e24887f505 100644
--- a/src/backend/optimizer/plan/planmain.c
+++ b/src/backend/optimizer/plan/planmain.c
@@ -195,6 +195,8 @@ query_planner(PlannerInfo *root,
 	 */
 	reconsider_outer_join_clauses(root);
 
+	transform_join_clauses(root);
+
 	/*
 	 * If we formed any equivalence classes, generate additional restriction
 	 * clauses as appropriate.  (Implied join clauses are formed on-the-fly
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 243c8fb1e4..4677f479c5 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,23 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+		{
+			rel->notnullattnums = bms_add_member(rel->notnullattnums,
+												 attr->attnum);
+			/*
+			 * Per ATExecDropNotNull(), dropped columns will have their attnotnull
+			 * unset, so we needn't check for dropped columns in the above condition.
+			 */
+			Assert(!attr->attisdropped);
+		}
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
@@ -1549,16 +1566,20 @@ relation_excluded_by_constraints(PlannerInfo *root,
 
 	/*
 	 * Regardless of the setting of constraint_exclusion, detect
-	 * constant-FALSE-or-NULL restriction clauses.  Because const-folding will
-	 * reduce "anything AND FALSE" to just "FALSE", any such case should
-	 * result in exactly one baserestrictinfo entry.  This doesn't fire very
-	 * often, but it seems cheap enough to be worth doing anyway.  (Without
-	 * this, we'd miss some optimizations that 9.5 and earlier found via much
-	 * more roundabout methods.)
+	 * constant-FALSE-or-NULL restriction clauses.  Const-folding will reduce
+	 * "anything AND FALSE" to just "FALSE", any such case should result in
+	 * exactly one baserestrictinfo entry.  The transform_clause()
+	 * infrastructure isn't quite as careful and may leave a "FALSE" within a
+	 * List of RestrictInfos.  Here we loop over each restrictinfo to check
+	 * and return true if we find any impossible RestrictInfos.
+	 *
+	 * This doesn't fire very often, but it seems cheap enough to be worth
+	 * doing anyway.  (Without this, we'd miss some optimizations that 9.5 and
+	 * earlier found via much more roundabout methods.)
 	 */
-	if (list_length(rel->baserestrictinfo) == 1)
+	foreach(lc, rel->baserestrictinfo)
 	{
-		RestrictInfo *rinfo = (RestrictInfo *) linitial(rel->baserestrictinfo);
+		RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
 		Expr	   *clause = rinfo->clause;
 
 		if (clause && IsA(clause, Const) &&
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 76dad17e33..5d6d97c111 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -221,6 +221,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->relid = relid;
 	rel->rtekind = rte->rtekind;
 	/* min_attr, max_attr, attr_needed, attr_widths are set below */
+	rel->notnullattnums = NULL;
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
@@ -707,6 +708,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
@@ -905,6 +907,7 @@ build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 5702fbba60..d4f6bbcd2c 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset  *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index 31c188176b..f8b794b0e3 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -75,6 +75,8 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern Expr *transform_clause(PlannerInfo *root, Expr *clause);
+extern void transform_join_clauses(PlannerInfo *root);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out
index 9b8638f286..b95d30f658 100644
--- a/src/test/regress/expected/join.out
+++ b/src/test/regress/expected/join.out
@@ -5788,13 +5788,11 @@ explain (costs off)
 select p.* from
   parent p left join child c on (p.k = c.k)
   where p.k = 1 and p.k = 2;
-                   QUERY PLAN                   
-------------------------------------------------
+        QUERY PLAN        
+--------------------------
  Result
    One-Time Filter: false
-   ->  Index Scan using parent_pkey on parent p
-         Index Cond: (k = 1)
-(4 rows)
+(2 rows)
 
 select p.* from
   (parent p left join child c on (p.k = c.k)) join parent x on p.k = x.k
diff --git a/src/test/regress/expected/predicate.out b/src/test/regress/expected/predicate.out
new file mode 100644
index 0000000000..5c4914dc80
--- /dev/null
+++ b/src/test/regress/expected/predicate.out
@@ -0,0 +1,146 @@
+--
+-- Tests for predicate transformation
+--
+CREATE TABLE pred_tab (a INT NOT NULL, b INT);
+--
+-- test that restrictions that we detect as always true are ignored
+--
+-- An IS NOT NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- A more complex variant of the above.  Ensure we're left only with the
+-- t.b = 1 qual since t.a IS NOT NULL is always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b = 1 AND t.a IS NOT NULL;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+   Filter: (b = 1)
+(2 rows)
+
+-- Ensure t.b IS NOT NULL is not removed as t.b allows NULL values.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL;
+        QUERY PLAN         
+---------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NOT NULL)
+(2 rows)
+
+-- Ensure the t.a IS NOT NULL is detected as always true.  We shouldn't see
+-- any quals in the scan.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL OR t.b = 1;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- Ensure the quals remain as t.b allows NULL values.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL OR t.a = 1;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NOT NULL) OR (a = 1))
+(2 rows)
+
+-- An IS NOT NULL NullTest in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and;
+-- b) its Var is not nulled by any outer joins
+-- Ensure t2.a IS NOT NULL is not seen in the plan
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1 LEFT JOIN pred_tab t2 ON true
+LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- When some t2 rows are missing due to the left join we cannot forego
+-- including the t2.a is not null in the plan.  Ensure it remains.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1 LEFT JOIN pred_tab t2 ON t1.a = 1
+LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NOT NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- Ensure t2.a IS NULL is detected as constantly TRUE and results in none of
+-- the quals appearing in the plan.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1 LEFT JOIN pred_tab t2 ON true
+LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Ensure that the IS NOT NULL qual isn't removed as t2.a is nullable from
+-- t2's left join to t1.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1 LEFT JOIN pred_tab t2 ON t1.a = 1
+LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+                    QUERY PLAN
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NOT NULL) OR (t2.b = 1))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+--
+-- Ensure that impossible IS NULL NullTests are detected when the Var cannot
+-- be NULL
+--
+-- Ensure we detect t.a IS NULL is impossible AND forego the scan
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- As above, but add an additional qual
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a = 1234 AND t.a IS NULL;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+DROP TABLE pred_tab;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 4df9d8503b..3816efc7b3 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr
 # The stats test resets stats, so nothing else needing stats access can be in
 # this group.
 # ----------
-test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
 
 # event_trigger depends on create_am and cannot run concurrently with
 # any test that runs DDL
diff --git a/src/test/regress/sql/predicate.sql b/src/test/regress/sql/predicate.sql
new file mode 100644
index 0000000000..faeb54aee7
--- /dev/null
+++ b/src/test/regress/sql/predicate.sql
@@ -0,0 +1,75 @@
+--
+-- Tests for predicate transformation
+--
+
+CREATE TABLE pred_tab (a INT NOT NULL, b INT);
+
+--
+-- test that restrictions that we detect as always true are ignored
+--
+
+-- An IS NOT NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL;
+
+-- A more complex variant of the above.  Ensure we're left only with the
+-- t.b = 1 qual since t.a IS NOT NULL is always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b = 1 AND t.a IS NOT NULL;
+
+-- Ensure t.b IS NOT NULL is not removed as t.b allows NULL values.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL;
+
+-- Ensure the t.a IS NOT NULL is detected as always true.  We shouldn't see
+-- any quals in the scan.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL OR t.b = 1;
+
+-- Ensure the quals remain as t.b allows NULL values.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL OR t.a = 1;
+
+-- An IS NOT NULL NullTest in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and;
+-- b) its Var is not nulled by any outer joins
+
+-- Ensure t2.a IS NOT NULL is not seen in the plan
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1 LEFT JOIN pred_tab t2 ON true
+LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+
+-- When some t2 rows are missing due to the left join we cannot forego
+-- including the t2.a is not null in the plan.  Ensure it remains.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1 LEFT JOIN pred_tab t2 ON t1.a = 1
+LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+
+-- Ensure t2.a IS NULL is detected as constantly TRUE and results in none of
+-- the quals appearing in the plan.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1 LEFT JOIN pred_tab t2 ON true
+LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+
+-- Ensure that the IS NOT NULL qual isn't removed as t2.a is nullable from
+-- t2's left join to t1.
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1 LEFT JOIN pred_tab t2 ON t1.a = 1
+LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+
+--
+-- Ensure that impossible IS NULL NullTests are detected when the Var cannot
+-- be NULL
+--
+
+-- Ensure we detect t.a IS NULL is impossible AND forego the scan
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL;
+
+-- As above, but add an additional qual
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a = 1234 AND t.a IS NULL;
+
+DROP TABLE pred_tab;
+
#20Richard Guo
guofenglinux@gmail.com
In reply to: David Rowley (#19)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Tue, Sep 26, 2023 at 9:42 PM David Rowley <dgrowleyml@gmail.com> wrote:

I ended up moving the function that looks for the NullTest quals in
the joinlist out so it's done after the quals have been distributed to
the relations.

It seems that the RestrictInfos for the "same" qual condition still may
get different serial numbers even if transform_join_clauses() is called
after we've distributed all the quals. For example,

select * from t1
left join t2 on t1.a = t2.c
left join t3 on t2.c = t3.e and t2.c is null;

There are two versions for qual 't2.c is null': with and without being
marked nullable by t1/t2 join. Let's write them as 'c* is null' and 'c
is null'. They are supposed to have identical serial number. But after
we've transformed 'c is null' to 'false', they do not have identical
serial number any more. This may cause problems where the logic of
serial numbers is relied on?

I'm not really that happy with this as if we ever
found some way to optimise quals that could be made part of an
EquivalenceClass then those quals would have already have been
processed to become EquivalenceClasses. I just don't see how to do it
earlier as deconstruct_distribute_oj_quals() calls
remove_nulling_relids() which changes the Var's varnullingrels causing
them to be empty during the processing of the NullTest qual.

Hmm, I don't think it's a problem that deconstruct_distribute_oj_quals
changes the nullingrels. It will compute the correct nullingrels at
last for different clones of the same qual condition. We can just check
the nullingrels whatever it computes.

It's also not so great that the RestrictInfo gets duplicated in:

Adjusting the code to build a new false clause and setting that in the
existing RestrictInfo rather than building a new RestrictInfo seems to
fix that. I wondered if the duplication was a result of the
rinfo_serial number changing.

The RestrictInfo nodes in different joinlists are multiply-linked rather
than copied, so when building restrictlist for a joinrel we use pointer
equality to remove any duplication. In your patch new RestrictInfo
nodes are created in transform_join_clauses(), so pointer equality no
longer works and we see duplication in the plan.

Checking back to the original MinMaxAgg I'm not sure if this is all
getting more complex than it's worth or not.

It seems that optimizing IS NULL quals is more complex than optimizing
IS NOT NULL quals. I also wonder if it's worth the trouble to optimize
IS NULL quals.

BTW, there is an Assert failure running regression tests with your
patch. I haven't looked into it.

Thanks
Richard

#21David Rowley
dgrowleyml@gmail.com
In reply to: Richard Guo (#20)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Thu, 28 Sept 2023 at 16:22, Richard Guo <guofenglinux@gmail.com> wrote:

It seems that optimizing IS NULL quals is more complex than optimizing
IS NOT NULL quals. I also wonder if it's worth the trouble to optimize
IS NULL quals.

I'm happy to reduce the scope of this patch. As for what to cut, I
think if we're doing a subset then we should try to do that subset in
a way that best leaves things open for phase 2 at some later date.

In my view, it would be less surprising that this works for base quals
and not join quals than if it worked with "Var IS NOT NULL" but not
"Var IS NULL". I'm unsure if my view is clouded by the fact that I
don't have a clear picture in my head on how this should work for join
quals, however.

Would it be surprising if this didn't work for join quals? My
thoughts are probably not any more so than the fact that extended
statistics only work for base quals and not join quals, but I'm sure
other people will have different views on that. I don't feel like we
should end up with exactly nothing committed from this patch solely
due to scope creep.

David

#22Richard Guo
guofenglinux@gmail.com
In reply to: David Rowley (#21)
1 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Thu, Sep 28, 2023 at 11:51 AM David Rowley <dgrowleyml@gmail.com> wrote:

On Thu, 28 Sept 2023 at 16:22, Richard Guo <guofenglinux@gmail.com> wrote:

It seems that optimizing IS NULL quals is more complex than optimizing
IS NOT NULL quals. I also wonder if it's worth the trouble to optimize
IS NULL quals.

I'm happy to reduce the scope of this patch. As for what to cut, I
think if we're doing a subset then we should try to do that subset in
a way that best leaves things open for phase 2 at some later date.

I had a go at supporting IS NULL quals and ended up with the attached.
The patch generates a new constant-FALSE RestrictInfo that is marked
with the same required_relids etc as the original one if it is an IS
NULL qual that can be reduced to FALSE. Note that the original
rinfo_serial is also copied to the new RestrictInfo.

One thing that is not great is that we may have 'FALSE and otherquals'
in the final plan, as shown by the plan below which is from the new
added test case.

+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab
t3 on t2.a is null and t2.b = 1;
+                    QUERY PLAN
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)

Maybe we can artificially reduce it to 'FALSE', but I'm not sure if it's
worth the trouble.

Thanks
Richard

Attachments:

v5-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchapplication/octet-stream; name=v5-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchDownload
From 77641116c1d58bac901df71d9d4421b8639693bb Mon Sep 17 00:00:00 2001
From: Richard Guo <guofenglinux@gmail.com>
Date: Sat, 7 Oct 2023 17:04:07 +0800
Subject: [PATCH v5] Reduce NullTest quals to constant TRUE or FALSE

---
 .../postgres_fdw/expected/postgres_fdw.out    |  16 +-
 contrib/postgres_fdw/sql/postgres_fdw.sql     |   4 +-
 src/backend/optimizer/plan/initsplan.c        | 243 ++++++++++++++----
 src/backend/optimizer/util/joininfo.c         |  25 ++
 src/backend/optimizer/util/plancat.c          |  22 +-
 src/backend/optimizer/util/relnode.c          |   2 +
 src/include/nodes/pathnodes.h                 |   2 +
 src/include/optimizer/planmain.h              |   4 +
 src/test/regress/expected/join.out            |   8 +-
 src/test/regress/expected/predicate.out       | 204 +++++++++++++++
 src/test/regress/parallel_schedule            |   2 +-
 src/test/regress/sql/predicate.sql            |  80 ++++++
 12 files changed, 544 insertions(+), 68 deletions(-)
 create mode 100644 src/test/regress/expected/predicate.out
 create mode 100644 src/test/regress/sql/predicate.sql

diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 144c114d0f..4d7c5b9140 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -656,20 +656,20 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 =
    Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-                                           QUERY PLAN                                            
--------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+                                          QUERY PLAN                                          
+----------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NULL))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
-                                             QUERY PLAN                                              
------------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
+                                            QUERY PLAN                                            
+--------------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NOT NULL))
 (3 rows)
 
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index a303bfb322..8542a9e9de 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -332,8 +332,8 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
 -- ===================================================================
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1;         -- Var, OpExpr(b), Const
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1;          -- OpExpr(l)
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index b31d892121..06e73f4169 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,174 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_baserestrictinfo_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted
+ *		by 'relid' with some prechecks to try to determine if the qual is
+ *		always true, in which case we ignore it rather than add it, or if the
+ *		qual is always false, in which case we replace it with constant-FALSE.
+ */
+static void
+add_baserestrictinfo_to_rel(PlannerInfo *root, Index relid,
+							RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Substitute constant-FALSE for the origin qual if it is always false */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int		save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 false,	/* pseudoconstant */
+										 0,	/* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * expr_is_nonnullable
+ *	  Check to see if the Expr cannot be NULL
+ *
+ * If the Expr is a simple Var that is defined NOT NULL and meanwhile is not
+ * nulled by any outer joins, then we can know that it cannot be NULL.
+ */
+static bool
+expr_is_nonnullable(PlannerInfo *root, Expr *expr)
+{
+	RelOptInfo *rel;
+	Var		   *var;
+
+	/* For now only check simple Vars */
+	if (!IsA(expr, Var))
+		return false;
+
+	var = (Var *) expr;
+
+	/* could the Var be nulled by any outer joins? */
+	if (!bms_is_empty(var->varnullingrels))
+		return false;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		return true;
+
+	/* is the column defined NOT NULL? */
+	rel = find_base_rel(root, var->varno);
+	if (var->varattno > 0 &&
+		bms_is_member(var->varattno, rel->notnullattnums))
+		return true;
+
+	return false;
+}
+
+/*
+ * restriction_is_always_true
+ *	  Check to see if the RestrictInfo is always true.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_true(PlannerInfo *root,
+						   RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NOT_NULL qual? */
+		if (nulltest->nulltesttype != IS_NOT_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo))
+				continue;
+
+			if (restriction_is_always_true(root, (RestrictInfo *) orarg))
+				return true;
+		}
+	}
+
+	return false;
+}
+
+/*
+ * restriction_is_always_false
+ *	  Check to see if the RestrictInfo is always false.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_false(PlannerInfo *root,
+							RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NULL qual? */
+		if (nulltest->nulltesttype != IS_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo) ||
+				!restriction_is_always_false(root, (RestrictInfo *) orarg))
+				return false;
+		}
+		return true;
+	}
+
+	return false;
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,58 +2800,39 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
+	int			relid;
 
-	switch (bms_membership(relids))
+	if (relids == NULL)
 	{
-		case BMS_SINGLETON:
-
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, bms_singleton_member(relids));
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-			break;
-		case BMS_MULTIPLE:
-
-			/*
-			 * The clause is a join clause, since there is more than one rel
-			 * in its relid set.
-			 */
-
-			/*
-			 * Check for hashjoinable operators.  (We don't bother setting the
-			 * hashjoin info except in true join clauses.)
-			 */
-			check_hashjoinable(restrictinfo);
+		/*
+		 * clause references no rels, and therefore we have no place to
+		 * attach it.  Shouldn't get here if callers are working properly.
+		 */
+		elog(ERROR, "cannot cope with variable-free clause");
+	}
+	else if (bms_get_singleton_member(relids, &relid))
+		add_baserestrictinfo_to_rel(root, relid, restrictinfo);
+	else
+	{
+		/*
+		 * The clause is a join clause, since there is more than one rel in
+		 * its relid set.
+		 */
 
-			/*
-			 * Likewise, check if the clause is suitable to be used with a
-			 * Memoize node to cache inner tuples during a parameterized
-			 * nested loop.
-			 */
-			check_memoizable(restrictinfo);
+		/*
+		 * Check for hashjoinable operators.  (We don't bother setting the
+		 * hashjoin info except in true join clauses.)
+		 */
+		check_hashjoinable(restrictinfo);
 
-			/*
-			 * Add clause to the join lists of all the relevant relations.
-			 */
-			add_join_clause_to_rels(root, restrictinfo, relids);
-			break;
-		default:
+		/*
+		 * Likewise, check if the clause is suitable to be used with a Memoize
+		 * node to cache inner tuples during a parameterized nested loop.
+		 */
+		check_memoizable(restrictinfo);
 
-			/*
-			 * clause references no rels, and therefore we have no place to
-			 * attach it.  Shouldn't get here if callers are working properly.
-			 */
-			elog(ERROR, "cannot cope with variable-free clause");
-			break;
+		/* Add clause to the join lists of all the relevant relations. */
+		add_join_clause_to_rels(root, restrictinfo, relids);
 	}
 }
 
diff --git a/src/backend/optimizer/util/joininfo.c b/src/backend/optimizer/util/joininfo.c
index 968a5a488e..b0b960a001 100644
--- a/src/backend/optimizer/util/joininfo.c
+++ b/src/backend/optimizer/util/joininfo.c
@@ -14,9 +14,12 @@
  */
 #include "postgres.h"
 
+#include "nodes/makefuncs.h"
 #include "optimizer/joininfo.h"
 #include "optimizer/pathnode.h"
 #include "optimizer/paths.h"
+#include "optimizer/planmain.h"
+#include "optimizer/restrictinfo.h"
 
 
 /*
@@ -98,6 +101,28 @@ add_join_clause_to_rels(PlannerInfo *root,
 {
 	int			cur_relid;
 
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Substitute constant-FALSE for the origin qual if it is always false */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int		save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 false,	/* pseudoconstant */
+										 0,	/* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
 	cur_relid = -1;
 	while ((cur_relid = bms_next_member(join_relids, cur_relid)) >= 0)
 	{
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 243c8fb1e4..332690eeb0 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,15 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+			rel->notnullattnums = bms_add_member(rel->notnullattnums, attr->attnum);
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
@@ -1549,16 +1558,19 @@ relation_excluded_by_constraints(PlannerInfo *root,
 
 	/*
 	 * Regardless of the setting of constraint_exclusion, detect
-	 * constant-FALSE-or-NULL restriction clauses.  Because const-folding will
-	 * reduce "anything AND FALSE" to just "FALSE", any such case should
-	 * result in exactly one baserestrictinfo entry.  This doesn't fire very
+	 * constant-FALSE-or-NULL restriction clauses.  Although const-folding will
+	 * reduce "anything AND FALSE" to just "FALSE", the baserestrictinfo list
+	 * might possibly have other members besides the FALSE constant, since
+	 * equivclass.c as well as add_baserestrictinfo_to_rel may generate
+	 * constant-FALSE baserestrictinfo entry on the fly.  In addition, other
+	 * quals could get "pushed down" to the baserel.  This doesn't fire very
 	 * often, but it seems cheap enough to be worth doing anyway.  (Without
 	 * this, we'd miss some optimizations that 9.5 and earlier found via much
 	 * more roundabout methods.)
 	 */
-	if (list_length(rel->baserestrictinfo) == 1)
+	foreach(lc, rel->baserestrictinfo)
 	{
-		RestrictInfo *rinfo = (RestrictInfo *) linitial(rel->baserestrictinfo);
+		RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
 		Expr	   *clause = rinfo->clause;
 
 		if (clause && IsA(clause, Const) &&
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 5d83f60eb9..6bb0df6535 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -221,6 +221,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->relid = relid;
 	rel->rtekind = rte->rtekind;
 	/* min_attr, max_attr, attr_needed, attr_widths are set below */
+	rel->notnullattnums = NULL;
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
@@ -705,6 +706,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 5702fbba60..d4f6bbcd2c 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset  *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index 31c188176b..60f2597cbe 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -75,6 +75,10 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern bool restriction_is_always_true(PlannerInfo *root,
+									   RestrictInfo *restrictinfo);
+extern bool restriction_is_always_false(PlannerInfo *root,
+										RestrictInfo *restrictinfo);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out
index 9b8638f286..b95d30f658 100644
--- a/src/test/regress/expected/join.out
+++ b/src/test/regress/expected/join.out
@@ -5788,13 +5788,11 @@ explain (costs off)
 select p.* from
   parent p left join child c on (p.k = c.k)
   where p.k = 1 and p.k = 2;
-                   QUERY PLAN                   
-------------------------------------------------
+        QUERY PLAN        
+--------------------------
  Result
    One-Time Filter: false
-   ->  Index Scan using parent_pkey on parent p
-         Index Cond: (k = 1)
-(4 rows)
+(2 rows)
 
 select p.* from
   (parent p left join child c on (p.k = c.k)) join parent x on p.k = x.k
diff --git a/src/test/regress/expected/predicate.out b/src/test/regress/expected/predicate.out
new file mode 100644
index 0000000000..47c8c1d2bd
--- /dev/null
+++ b/src/test/regress/expected/predicate.out
@@ -0,0 +1,204 @@
+--
+-- Tests for predicate handling
+--
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int, c int not null);
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+        QUERY PLAN         
+---------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NOT NULL)
+(2 rows)
+
+-- An IS_NULL qual in restriction clauses can be reduced to constant-FALSE if
+-- it's on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.a is null;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- On the contrary, an IS_NULL qual in restriction clauses can not be reduced
+-- to constant-FALSE if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is null;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NULL)
+(2 rows)
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NOT NULL) OR (a = 1))
+(2 rows)
+
+explain (costs off)
+select * from pred_tab t where t.a is null or t.c is null;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+explain (costs off)
+select * from pred_tab t where t.b is null or t.c is null;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NULL) OR (c IS NULL))
+(2 rows)
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NOT NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- An IS_NULL qual in join clauses can be reduced to constant-FALSE if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null and t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+-- Otherwise the IS_NULL qual in join clauses cannot be reduced to constant-FALSE
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NULL)
+   ->  Nested Loop Left Join
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(8 rows)
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NOT NULL) OR (t2.b = 1))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on (t2.a is null or t2.c is null) and t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null or t2.c is null;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NULL) OR (t2.c IS NULL))
+   ->  Nested Loop Left Join
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(8 rows)
+
+drop table pred_tab;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 4df9d8503b..3816efc7b3 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr
 # The stats test resets stats, so nothing else needing stats access can be in
 # this group.
 # ----------
-test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
 
 # event_trigger depends on create_am and cannot run concurrently with
 # any test that runs DDL
diff --git a/src/test/regress/sql/predicate.sql b/src/test/regress/sql/predicate.sql
new file mode 100644
index 0000000000..9d4336861f
--- /dev/null
+++ b/src/test/regress/sql/predicate.sql
@@ -0,0 +1,80 @@
+--
+-- Tests for predicate handling
+--
+
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int, c int not null);
+
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+
+-- An IS_NULL qual in restriction clauses can be reduced to constant-FALSE if
+-- it's on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.a is null;
+
+-- On the contrary, an IS_NULL qual in restriction clauses can not be reduced
+-- to constant-FALSE if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is null;
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+
+explain (costs off)
+select * from pred_tab t where t.a is null or t.c is null;
+
+explain (costs off)
+select * from pred_tab t where t.b is null or t.c is null;
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+
+-- An IS_NULL qual in join clauses can be reduced to constant-FALSE if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null and t2.b = 1;
+
+-- Otherwise the IS_NULL qual in join clauses cannot be reduced to constant-FALSE
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null;
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on (t2.a is null or t2.c is null) and t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null or t2.c is null;
+
+drop table pred_tab;
-- 
2.31.0

#23Andrei Lepikhov
a.lepikhov@postgrespro.ru
In reply to: Richard Guo (#22)
1 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On 8/10/2023 15:26, Richard Guo wrote:
Hi,

On Thu, Sep 28, 2023 at 11:51 AM David Rowley <dgrowleyml@gmail.com
<mailto:dgrowleyml@gmail.com>> wrote:

On Thu, 28 Sept 2023 at 16:22, Richard Guo <guofenglinux@gmail.com
<mailto:guofenglinux@gmail.com>> wrote:

It seems that optimizing IS NULL quals is more complex than

optimizing

IS NOT NULL quals.  I also wonder if it's worth the trouble to

optimize

IS NULL quals.

I'm happy to reduce the scope of this patch. As for what to cut, I
think if we're doing a subset then we should try to do that subset in
a way that best leaves things open for phase 2 at some later date.

I had a go at supporting IS NULL quals and ended up with the attached.
The patch generates a new constant-FALSE RestrictInfo that is marked
with the same required_relids etc as the original one if it is an IS
NULL qual that can be reduced to FALSE.  Note that the original
rinfo_serial is also copied to the new RestrictInfo.

One thing that is not great is that we may have 'FALSE and otherquals'
in the final plan, as shown by the plan below which is from the new
added test case.

Setting aside the thread's subject, I am interested in this feature
because of its connection with the SJE feature and the same issue raised
[1]: Removing unneeded self joins /messages/by-id/CAPpHfdt-0kVV7O==aJEbjY2iGYBu+XBzTHEbPv_6sVNeC7fffQ@mail.gmail.com
In the attachment - rebased version of your patch (because of the
5d8aa8bced).
Although the patch is already in a good state, some improvements can be
made. Look:
explain (costs off)
SELECT oid,relname FROM pg_class
WHERE oid < 5 OR (oid = 1 AND oid IS NULL);

Bitmap Heap Scan on pg_class
Recheck Cond: ((oid < '5'::oid) OR ((oid = '1'::oid) AND (oid IS NULL)))
-> BitmapOr
-> Bitmap Index Scan on pg_class_oid_index
Index Cond: (oid < '5'::oid)
-> Bitmap Index Scan on pg_class_oid_index
Index Cond: ((oid = '1'::oid) AND (oid IS NULL))

If we go deeply through the filter, I guess we could replace such buried
clauses.

[1]: Removing unneeded self joins /messages/by-id/CAPpHfdt-0kVV7O==aJEbjY2iGYBu+XBzTHEbPv_6sVNeC7fffQ@mail.gmail.com
/messages/by-id/CAPpHfdt-0kVV7O==aJEbjY2iGYBu+XBzTHEbPv_6sVNeC7fffQ@mail.gmail.com

--
regards,
Andrei Lepikhov
Postgres Professional

Attachments:

v6-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchtext/plain; charset=UTF-8; name=v6-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchDownload
From 0a08ccbf376c1003c45ba8a555a39ae9c2f9c207 Mon Sep 17 00:00:00 2001
From: Richard Guo <guofenglinux@gmail.com>
Date: Sat, 7 Oct 2023 17:04:07 +0800
Subject: [PATCH] Reduce NullTest quals to constant TRUE or FALSE

---
 .../postgres_fdw/expected/postgres_fdw.out    |  16 +-
 contrib/postgres_fdw/sql/postgres_fdw.sql     |   4 +-
 src/backend/optimizer/plan/initsplan.c        | 243 ++++++++++++++----
 src/backend/optimizer/util/joininfo.c         |  25 ++
 src/backend/optimizer/util/plancat.c          |   9 +
 src/backend/optimizer/util/relnode.c          |   2 +
 src/include/nodes/pathnodes.h                 |   2 +
 src/include/optimizer/planmain.h              |   4 +
 src/test/regress/expected/predicate.out       | 204 +++++++++++++++
 src/test/regress/parallel_schedule            |   2 +-
 src/test/regress/sql/predicate.sql            |  80 ++++++
 11 files changed, 533 insertions(+), 58 deletions(-)
 create mode 100644 src/test/regress/expected/predicate.out
 create mode 100644 src/test/regress/sql/predicate.sql

diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 144c114d0f..4d7c5b9140 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -656,20 +656,20 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 =
    Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-                                           QUERY PLAN                                            
--------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+                                          QUERY PLAN                                          
+----------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NULL))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
-                                             QUERY PLAN                                              
------------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
+                                            QUERY PLAN                                            
+--------------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NOT NULL))
 (3 rows)
 
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index a303bfb322..8542a9e9de 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -332,8 +332,8 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
 -- ===================================================================
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1;         -- Var, OpExpr(b), Const
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1;          -- OpExpr(l)
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index b31d892121..06e73f4169 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,174 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_baserestrictinfo_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted
+ *		by 'relid' with some prechecks to try to determine if the qual is
+ *		always true, in which case we ignore it rather than add it, or if the
+ *		qual is always false, in which case we replace it with constant-FALSE.
+ */
+static void
+add_baserestrictinfo_to_rel(PlannerInfo *root, Index relid,
+							RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Substitute constant-FALSE for the origin qual if it is always false */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int		save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 false,	/* pseudoconstant */
+										 0,	/* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * expr_is_nonnullable
+ *	  Check to see if the Expr cannot be NULL
+ *
+ * If the Expr is a simple Var that is defined NOT NULL and meanwhile is not
+ * nulled by any outer joins, then we can know that it cannot be NULL.
+ */
+static bool
+expr_is_nonnullable(PlannerInfo *root, Expr *expr)
+{
+	RelOptInfo *rel;
+	Var		   *var;
+
+	/* For now only check simple Vars */
+	if (!IsA(expr, Var))
+		return false;
+
+	var = (Var *) expr;
+
+	/* could the Var be nulled by any outer joins? */
+	if (!bms_is_empty(var->varnullingrels))
+		return false;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		return true;
+
+	/* is the column defined NOT NULL? */
+	rel = find_base_rel(root, var->varno);
+	if (var->varattno > 0 &&
+		bms_is_member(var->varattno, rel->notnullattnums))
+		return true;
+
+	return false;
+}
+
+/*
+ * restriction_is_always_true
+ *	  Check to see if the RestrictInfo is always true.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_true(PlannerInfo *root,
+						   RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NOT_NULL qual? */
+		if (nulltest->nulltesttype != IS_NOT_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo))
+				continue;
+
+			if (restriction_is_always_true(root, (RestrictInfo *) orarg))
+				return true;
+		}
+	}
+
+	return false;
+}
+
+/*
+ * restriction_is_always_false
+ *	  Check to see if the RestrictInfo is always false.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_false(PlannerInfo *root,
+							RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NULL qual? */
+		if (nulltest->nulltesttype != IS_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo) ||
+				!restriction_is_always_false(root, (RestrictInfo *) orarg))
+				return false;
+		}
+		return true;
+	}
+
+	return false;
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,58 +2800,39 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
+	int			relid;
 
-	switch (bms_membership(relids))
+	if (relids == NULL)
 	{
-		case BMS_SINGLETON:
-
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, bms_singleton_member(relids));
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-			break;
-		case BMS_MULTIPLE:
-
-			/*
-			 * The clause is a join clause, since there is more than one rel
-			 * in its relid set.
-			 */
-
-			/*
-			 * Check for hashjoinable operators.  (We don't bother setting the
-			 * hashjoin info except in true join clauses.)
-			 */
-			check_hashjoinable(restrictinfo);
+		/*
+		 * clause references no rels, and therefore we have no place to
+		 * attach it.  Shouldn't get here if callers are working properly.
+		 */
+		elog(ERROR, "cannot cope with variable-free clause");
+	}
+	else if (bms_get_singleton_member(relids, &relid))
+		add_baserestrictinfo_to_rel(root, relid, restrictinfo);
+	else
+	{
+		/*
+		 * The clause is a join clause, since there is more than one rel in
+		 * its relid set.
+		 */
 
-			/*
-			 * Likewise, check if the clause is suitable to be used with a
-			 * Memoize node to cache inner tuples during a parameterized
-			 * nested loop.
-			 */
-			check_memoizable(restrictinfo);
+		/*
+		 * Check for hashjoinable operators.  (We don't bother setting the
+		 * hashjoin info except in true join clauses.)
+		 */
+		check_hashjoinable(restrictinfo);
 
-			/*
-			 * Add clause to the join lists of all the relevant relations.
-			 */
-			add_join_clause_to_rels(root, restrictinfo, relids);
-			break;
-		default:
+		/*
+		 * Likewise, check if the clause is suitable to be used with a Memoize
+		 * node to cache inner tuples during a parameterized nested loop.
+		 */
+		check_memoizable(restrictinfo);
 
-			/*
-			 * clause references no rels, and therefore we have no place to
-			 * attach it.  Shouldn't get here if callers are working properly.
-			 */
-			elog(ERROR, "cannot cope with variable-free clause");
-			break;
+		/* Add clause to the join lists of all the relevant relations. */
+		add_join_clause_to_rels(root, restrictinfo, relids);
 	}
 }
 
diff --git a/src/backend/optimizer/util/joininfo.c b/src/backend/optimizer/util/joininfo.c
index 968a5a488e..b0b960a001 100644
--- a/src/backend/optimizer/util/joininfo.c
+++ b/src/backend/optimizer/util/joininfo.c
@@ -14,9 +14,12 @@
  */
 #include "postgres.h"
 
+#include "nodes/makefuncs.h"
 #include "optimizer/joininfo.h"
 #include "optimizer/pathnode.h"
 #include "optimizer/paths.h"
+#include "optimizer/planmain.h"
+#include "optimizer/restrictinfo.h"
 
 
 /*
@@ -98,6 +101,28 @@ add_join_clause_to_rels(PlannerInfo *root,
 {
 	int			cur_relid;
 
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Substitute constant-FALSE for the origin qual if it is always false */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int		save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 false,	/* pseudoconstant */
+										 0,	/* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
 	cur_relid = -1;
 	while ((cur_relid = bms_next_member(join_relids, cur_relid)) >= 0)
 	{
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 7159c775fb..0024b27edc 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,15 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+			rel->notnullattnums = bms_add_member(rel->notnullattnums, attr->attnum);
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 5d83f60eb9..6bb0df6535 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -221,6 +221,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->relid = relid;
 	rel->rtekind = rte->rtekind;
 	/* min_attr, max_attr, attr_needed, attr_widths are set below */
+	rel->notnullattnums = NULL;
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
@@ -705,6 +706,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 5702fbba60..d4f6bbcd2c 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset  *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index 31c188176b..60f2597cbe 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -75,6 +75,10 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern bool restriction_is_always_true(PlannerInfo *root,
+									   RestrictInfo *restrictinfo);
+extern bool restriction_is_always_false(PlannerInfo *root,
+										RestrictInfo *restrictinfo);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
diff --git a/src/test/regress/expected/predicate.out b/src/test/regress/expected/predicate.out
new file mode 100644
index 0000000000..47c8c1d2bd
--- /dev/null
+++ b/src/test/regress/expected/predicate.out
@@ -0,0 +1,204 @@
+--
+-- Tests for predicate handling
+--
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int, c int not null);
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+        QUERY PLAN         
+---------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NOT NULL)
+(2 rows)
+
+-- An IS_NULL qual in restriction clauses can be reduced to constant-FALSE if
+-- it's on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.a is null;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- On the contrary, an IS_NULL qual in restriction clauses can not be reduced
+-- to constant-FALSE if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is null;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NULL)
+(2 rows)
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NOT NULL) OR (a = 1))
+(2 rows)
+
+explain (costs off)
+select * from pred_tab t where t.a is null or t.c is null;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+explain (costs off)
+select * from pred_tab t where t.b is null or t.c is null;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NULL) OR (c IS NULL))
+(2 rows)
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NOT NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- An IS_NULL qual in join clauses can be reduced to constant-FALSE if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null and t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+-- Otherwise the IS_NULL qual in join clauses cannot be reduced to constant-FALSE
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NULL)
+   ->  Nested Loop Left Join
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(8 rows)
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NOT NULL) OR (t2.b = 1))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on (t2.a is null or t2.c is null) and t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null or t2.c is null;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NULL) OR (t2.c IS NULL))
+   ->  Nested Loop Left Join
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(8 rows)
+
+drop table pred_tab;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 4df9d8503b..3816efc7b3 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr
 # The stats test resets stats, so nothing else needing stats access can be in
 # this group.
 # ----------
-test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
 
 # event_trigger depends on create_am and cannot run concurrently with
 # any test that runs DDL
diff --git a/src/test/regress/sql/predicate.sql b/src/test/regress/sql/predicate.sql
new file mode 100644
index 0000000000..9d4336861f
--- /dev/null
+++ b/src/test/regress/sql/predicate.sql
@@ -0,0 +1,80 @@
+--
+-- Tests for predicate handling
+--
+
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int, c int not null);
+
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+
+-- An IS_NULL qual in restriction clauses can be reduced to constant-FALSE if
+-- it's on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.a is null;
+
+-- On the contrary, an IS_NULL qual in restriction clauses can not be reduced
+-- to constant-FALSE if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is null;
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+
+explain (costs off)
+select * from pred_tab t where t.a is null or t.c is null;
+
+explain (costs off)
+select * from pred_tab t where t.b is null or t.c is null;
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+
+-- An IS_NULL qual in join clauses can be reduced to constant-FALSE if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null and t2.b = 1;
+
+-- Otherwise the IS_NULL qual in join clauses cannot be reduced to constant-FALSE
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null;
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on (t2.a is null or t2.c is null) and t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null or t2.c is null;
+
+drop table pred_tab;
-- 
2.42.0

#24Richard Guo
guofenglinux@gmail.com
In reply to: Andrei Lepikhov (#23)
1 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Tue, Oct 24, 2023 at 12:25 PM Andrei Lepikhov <a.lepikhov@postgrespro.ru>
wrote:

Setting aside the thread's subject, I am interested in this feature
because of its connection with the SJE feature and the same issue raised
[1] during the discussion.

Thanks for taking an interest in this.

I rebased this patch over the SJE commit, and found that it can help
discard redundant IS_NOT_NULL quals added by SJE logic if we've
successfully removed some self-joins on primary keys, as shown by the
regression test plan changes, which IMO makes this patch look more
useful in practice.

Although the patch is already in a good state, some improvements can be
made. Look:
explain (costs off)
SELECT oid,relname FROM pg_class
WHERE oid < 5 OR (oid = 1 AND oid IS NULL);

Bitmap Heap Scan on pg_class
Recheck Cond: ((oid < '5'::oid) OR ((oid = '1'::oid) AND (oid IS
NULL)))
-> BitmapOr
-> Bitmap Index Scan on pg_class_oid_index
Index Cond: (oid < '5'::oid)
-> Bitmap Index Scan on pg_class_oid_index
Index Cond: ((oid = '1'::oid) AND (oid IS NULL))

If we go deeply through the filter, I guess we could replace such buried
clauses.

Yeah, we can do that by exploring harder on OR clauses. But for now I
think it's more important for this patch to introduce the
'reduce-quals-to-constant' mechanism. As a start I think it'd be better
to keep the logic simple for review. In the future maybe we can extend
it to consider more than just NullTest quals, for example we could also
consider applicable constraint expressions of the given relation.

Thanks
Richard

Attachments:

v7-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchapplication/octet-stream; name=v7-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchDownload
From 4550dd83d800b66a6882ab6aed74a907dcda1fdc Mon Sep 17 00:00:00 2001
From: Richard Guo <guofenglinux@gmail.com>
Date: Wed, 1 Nov 2023 08:45:30 +0800
Subject: [PATCH v7] Reduce NullTest quals to constant TRUE or FALSE

---
 .../postgres_fdw/expected/postgres_fdw.out    |  16 +-
 contrib/postgres_fdw/sql/postgres_fdw.sql     |   4 +-
 src/backend/optimizer/plan/initsplan.c        | 243 ++++++++++++++----
 src/backend/optimizer/util/joininfo.c         |  25 ++
 src/backend/optimizer/util/plancat.c          |   9 +
 src/backend/optimizer/util/relnode.c          |   2 +
 src/include/nodes/pathnodes.h                 |   2 +
 src/include/optimizer/planmain.h              |   4 +
 src/test/regress/expected/equivclass.out      |  18 +-
 src/test/regress/expected/join.out            |  38 +--
 src/test/regress/expected/predicate.out       | 204 +++++++++++++++
 src/test/regress/parallel_schedule            |   2 +-
 src/test/regress/sql/predicate.sql            |  80 ++++++
 13 files changed, 560 insertions(+), 87 deletions(-)
 create mode 100644 src/test/regress/expected/predicate.out
 create mode 100644 src/test/regress/sql/predicate.sql

diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 144c114d0f..4d7c5b9140 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -656,20 +656,20 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 =
    Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-                                           QUERY PLAN                                            
--------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+                                          QUERY PLAN                                          
+----------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NULL))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
-                                             QUERY PLAN                                              
------------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
+                                            QUERY PLAN                                            
+--------------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NOT NULL))
 (3 rows)
 
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index a303bfb322..8542a9e9de 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -332,8 +332,8 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
 -- ===================================================================
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1;         -- Var, OpExpr(b), Const
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1;          -- OpExpr(l)
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index b31d892121..ccb27a06f6 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,174 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_baserestrictinfo_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted
+ *		by 'relid' with some prechecks to try to determine if the qual is
+ *		always true, in which case we ignore it rather than add it, or if the
+ *		qual is always false, in which case we replace it with constant-FALSE.
+ */
+static void
+add_baserestrictinfo_to_rel(PlannerInfo *root, Index relid,
+							RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Substitute constant-FALSE for the origin qual if it is always false */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int		save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 0,	/* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * expr_is_nonnullable
+ *	  Check to see if the Expr cannot be NULL
+ *
+ * If the Expr is a simple Var that is defined NOT NULL and meanwhile is not
+ * nulled by any outer joins, then we can know that it cannot be NULL.
+ */
+static bool
+expr_is_nonnullable(PlannerInfo *root, Expr *expr)
+{
+	RelOptInfo *rel;
+	Var		   *var;
+
+	/* For now only check simple Vars */
+	if (!IsA(expr, Var))
+		return false;
+
+	var = (Var *) expr;
+
+	/* could the Var be nulled by any outer joins? */
+	if (!bms_is_empty(var->varnullingrels))
+		return false;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		return true;
+
+	/* is the column defined NOT NULL? */
+	rel = find_base_rel(root, var->varno);
+	if (var->varattno > 0 &&
+		bms_is_member(var->varattno, rel->notnullattnums))
+		return true;
+
+	return false;
+}
+
+/*
+ * restriction_is_always_true
+ *	  Check to see if the RestrictInfo is always true.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_true(PlannerInfo *root,
+						   RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NOT_NULL qual? */
+		if (nulltest->nulltesttype != IS_NOT_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo))
+				continue;
+
+			if (restriction_is_always_true(root, (RestrictInfo *) orarg))
+				return true;
+		}
+	}
+
+	return false;
+}
+
+/*
+ * restriction_is_always_false
+ *	  Check to see if the RestrictInfo is always false.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_false(PlannerInfo *root,
+							RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NULL qual? */
+		if (nulltest->nulltesttype != IS_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo) ||
+				!restriction_is_always_false(root, (RestrictInfo *) orarg))
+				return false;
+		}
+		return true;
+	}
+
+	return false;
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,58 +2800,39 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
+	int			relid;
 
-	switch (bms_membership(relids))
+	if (relids == NULL)
 	{
-		case BMS_SINGLETON:
-
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, bms_singleton_member(relids));
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-			break;
-		case BMS_MULTIPLE:
-
-			/*
-			 * The clause is a join clause, since there is more than one rel
-			 * in its relid set.
-			 */
-
-			/*
-			 * Check for hashjoinable operators.  (We don't bother setting the
-			 * hashjoin info except in true join clauses.)
-			 */
-			check_hashjoinable(restrictinfo);
+		/*
+		 * clause references no rels, and therefore we have no place to
+		 * attach it.  Shouldn't get here if callers are working properly.
+		 */
+		elog(ERROR, "cannot cope with variable-free clause");
+	}
+	else if (bms_get_singleton_member(relids, &relid))
+		add_baserestrictinfo_to_rel(root, relid, restrictinfo);
+	else
+	{
+		/*
+		 * The clause is a join clause, since there is more than one rel in
+		 * its relid set.
+		 */
 
-			/*
-			 * Likewise, check if the clause is suitable to be used with a
-			 * Memoize node to cache inner tuples during a parameterized
-			 * nested loop.
-			 */
-			check_memoizable(restrictinfo);
+		/*
+		 * Check for hashjoinable operators.  (We don't bother setting the
+		 * hashjoin info except in true join clauses.)
+		 */
+		check_hashjoinable(restrictinfo);
 
-			/*
-			 * Add clause to the join lists of all the relevant relations.
-			 */
-			add_join_clause_to_rels(root, restrictinfo, relids);
-			break;
-		default:
+		/*
+		 * Likewise, check if the clause is suitable to be used with a Memoize
+		 * node to cache inner tuples during a parameterized nested loop.
+		 */
+		check_memoizable(restrictinfo);
 
-			/*
-			 * clause references no rels, and therefore we have no place to
-			 * attach it.  Shouldn't get here if callers are working properly.
-			 */
-			elog(ERROR, "cannot cope with variable-free clause");
-			break;
+		/* Add clause to the join lists of all the relevant relations. */
+		add_join_clause_to_rels(root, restrictinfo, relids);
 	}
 }
 
diff --git a/src/backend/optimizer/util/joininfo.c b/src/backend/optimizer/util/joininfo.c
index 968a5a488e..2645490c43 100644
--- a/src/backend/optimizer/util/joininfo.c
+++ b/src/backend/optimizer/util/joininfo.c
@@ -14,9 +14,12 @@
  */
 #include "postgres.h"
 
+#include "nodes/makefuncs.h"
 #include "optimizer/joininfo.h"
 #include "optimizer/pathnode.h"
 #include "optimizer/paths.h"
+#include "optimizer/planmain.h"
+#include "optimizer/restrictinfo.h"
 
 
 /*
@@ -98,6 +101,28 @@ add_join_clause_to_rels(PlannerInfo *root,
 {
 	int			cur_relid;
 
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Substitute constant-FALSE for the origin qual if it is always false */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int		save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 0,	/* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
 	cur_relid = -1;
 	while ((cur_relid = bms_next_member(join_relids, cur_relid)) >= 0)
 	{
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 7159c775fb..0024b27edc 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,15 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+			rel->notnullattnums = bms_add_member(rel->notnullattnums, attr->attnum);
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 5d83f60eb9..6bb0df6535 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -221,6 +221,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->relid = relid;
 	rel->rtekind = rte->rtekind;
 	/* min_attr, max_attr, attr_needed, attr_widths are set below */
+	rel->notnullattnums = NULL;
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
@@ -705,6 +706,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index ed85dc7414..0d5ff34fb2 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset  *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index 2bc857745a..a4edd2f61d 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -76,6 +76,10 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern bool restriction_is_always_true(PlannerInfo *root,
+									   RestrictInfo *restrictinfo);
+extern bool restriction_is_always_false(PlannerInfo *root,
+										RestrictInfo *restrictinfo);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
diff --git a/src/test/regress/expected/equivclass.out b/src/test/regress/expected/equivclass.out
index de71441052..3d5de28354 100644
--- a/src/test/regress/expected/equivclass.out
+++ b/src/test/regress/expected/equivclass.out
@@ -438,15 +438,14 @@ set enable_mergejoin to off;
 explain (costs off)
   select * from ec0 m join ec0 n on m.ff = n.ff
   join ec1 p on m.ff + n.ff = p.f1;
-               QUERY PLAN               
-----------------------------------------
+              QUERY PLAN               
+---------------------------------------
  Nested Loop
    Join Filter: ((n.ff + n.ff) = p.f1)
-   ->  Seq Scan on ec1 p
+   ->  Seq Scan on ec0 n
    ->  Materialize
-         ->  Seq Scan on ec0 n
-               Filter: (ff IS NOT NULL)
-(6 rows)
+         ->  Seq Scan on ec1 p
+(5 rows)
 
 explain (costs off)
   select * from ec0 m join ec0 n on m.ff = n.ff
@@ -455,11 +454,10 @@ explain (costs off)
 ---------------------------------------------------------------
  Nested Loop
    Join Filter: ((p.f1)::bigint = ((n.ff + n.ff))::int8alias1)
-   ->  Seq Scan on ec1 p
+   ->  Seq Scan on ec0 n
    ->  Materialize
-         ->  Seq Scan on ec0 n
-               Filter: (ff IS NOT NULL)
-(6 rows)
+         ->  Seq Scan on ec1 p
+(5 rows)
 
 reset enable_mergejoin;
 -- this could be converted, but isn't at present
diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out
index 446959e3c5..c1499edb62 100644
--- a/src/test/regress/expected/join.out
+++ b/src/test/regress/expected/join.out
@@ -6331,14 +6331,14 @@ SELECT * FROM pg_am am WHERE am.amname IN (
     JOIN pg_class c2
     ON c1.oid=c2.oid AND c1.oid < 10
 );
-                             QUERY PLAN                              
----------------------------------------------------------------------
+                           QUERY PLAN                           
+----------------------------------------------------------------
  Nested Loop Semi Join
    Join Filter: (am.amname = c2.relname)
    ->  Seq Scan on pg_am am
    ->  Materialize
          ->  Index Scan using pg_class_oid_index on pg_class c2
-               Index Cond: ((oid < '10'::oid) AND (oid IS NOT NULL))
+               Index Cond: (oid < '10'::oid)
 (6 rows)
 
 --
@@ -6593,14 +6593,14 @@ SELECT COUNT(*) FROM tab_with_flag
 WHERE
 	(is_flag IS NULL OR is_flag = 0)
 	AND id IN (SELECT id FROM tab_with_flag WHERE id IN (2, 3));
-                                    QUERY PLAN                                    
-----------------------------------------------------------------------------------
+                        QUERY PLAN                         
+-----------------------------------------------------------
  Aggregate
    ->  Bitmap Heap Scan on tab_with_flag
-         Recheck Cond: ((id = ANY ('{2,3}'::integer[])) AND (id IS NOT NULL))
+         Recheck Cond: (id = ANY ('{2,3}'::integer[]))
          Filter: ((is_flag IS NULL) OR (is_flag = 0))
          ->  Bitmap Index Scan on tab_with_flag_pkey
-               Index Cond: ((id = ANY ('{2,3}'::integer[])) AND (id IS NOT NULL))
+               Index Cond: (id = ANY ('{2,3}'::integer[]))
 (6 rows)
 
 DROP TABLE tab_with_flag;
@@ -6719,11 +6719,11 @@ reset enable_seqscan;
 CREATE TABLE emp1 ( id SERIAL PRIMARY KEY NOT NULL, code int);
 explain (verbose, costs off)
 SELECT * FROM emp1 e1, emp1 e2 WHERE e1.id = e2.id AND e2.code <> e1.code;
-                        QUERY PLAN                        
-----------------------------------------------------------
+                QUERY PLAN                
+------------------------------------------
  Seq Scan on public.emp1 e2
    Output: e2.id, e2.code, e2.id, e2.code
-   Filter: ((e2.id IS NOT NULL) AND (e2.code <> e2.code))
+   Filter: (e2.code <> e2.code)
 (3 rows)
 
 -- Shuffle self-joined relations. Only in the case of iterative deletion
@@ -6732,31 +6732,31 @@ CREATE UNIQUE INDEX ON emp1((id*id));
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c1.id=c2.id AND c1.id*c2.id=c3.id*c3.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c1.id=c3.id AND c1.id*c3.id=c2.id*c2.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c3.id=c2.id AND c3.id*c2.id=c1.id*c1.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 -- We can remove the join even if we find the join can't duplicate rows and
diff --git a/src/test/regress/expected/predicate.out b/src/test/regress/expected/predicate.out
new file mode 100644
index 0000000000..47c8c1d2bd
--- /dev/null
+++ b/src/test/regress/expected/predicate.out
@@ -0,0 +1,204 @@
+--
+-- Tests for predicate handling
+--
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int, c int not null);
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+        QUERY PLAN         
+---------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NOT NULL)
+(2 rows)
+
+-- An IS_NULL qual in restriction clauses can be reduced to constant-FALSE if
+-- it's on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.a is null;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- On the contrary, an IS_NULL qual in restriction clauses can not be reduced
+-- to constant-FALSE if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is null;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NULL)
+(2 rows)
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NOT NULL) OR (a = 1))
+(2 rows)
+
+explain (costs off)
+select * from pred_tab t where t.a is null or t.c is null;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+explain (costs off)
+select * from pred_tab t where t.b is null or t.c is null;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NULL) OR (c IS NULL))
+(2 rows)
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NOT NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- An IS_NULL qual in join clauses can be reduced to constant-FALSE if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null and t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+-- Otherwise the IS_NULL qual in join clauses cannot be reduced to constant-FALSE
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NULL)
+   ->  Nested Loop Left Join
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(8 rows)
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NOT NULL) OR (t2.b = 1))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on (t2.a is null or t2.c is null) and t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null or t2.c is null;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NULL) OR (t2.c IS NULL))
+   ->  Nested Loop Left Join
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(8 rows)
+
+drop table pred_tab;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index f0987ff537..6f5a33c234 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr
 # The stats test resets stats, so nothing else needing stats access can be in
 # this group.
 # ----------
-test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
 
 # event_trigger depends on create_am and cannot run concurrently with
 # any test that runs DDL
diff --git a/src/test/regress/sql/predicate.sql b/src/test/regress/sql/predicate.sql
new file mode 100644
index 0000000000..9d4336861f
--- /dev/null
+++ b/src/test/regress/sql/predicate.sql
@@ -0,0 +1,80 @@
+--
+-- Tests for predicate handling
+--
+
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int, c int not null);
+
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+
+-- An IS_NULL qual in restriction clauses can be reduced to constant-FALSE if
+-- it's on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.a is null;
+
+-- On the contrary, an IS_NULL qual in restriction clauses can not be reduced
+-- to constant-FALSE if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is null;
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+
+explain (costs off)
+select * from pred_tab t where t.a is null or t.c is null;
+
+explain (costs off)
+select * from pred_tab t where t.b is null or t.c is null;
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+
+-- An IS_NULL qual in join clauses can be reduced to constant-FALSE if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null and t2.b = 1;
+
+-- Otherwise the IS_NULL qual in join clauses cannot be reduced to constant-FALSE
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null;
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on (t2.a is null or t2.c is null) and t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null or t2.c is null;
+
+drop table pred_tab;
-- 
2.31.0

#25David Rowley
dgrowleyml@gmail.com
In reply to: Richard Guo (#24)
1 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Wed, 1 Nov 2023 at 15:21, Richard Guo <guofenglinux@gmail.com> wrote:

I rebased this patch over the SJE commit

I rebased your v7 patch on top of 930d2b442 and updated the expected
results of some new regression tests which now have their NullTest
clauses removed.

I also renamed add_baserestrictinfo_to_rel() to
add_base_clause_to_rel() so that it's more aligned to
add_join_clause_to_rels().

On looking deeper, I see you're overwriting the rinfo_serial of the
const-false RestrictInfo with the one from the original RestrictInfo.
If that's the correct thing to do then the following comment would
need to be updated to mention this exception of why the rinfo_serial
isn't unique.

/*----------
* Serial number of this RestrictInfo. This is unique within the current
* PlannerInfo context, with a few critical exceptions:
* 1. When we generate multiple clones of the same qual condition to
* cope with outer join identity 3, all the clones get the same serial
* number. This reflects that we only want to apply one of them in any
* given plan.
* 2. If we manufacture a commuted version of a qual to use as an index
* condition, it copies the original's rinfo_serial, since it is in
* practice the same condition.
* 3. RestrictInfos made for a child relation copy their parent's
* rinfo_serial. Likewise, when an EquivalenceClass makes a derived
* equality clause for a child relation, it copies the rinfo_serial of
* the matching equality clause for the parent. This allows detection
* of redundant pushed-down equality clauses.
*----------
*/

Looking at the tests, I see:

select * from pred_tab t1 left join pred_tab t2 on true left join
pred_tab t3 on t2.a is null;

I'm wondering if you can come up with a better test for this? I don't
quite see any reason why varnullingrels can't be empty for t2.a in the
join qual as the "ON true" join condition between t1 and t2 means that
there shouldn't ever be any NULL t2.a rows. My thoughts are that if
we improve how varnullingrels are set in the future then this test
will be broken.

Also, I also like to write exactly what each test is testing so that
it's easier in the future to maintain the expected results. It's
often tricky when making planner changes to know if some planner
changes makes a test completely useless or if the expected results
just need to be updated. If someone changes varnullingrels to be
empty for this case, then if they accept the actual results as
expected results then the test becomes useless. I tend to do this
with comments in the .sql file along the lines of "-- Ensure ..."

I also would rather see the SQLs in the test wrap their lines before
each join and the keywords to be upper case.

David

Attachments:

v8-0001-Ignore-redundant-NOT-NULL-clauses.patchtext/plain; charset=US-ASCII; name=v8-0001-Ignore-redundant-NOT-NULL-clauses.patchDownload
From c8cdd4dac33ce4800dfc094d8985866f891563f8 Mon Sep 17 00:00:00 2001
From: David Rowley <dgrowley@gmail.com>
Date: Tue, 28 Nov 2023 16:48:08 +1300
Subject: [PATCH v8] Ignore redundant NOT NULL clauses

---
 .../postgres_fdw/expected/postgres_fdw.out    |  16 +-
 contrib/postgres_fdw/sql/postgres_fdw.sql     |   4 +-
 src/backend/optimizer/plan/initsplan.c        | 184 ++++++++++++++--
 src/backend/optimizer/util/joininfo.c         |  25 +++
 src/backend/optimizer/util/plancat.c          |   9 +
 src/backend/optimizer/util/relnode.c          |   3 +
 src/include/nodes/pathnodes.h                 |   2 +
 src/include/optimizer/planmain.h              |   4 +
 src/test/regress/expected/equivclass.out      |  18 +-
 src/test/regress/expected/join.out            |  52 +++--
 src/test/regress/expected/predicate.out       | 204 ++++++++++++++++++
 src/test/regress/parallel_schedule            |   2 +-
 src/test/regress/sql/predicate.sql            |  80 +++++++
 13 files changed, 540 insertions(+), 63 deletions(-)
 create mode 100644 src/test/regress/expected/predicate.out
 create mode 100644 src/test/regress/sql/predicate.sql

diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 22cae37a1e..a0dd41894a 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -656,20 +656,20 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 =
    Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-                                           QUERY PLAN                                            
--------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+                                          QUERY PLAN                                          
+----------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NULL))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
-                                             QUERY PLAN                                              
------------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
+                                            QUERY PLAN                                            
+--------------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NOT NULL))
 (3 rows)
 
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 075da4ff86..3a78552f19 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -332,8 +332,8 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
 -- ===================================================================
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1;         -- Var, OpExpr(b), Const
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1;          -- OpExpr(l)
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index 8295e7753d..57f1323049 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,174 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_base_clause_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted
+ *		by 'relid' with some prechecks to try to determine if the qual is
+ *		always true, in which case we ignore it rather than add it, or if the
+ *		qual is always false, in which case we replace it with constant-FALSE.
+ */
+static void
+add_base_clause_to_rel(PlannerInfo *root, Index relid,
+					   RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Substitute constant-FALSE for the origin qual if it is always false */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int			save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 0, /* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * expr_is_nonnullable
+ *	  Check to see if the Expr cannot be NULL
+ *
+ * If the Expr is a simple Var that is defined NOT NULL and meanwhile is not
+ * nulled by any outer joins, then we can know that it cannot be NULL.
+ */
+static bool
+expr_is_nonnullable(PlannerInfo *root, Expr *expr)
+{
+	RelOptInfo *rel;
+	Var		   *var;
+
+	/* For now only check simple Vars */
+	if (!IsA(expr, Var))
+		return false;
+
+	var = (Var *) expr;
+
+	/* could the Var be nulled by any outer joins? */
+	if (!bms_is_empty(var->varnullingrels))
+		return false;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		return true;
+
+	/* is the column defined NOT NULL? */
+	rel = find_base_rel(root, var->varno);
+	if (var->varattno > 0 &&
+		bms_is_member(var->varattno, rel->notnullattnums))
+		return true;
+
+	return false;
+}
+
+/*
+ * restriction_is_always_true
+ *	  Check to see if the RestrictInfo is always true.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_true(PlannerInfo *root,
+						   RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest   *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NOT_NULL qual? */
+		if (nulltest->nulltesttype != IS_NOT_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node	   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo))
+				continue;
+
+			if (restriction_is_always_true(root, (RestrictInfo *) orarg))
+				return true;
+		}
+	}
+
+	return false;
+}
+
+/*
+ * restriction_is_always_false
+ *	  Check to see if the RestrictInfo is always false.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_false(PlannerInfo *root,
+							RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest   *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NULL qual? */
+		if (nulltest->nulltesttype != IS_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node	   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo) ||
+				!restriction_is_always_false(root, (RestrictInfo *) orarg))
+				return false;
+		}
+		return true;
+	}
+
+	return false;
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,27 +2800,13 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
 
 	if (!bms_is_empty(relids))
 	{
 		int			relid;
 
 		if (bms_get_singleton_member(relids, &relid))
-		{
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, relid);
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-		}
+			add_base_clause_to_rel(root, relid, restrictinfo);
 		else
 		{
 			/*
diff --git a/src/backend/optimizer/util/joininfo.c b/src/backend/optimizer/util/joininfo.c
index 968a5a488e..d79d6f8169 100644
--- a/src/backend/optimizer/util/joininfo.c
+++ b/src/backend/optimizer/util/joininfo.c
@@ -14,9 +14,12 @@
  */
 #include "postgres.h"
 
+#include "nodes/makefuncs.h"
 #include "optimizer/joininfo.h"
 #include "optimizer/pathnode.h"
 #include "optimizer/paths.h"
+#include "optimizer/planmain.h"
+#include "optimizer/restrictinfo.h"
 
 
 /*
@@ -98,6 +101,28 @@ add_join_clause_to_rels(PlannerInfo *root,
 {
 	int			cur_relid;
 
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/* Substitute constant-FALSE for the origin qual if it is always false */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int			save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 0, /* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
 	cur_relid = -1;
 	while ((cur_relid = bms_next_member(join_relids, cur_relid)) >= 0)
 	{
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 7159c775fb..0024b27edc 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,15 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+			rel->notnullattnums = bms_add_member(rel->notnullattnums, attr->attnum);
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 5d83f60eb9..4edccd6da6 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -221,6 +221,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->relid = relid;
 	rel->rtekind = rte->rtekind;
 	/* min_attr, max_attr, attr_needed, attr_widths are set below */
+	rel->notnullattnums = NULL;
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
@@ -705,6 +706,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
@@ -903,6 +905,7 @@ build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index ed85dc7414..0d5ff34fb2 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset  *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index 2bc857745a..a4edd2f61d 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -76,6 +76,10 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern bool restriction_is_always_true(PlannerInfo *root,
+									   RestrictInfo *restrictinfo);
+extern bool restriction_is_always_false(PlannerInfo *root,
+										RestrictInfo *restrictinfo);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
diff --git a/src/test/regress/expected/equivclass.out b/src/test/regress/expected/equivclass.out
index de71441052..3d5de28354 100644
--- a/src/test/regress/expected/equivclass.out
+++ b/src/test/regress/expected/equivclass.out
@@ -438,15 +438,14 @@ set enable_mergejoin to off;
 explain (costs off)
   select * from ec0 m join ec0 n on m.ff = n.ff
   join ec1 p on m.ff + n.ff = p.f1;
-               QUERY PLAN               
-----------------------------------------
+              QUERY PLAN               
+---------------------------------------
  Nested Loop
    Join Filter: ((n.ff + n.ff) = p.f1)
-   ->  Seq Scan on ec1 p
+   ->  Seq Scan on ec0 n
    ->  Materialize
-         ->  Seq Scan on ec0 n
-               Filter: (ff IS NOT NULL)
-(6 rows)
+         ->  Seq Scan on ec1 p
+(5 rows)
 
 explain (costs off)
   select * from ec0 m join ec0 n on m.ff = n.ff
@@ -455,11 +454,10 @@ explain (costs off)
 ---------------------------------------------------------------
  Nested Loop
    Join Filter: ((p.f1)::bigint = ((n.ff + n.ff))::int8alias1)
-   ->  Seq Scan on ec1 p
+   ->  Seq Scan on ec0 n
    ->  Materialize
-         ->  Seq Scan on ec0 n
-               Filter: (ff IS NOT NULL)
-(6 rows)
+         ->  Seq Scan on ec1 p
+(5 rows)
 
 reset enable_mergejoin;
 -- this could be converted, but isn't at present
diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out
index 2c73270143..24d3004095 100644
--- a/src/test/regress/expected/join.out
+++ b/src/test/regress/expected/join.out
@@ -6357,14 +6357,14 @@ SELECT * FROM pg_am am WHERE am.amname IN (
     JOIN pg_class c2
     ON c1.oid=c2.oid AND c1.oid < 10
 );
-                             QUERY PLAN                              
----------------------------------------------------------------------
+                           QUERY PLAN                           
+----------------------------------------------------------------
  Nested Loop Semi Join
    Join Filter: (am.amname = c2.relname)
    ->  Seq Scan on pg_am am
    ->  Materialize
          ->  Index Scan using pg_class_oid_index on pg_class c2
-               Index Cond: ((oid < '10'::oid) AND (oid IS NOT NULL))
+               Index Cond: (oid < '10'::oid)
 (6 rows)
 
 --
@@ -6619,14 +6619,14 @@ SELECT COUNT(*) FROM tab_with_flag
 WHERE
 	(is_flag IS NULL OR is_flag = 0)
 	AND id IN (SELECT id FROM tab_with_flag WHERE id IN (2, 3));
-                                    QUERY PLAN                                    
-----------------------------------------------------------------------------------
+                        QUERY PLAN                         
+-----------------------------------------------------------
  Aggregate
    ->  Bitmap Heap Scan on tab_with_flag
-         Recheck Cond: ((id = ANY ('{2,3}'::integer[])) AND (id IS NOT NULL))
+         Recheck Cond: (id = ANY ('{2,3}'::integer[]))
          Filter: ((is_flag IS NULL) OR (is_flag = 0))
          ->  Bitmap Index Scan on tab_with_flag_pkey
-               Index Cond: ((id = ANY ('{2,3}'::integer[])) AND (id IS NOT NULL))
+               Index Cond: (id = ANY ('{2,3}'::integer[]))
 (6 rows)
 
 DROP TABLE tab_with_flag;
@@ -6745,11 +6745,11 @@ reset enable_seqscan;
 CREATE TABLE emp1 ( id SERIAL PRIMARY KEY NOT NULL, code int);
 explain (verbose, costs off)
 SELECT * FROM emp1 e1, emp1 e2 WHERE e1.id = e2.id AND e2.code <> e1.code;
-                        QUERY PLAN                        
-----------------------------------------------------------
+                QUERY PLAN                
+------------------------------------------
  Seq Scan on public.emp1 e2
    Output: e2.id, e2.code, e2.id, e2.code
-   Filter: ((e2.id IS NOT NULL) AND (e2.code <> e2.code))
+   Filter: (e2.code <> e2.code)
 (3 rows)
 
 -- Shuffle self-joined relations. Only in the case of iterative deletion
@@ -6758,31 +6758,31 @@ CREATE UNIQUE INDEX ON emp1((id*id));
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c1.id=c2.id AND c1.id*c2.id=c3.id*c3.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c1.id=c3.id AND c1.id*c3.id=c2.id*c2.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c3.id=c2.id AND c3.id*c2.id=c1.id*c1.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 -- Check the usage of a parse tree by the set operations (bug #18170)
@@ -6791,16 +6791,15 @@ SELECT c1.code FROM emp1 c1 LEFT JOIN emp1 c2 ON c1.id = c2.id
 WHERE c2.id IS NOT NULL
 EXCEPT ALL
 SELECT c3.code FROM emp1 c3;
-                  QUERY PLAN                  
-----------------------------------------------
+                QUERY PLAN                 
+-------------------------------------------
  HashSetOp Except All
    ->  Append
          ->  Subquery Scan on "*SELECT* 1"
                ->  Seq Scan on emp1 c2
-                     Filter: (id IS NOT NULL)
          ->  Subquery Scan on "*SELECT* 2"
                ->  Seq Scan on emp1 c3
-(7 rows)
+(6 rows)
 
 -- Check that SJE removes references from PHVs correctly
 explain (costs off)
@@ -6809,8 +6808,8 @@ select * from emp1 t1 left join
         left join (emp1 t3 join emp1 t4 on t3.id = t4.id)
         on true)
 on true;
-                     QUERY PLAN                     
-----------------------------------------------------
+                 QUERY PLAN                  
+---------------------------------------------
  Nested Loop Left Join
    ->  Seq Scan on emp1 t1
    ->  Materialize
@@ -6818,8 +6817,7 @@ on true;
                ->  Seq Scan on emp1 t2
                ->  Materialize
                      ->  Seq Scan on emp1 t4
-                           Filter: (id IS NOT NULL)
-(8 rows)
+(7 rows)
 
 -- Check that SJE does not remove self joins if a PHV references the removed
 -- rel laterally.
diff --git a/src/test/regress/expected/predicate.out b/src/test/regress/expected/predicate.out
new file mode 100644
index 0000000000..47c8c1d2bd
--- /dev/null
+++ b/src/test/regress/expected/predicate.out
@@ -0,0 +1,204 @@
+--
+-- Tests for predicate handling
+--
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int, c int not null);
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+        QUERY PLAN         
+---------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NOT NULL)
+(2 rows)
+
+-- An IS_NULL qual in restriction clauses can be reduced to constant-FALSE if
+-- it's on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.a is null;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- On the contrary, an IS_NULL qual in restriction clauses can not be reduced
+-- to constant-FALSE if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is null;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NULL)
+(2 rows)
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NOT NULL) OR (a = 1))
+(2 rows)
+
+explain (costs off)
+select * from pred_tab t where t.a is null or t.c is null;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+explain (costs off)
+select * from pred_tab t where t.b is null or t.c is null;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NULL) OR (c IS NULL))
+(2 rows)
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NOT NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- An IS_NULL qual in join clauses can be reduced to constant-FALSE if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null and t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+-- Otherwise the IS_NULL qual in join clauses cannot be reduced to constant-FALSE
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NULL)
+   ->  Nested Loop Left Join
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(8 rows)
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NOT NULL) OR (t2.b = 1))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on (t2.a is null or t2.c is null) and t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null or t2.c is null;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NULL) OR (t2.c IS NULL))
+   ->  Nested Loop Left Join
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(8 rows)
+
+drop table pred_tab;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index f0987ff537..6f5a33c234 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr
 # The stats test resets stats, so nothing else needing stats access can be in
 # this group.
 # ----------
-test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
 
 # event_trigger depends on create_am and cannot run concurrently with
 # any test that runs DDL
diff --git a/src/test/regress/sql/predicate.sql b/src/test/regress/sql/predicate.sql
new file mode 100644
index 0000000000..9d4336861f
--- /dev/null
+++ b/src/test/regress/sql/predicate.sql
@@ -0,0 +1,80 @@
+--
+-- Tests for predicate handling
+--
+
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+create table pred_tab (a int not null, b int, c int not null);
+
+-- An IS_NOT_NULL qual in restriction clauses can be ignored if it's on a NOT
+-- NULL column
+explain (costs off)
+select * from pred_tab t where t.a is not null;
+
+-- On the contrary, an IS_NOT_NULL qual in restriction clauses can not be
+-- ignored if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is not null;
+
+-- An IS_NULL qual in restriction clauses can be reduced to constant-FALSE if
+-- it's on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.a is null;
+
+-- On the contrary, an IS_NULL qual in restriction clauses can not be reduced
+-- to constant-FALSE if it's not on a NOT NULL column
+explain (costs off)
+select * from pred_tab t where t.b is null;
+
+-- Tests for OR clauses in restriction clauses
+explain (costs off)
+select * from pred_tab t where t.a is not null or t.b = 1;
+
+explain (costs off)
+select * from pred_tab t where t.b is not null or t.a = 1;
+
+explain (costs off)
+select * from pred_tab t where t.a is null or t.c is null;
+
+explain (costs off)
+select * from pred_tab t where t.b is null or t.c is null;
+
+-- An IS_NOT_NULL qual in join clauses can be ignored if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null;
+
+-- Otherwise the IS_NOT_NULL qual in join clauses cannot be ignored
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null;
+
+-- An IS_NULL qual in join clauses can be reduced to constant-FALSE if
+-- a) it's on a NOT NULL column, and
+-- b) its Var is not nulled by any outer joins
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null and t2.b = 1;
+
+-- Otherwise the IS_NULL qual in join clauses cannot be reduced to constant-FALSE
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null;
+
+-- Tests for OR clauses in join clauses
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on t1.a = 1 left join pred_tab t3 on t2.a is not null or t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on (t2.a is null or t2.c is null) and t2.b = 1;
+
+explain (costs off)
+select * from pred_tab t1 left join pred_tab t2 on true left join pred_tab t3 on t2.a is null or t2.c is null;
+
+drop table pred_tab;
-- 
2.40.1.windows.1

#26Richard Guo
guofenglinux@gmail.com
In reply to: David Rowley (#25)
1 attachment(s)
Re: BUG #17540: Prepared statement: PG switches to a generic query plan which is consistently much slower

On Wed, Nov 29, 2023 at 8:48 AM David Rowley <dgrowleyml@gmail.com> wrote:

I rebased your v7 patch on top of 930d2b442 and updated the expected
results of some new regression tests which now have their NullTest
clauses removed.

Thanks for your rebase.

On looking deeper, I see you're overwriting the rinfo_serial of the
const-false RestrictInfo with the one from the original RestrictInfo.
If that's the correct thing to do then the following comment would
need to be updated to mention this exception of why the rinfo_serial
isn't unique.

Right, that's what we need to do.

Looking at the tests, I see:

select * from pred_tab t1 left join pred_tab t2 on true left join
pred_tab t3 on t2.a is null;

I'm wondering if you can come up with a better test for this? I don't
quite see any reason why varnullingrels can't be empty for t2.a in the
join qual as the "ON true" join condition between t1 and t2 means that
there shouldn't ever be any NULL t2.a rows. My thoughts are that if
we improve how varnullingrels are set in the future then this test
will be broken.

Also, I also like to write exactly what each test is testing so that
it's easier in the future to maintain the expected results. It's
often tricky when making planner changes to know if some planner
changes makes a test completely useless or if the expected results
just need to be updated. If someone changes varnullingrels to be
empty for this case, then if they accept the actual results as
expected results then the test becomes useless. I tend to do this
with comments in the .sql file along the lines of "-- Ensure ..."

I also would rather see the SQLs in the test wrap their lines before
each join and the keywords to be upper case.

Thanks for the suggestions on the tests. I had a go at improving the
test queries and their comments.

BTW, I changed the subject of this patch to 'Reduce NullTest quals to
constant TRUE or FALSE', which seems more accurate to me, because this
patch also reduces IS NULL clauses to constant-FALSE when applicable, in
addition to ignoring redundant NOT NULL clauses.

Thanks
Richard

Attachments:

v9-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchapplication/octet-stream; name=v9-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchDownload
From ab6bf6b49afb75addbdabdf61b0f5cb8c05fc0e8 Mon Sep 17 00:00:00 2001
From: Richard Guo <guofenglinux@gmail.com>
Date: Fri, 1 Dec 2023 14:02:31 +0800
Subject: [PATCH v9] Reduce NullTest quals to constant TRUE or FALSE

---
 .../postgres_fdw/expected/postgres_fdw.out    |  16 +-
 contrib/postgres_fdw/sql/postgres_fdw.sql     |   4 +-
 src/backend/optimizer/plan/initsplan.c        | 187 ++++++++++++--
 src/backend/optimizer/util/joininfo.c         |  28 +++
 src/backend/optimizer/util/plancat.c          |   9 +
 src/backend/optimizer/util/relnode.c          |   3 +
 src/include/nodes/pathnodes.h                 |   7 +-
 src/include/optimizer/planmain.h              |   4 +
 src/test/regress/expected/equivclass.out      |  18 +-
 src/test/regress/expected/join.out            |  52 ++--
 src/test/regress/expected/predicate.out       | 235 ++++++++++++++++++
 src/test/regress/parallel_schedule            |   2 +-
 src/test/regress/sql/predicate.sql            | 113 +++++++++
 13 files changed, 614 insertions(+), 64 deletions(-)
 create mode 100644 src/test/regress/expected/predicate.out
 create mode 100644 src/test/regress/sql/predicate.sql

diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 0a5bdf8bcc..900db5510d 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -656,20 +656,20 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 =
    Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-                                           QUERY PLAN                                            
--------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+                                          QUERY PLAN                                          
+----------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NULL))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
-                                             QUERY PLAN                                              
------------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
+                                            QUERY PLAN                                            
+--------------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NOT NULL))
 (3 rows)
 
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 075da4ff86..3a78552f19 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -332,8 +332,8 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
 -- ===================================================================
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1;         -- Var, OpExpr(b), Const
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1;          -- OpExpr(l)
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index 8295e7753d..bdc1415719 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,177 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_base_clause_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted
+ *		by 'relid' with some prechecks to try to determine if the qual is
+ *		always true, in which case we ignore it rather than add it, or if the
+ *		qual is always false, in which case we replace it with constant-FALSE.
+ */
+static void
+add_base_clause_to_rel(PlannerInfo *root, Index relid,
+					   RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/*
+	 * Substitute constant-FALSE for the origin qual if it is always false.
+	 * Note that we keep the same rinfo_serial.
+	 */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int			save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 0, /* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * expr_is_nonnullable
+ *	  Check to see if the Expr cannot be NULL
+ *
+ * If the Expr is a simple Var that is defined NOT NULL and meanwhile is not
+ * nulled by any outer joins, then we can know that it cannot be NULL.
+ */
+static bool
+expr_is_nonnullable(PlannerInfo *root, Expr *expr)
+{
+	RelOptInfo *rel;
+	Var		   *var;
+
+	/* For now only check simple Vars */
+	if (!IsA(expr, Var))
+		return false;
+
+	var = (Var *) expr;
+
+	/* could the Var be nulled by any outer joins? */
+	if (!bms_is_empty(var->varnullingrels))
+		return false;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		return true;
+
+	/* is the column defined NOT NULL? */
+	rel = find_base_rel(root, var->varno);
+	if (var->varattno > 0 &&
+		bms_is_member(var->varattno, rel->notnullattnums))
+		return true;
+
+	return false;
+}
+
+/*
+ * restriction_is_always_true
+ *	  Check to see if the RestrictInfo is always true.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_true(PlannerInfo *root,
+						   RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest   *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NOT_NULL qual? */
+		if (nulltest->nulltesttype != IS_NOT_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node	   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo))
+				continue;
+
+			if (restriction_is_always_true(root, (RestrictInfo *) orarg))
+				return true;
+		}
+	}
+
+	return false;
+}
+
+/*
+ * restriction_is_always_false
+ *	  Check to see if the RestrictInfo is always false.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_false(PlannerInfo *root,
+							RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest   *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NULL qual? */
+		if (nulltest->nulltesttype != IS_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node	   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo) ||
+				!restriction_is_always_false(root, (RestrictInfo *) orarg))
+				return false;
+		}
+		return true;
+	}
+
+	return false;
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,27 +2803,13 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
 
 	if (!bms_is_empty(relids))
 	{
 		int			relid;
 
 		if (bms_get_singleton_member(relids, &relid))
-		{
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, relid);
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-		}
+			add_base_clause_to_rel(root, relid, restrictinfo);
 		else
 		{
 			/*
diff --git a/src/backend/optimizer/util/joininfo.c b/src/backend/optimizer/util/joininfo.c
index 968a5a488e..926f77b5e1 100644
--- a/src/backend/optimizer/util/joininfo.c
+++ b/src/backend/optimizer/util/joininfo.c
@@ -14,9 +14,12 @@
  */
 #include "postgres.h"
 
+#include "nodes/makefuncs.h"
 #include "optimizer/joininfo.h"
 #include "optimizer/pathnode.h"
 #include "optimizer/paths.h"
+#include "optimizer/planmain.h"
+#include "optimizer/restrictinfo.h"
 
 
 /*
@@ -98,6 +101,31 @@ add_join_clause_to_rels(PlannerInfo *root,
 {
 	int			cur_relid;
 
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/*
+	 * Substitute constant-FALSE for the origin qual if it is always false.
+	 * Note that we keep the same rinfo_serial.
+	 */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int			save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 0, /* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
 	cur_relid = -1;
 	while ((cur_relid = bms_next_member(join_relids, cur_relid)) >= 0)
 	{
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 7159c775fb..0024b27edc 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,15 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+			rel->notnullattnums = bms_add_member(rel->notnullattnums, attr->attnum);
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 5d83f60eb9..4edccd6da6 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -221,6 +221,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->relid = relid;
 	rel->rtekind = rte->rtekind;
 	/* min_attr, max_attr, attr_needed, attr_widths are set below */
+	rel->notnullattnums = NULL;
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
@@ -705,6 +706,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
@@ -903,6 +905,7 @@ build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index ed85dc7414..2c1623d520 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset  *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
@@ -2588,7 +2590,10 @@ typedef struct RestrictInfo
 	 * 2. If we manufacture a commuted version of a qual to use as an index
 	 * condition, it copies the original's rinfo_serial, since it is in
 	 * practice the same condition.
-	 * 3. RestrictInfos made for a child relation copy their parent's
+	 * 3. If we reduce a qual to constant-FALSE, the new constant-FALSE qual
+	 * copies the original's rinfo_serial, since it is in practice the same
+	 * condition.
+	 * 4. RestrictInfos made for a child relation copy their parent's
 	 * rinfo_serial.  Likewise, when an EquivalenceClass makes a derived
 	 * equality clause for a child relation, it copies the rinfo_serial of
 	 * the matching equality clause for the parent.  This allows detection
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index 2bc857745a..a4edd2f61d 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -76,6 +76,10 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern bool restriction_is_always_true(PlannerInfo *root,
+									   RestrictInfo *restrictinfo);
+extern bool restriction_is_always_false(PlannerInfo *root,
+										RestrictInfo *restrictinfo);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
diff --git a/src/test/regress/expected/equivclass.out b/src/test/regress/expected/equivclass.out
index de71441052..3d5de28354 100644
--- a/src/test/regress/expected/equivclass.out
+++ b/src/test/regress/expected/equivclass.out
@@ -438,15 +438,14 @@ set enable_mergejoin to off;
 explain (costs off)
   select * from ec0 m join ec0 n on m.ff = n.ff
   join ec1 p on m.ff + n.ff = p.f1;
-               QUERY PLAN               
-----------------------------------------
+              QUERY PLAN               
+---------------------------------------
  Nested Loop
    Join Filter: ((n.ff + n.ff) = p.f1)
-   ->  Seq Scan on ec1 p
+   ->  Seq Scan on ec0 n
    ->  Materialize
-         ->  Seq Scan on ec0 n
-               Filter: (ff IS NOT NULL)
-(6 rows)
+         ->  Seq Scan on ec1 p
+(5 rows)
 
 explain (costs off)
   select * from ec0 m join ec0 n on m.ff = n.ff
@@ -455,11 +454,10 @@ explain (costs off)
 ---------------------------------------------------------------
  Nested Loop
    Join Filter: ((p.f1)::bigint = ((n.ff + n.ff))::int8alias1)
-   ->  Seq Scan on ec1 p
+   ->  Seq Scan on ec0 n
    ->  Materialize
-         ->  Seq Scan on ec0 n
-               Filter: (ff IS NOT NULL)
-(6 rows)
+         ->  Seq Scan on ec1 p
+(5 rows)
 
 reset enable_mergejoin;
 -- this could be converted, but isn't at present
diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out
index 2c73270143..24d3004095 100644
--- a/src/test/regress/expected/join.out
+++ b/src/test/regress/expected/join.out
@@ -6357,14 +6357,14 @@ SELECT * FROM pg_am am WHERE am.amname IN (
     JOIN pg_class c2
     ON c1.oid=c2.oid AND c1.oid < 10
 );
-                             QUERY PLAN                              
----------------------------------------------------------------------
+                           QUERY PLAN                           
+----------------------------------------------------------------
  Nested Loop Semi Join
    Join Filter: (am.amname = c2.relname)
    ->  Seq Scan on pg_am am
    ->  Materialize
          ->  Index Scan using pg_class_oid_index on pg_class c2
-               Index Cond: ((oid < '10'::oid) AND (oid IS NOT NULL))
+               Index Cond: (oid < '10'::oid)
 (6 rows)
 
 --
@@ -6619,14 +6619,14 @@ SELECT COUNT(*) FROM tab_with_flag
 WHERE
 	(is_flag IS NULL OR is_flag = 0)
 	AND id IN (SELECT id FROM tab_with_flag WHERE id IN (2, 3));
-                                    QUERY PLAN                                    
-----------------------------------------------------------------------------------
+                        QUERY PLAN                         
+-----------------------------------------------------------
  Aggregate
    ->  Bitmap Heap Scan on tab_with_flag
-         Recheck Cond: ((id = ANY ('{2,3}'::integer[])) AND (id IS NOT NULL))
+         Recheck Cond: (id = ANY ('{2,3}'::integer[]))
          Filter: ((is_flag IS NULL) OR (is_flag = 0))
          ->  Bitmap Index Scan on tab_with_flag_pkey
-               Index Cond: ((id = ANY ('{2,3}'::integer[])) AND (id IS NOT NULL))
+               Index Cond: (id = ANY ('{2,3}'::integer[]))
 (6 rows)
 
 DROP TABLE tab_with_flag;
@@ -6745,11 +6745,11 @@ reset enable_seqscan;
 CREATE TABLE emp1 ( id SERIAL PRIMARY KEY NOT NULL, code int);
 explain (verbose, costs off)
 SELECT * FROM emp1 e1, emp1 e2 WHERE e1.id = e2.id AND e2.code <> e1.code;
-                        QUERY PLAN                        
-----------------------------------------------------------
+                QUERY PLAN                
+------------------------------------------
  Seq Scan on public.emp1 e2
    Output: e2.id, e2.code, e2.id, e2.code
-   Filter: ((e2.id IS NOT NULL) AND (e2.code <> e2.code))
+   Filter: (e2.code <> e2.code)
 (3 rows)
 
 -- Shuffle self-joined relations. Only in the case of iterative deletion
@@ -6758,31 +6758,31 @@ CREATE UNIQUE INDEX ON emp1((id*id));
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c1.id=c2.id AND c1.id*c2.id=c3.id*c3.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c1.id=c3.id AND c1.id*c3.id=c2.id*c2.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c3.id=c2.id AND c3.id*c2.id=c1.id*c1.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 -- Check the usage of a parse tree by the set operations (bug #18170)
@@ -6791,16 +6791,15 @@ SELECT c1.code FROM emp1 c1 LEFT JOIN emp1 c2 ON c1.id = c2.id
 WHERE c2.id IS NOT NULL
 EXCEPT ALL
 SELECT c3.code FROM emp1 c3;
-                  QUERY PLAN                  
-----------------------------------------------
+                QUERY PLAN                 
+-------------------------------------------
  HashSetOp Except All
    ->  Append
          ->  Subquery Scan on "*SELECT* 1"
                ->  Seq Scan on emp1 c2
-                     Filter: (id IS NOT NULL)
          ->  Subquery Scan on "*SELECT* 2"
                ->  Seq Scan on emp1 c3
-(7 rows)
+(6 rows)
 
 -- Check that SJE removes references from PHVs correctly
 explain (costs off)
@@ -6809,8 +6808,8 @@ select * from emp1 t1 left join
         left join (emp1 t3 join emp1 t4 on t3.id = t4.id)
         on true)
 on true;
-                     QUERY PLAN                     
-----------------------------------------------------
+                 QUERY PLAN                  
+---------------------------------------------
  Nested Loop Left Join
    ->  Seq Scan on emp1 t1
    ->  Materialize
@@ -6818,8 +6817,7 @@ on true;
                ->  Seq Scan on emp1 t2
                ->  Materialize
                      ->  Seq Scan on emp1 t4
-                           Filter: (id IS NOT NULL)
-(8 rows)
+(7 rows)
 
 -- Check that SJE does not remove self joins if a PHV references the removed
 -- rel laterally.
diff --git a/src/test/regress/expected/predicate.out b/src/test/regress/expected/predicate.out
new file mode 100644
index 0000000000..6e8c929fd9
--- /dev/null
+++ b/src/test/regress/expected/predicate.out
@@ -0,0 +1,235 @@
+--
+-- Tests for predicate handling
+--
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+CREATE TABLE pred_tab (a int NOT NULL, b int, c int NOT NULL);
+--
+-- Test restriction clauses
+--
+-- Ensure the IS_NOT_NULL qual is ignored, since it's on a NOT NULL column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- Ensure the IS_NOT_NULL qual is not ignored, since it's not on a NOT NULL
+-- column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL;
+        QUERY PLAN         
+---------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NOT NULL)
+(2 rows)
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE, since it's on a NOT
+-- NULL column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE, since it's not on
+-- a NOT NULL column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NULL)
+(2 rows)
+
+-- Tests for OR clauses in restriction clauses
+-- Ensure the OR clause is ignored
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL OR t.b = 1;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- Ensure the OR clause is not ignored
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL OR t.a = 1;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NOT NULL) OR (a = 1))
+(2 rows)
+
+-- Ensure the OR clause is reduced to constant-FALSE
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL OR t.c IS NULL;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- Ensure the OR clause is not reduced to constant-FALSE
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL OR t.c IS NULL;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NULL) OR (c IS NULL))
+(2 rows)
+
+--
+-- Test join clauses
+--
+-- Ensure the IS_NOT_NULL qual is ignored, since a) it's on a NOT NULL column,
+-- and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Ensure the IS_NOT_NULL qual is not ignored, since its Var is nullable by
+-- outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NOT NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE, since a) it's on a NOT
+-- NULL column, and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL AND t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE, since its Var is
+-- nullable by outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- Tests for OR clauses in join clauses
+-- Ensure the OR clause is ignored
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Ensure the OR clause is not ignored
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NOT NULL) OR (t2.b = 1))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- Ensure the OR clause is reduced to constant-FALSE
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON (t2.a IS NULL OR t2.c IS NULL) AND t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+-- Ensure the OR clause is not reduced to constant-FALSE
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL OR t2.c IS NULL;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NULL) OR (t2.c IS NULL))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+DROP TABLE pred_tab;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index f0987ff537..6f5a33c234 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr
 # The stats test resets stats, so nothing else needing stats access can be in
 # this group.
 # ----------
-test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
 
 # event_trigger depends on create_am and cannot run concurrently with
 # any test that runs DDL
diff --git a/src/test/regress/sql/predicate.sql b/src/test/regress/sql/predicate.sql
new file mode 100644
index 0000000000..b5f037d60b
--- /dev/null
+++ b/src/test/regress/sql/predicate.sql
@@ -0,0 +1,113 @@
+--
+-- Tests for predicate handling
+--
+
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+CREATE TABLE pred_tab (a int NOT NULL, b int, c int NOT NULL);
+
+--
+-- Test restriction clauses
+--
+
+-- Ensure the IS_NOT_NULL qual is ignored, since it's on a NOT NULL column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL;
+
+-- Ensure the IS_NOT_NULL qual is not ignored, since it's not on a NOT NULL
+-- column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL;
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE, since it's on a NOT
+-- NULL column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL;
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE, since it's not on
+-- a NOT NULL column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL;
+
+-- Tests for OR clauses in restriction clauses
+
+-- Ensure the OR clause is ignored
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL OR t.b = 1;
+
+-- Ensure the OR clause is not ignored
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL OR t.a = 1;
+
+-- Ensure the OR clause is reduced to constant-FALSE
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL OR t.c IS NULL;
+
+-- Ensure the OR clause is not reduced to constant-FALSE
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL OR t.c IS NULL;
+
+--
+-- Test join clauses
+--
+
+-- Ensure the IS_NOT_NULL qual is ignored, since a) it's on a NOT NULL column,
+-- and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+
+-- Ensure the IS_NOT_NULL qual is not ignored, since its Var is nullable by
+-- outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE, since a) it's on a NOT
+-- NULL column, and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL AND t2.b = 1;
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE, since its Var is
+-- nullable by outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL;
+
+-- Tests for OR clauses in join clauses
+
+-- Ensure the OR clause is ignored
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+
+-- Ensure the OR clause is not ignored
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+
+-- Ensure the OR clause is reduced to constant-FALSE
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON (t2.a IS NULL OR t2.c IS NULL) AND t2.b = 1;
+
+-- Ensure the OR clause is not reduced to constant-FALSE
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL OR t2.c IS NULL;
+
+DROP TABLE pred_tab;
-- 
2.31.0

#27David Rowley
dgrowleyml@gmail.com
In reply to: Richard Guo (#26)
1 attachment(s)
Removing const-false IS NULL quals and redundant IS NOT NULL quals

(Moving discussion from -bugs [1]/messages/by-id/flat/17540-7aa1855ad5ec18b4@postgresql.org to -hackers for more visibility.)

Background:
This started out as a performance fix for bug #17540 but has now
extended beyond that as fixing that only requires we don't add
redundant IS NOT NULL quals to Min/Max aggregate rewrites. The
attached gets rid of all IS NOT NULL quals on columns that are
provably not null and replaces any IS NULL quals on NOT NULL columns
with a const-false gating qual which could result in not having to
scan the relation at all.

explain (costs off) select * from pg_class where oid is null;
QUERY PLAN
--------------------------
Result
One-Time Filter: false

The need for this is slightly higher than it once was as the self-join
removal code must add IS NOT NULL quals when removing self-joins when
the join condition is strict.

explain select c1.* from pg_class c1 inner join pg_class c2 on c1.oid=c2.oid;
QUERY PLAN
----------------------------------------------------------------
Seq Scan on pg_class c2 (cost=0.00..18.15 rows=415 width=273)

master would contain an oid IS NOT NULL filter condition.

On Fri, 1 Dec 2023 at 23:07, Richard Guo <guofenglinux@gmail.com> wrote:

On Wed, Nov 29, 2023 at 8:48 AM David Rowley <dgrowleyml@gmail.com> wrote:

On looking deeper, I see you're overwriting the rinfo_serial of the
const-false RestrictInfo with the one from the original RestrictInfo.
If that's the correct thing to do then the following comment would
need to be updated to mention this exception of why the rinfo_serial
isn't unique.

Right, that's what we need to do.

Looking at the tests, I see:

select * from pred_tab t1 left join pred_tab t2 on true left join
pred_tab t3 on t2.a is null;

I'm wondering if you can come up with a better test for this? I don't
quite see any reason why varnullingrels can't be empty for t2.a in the
join qual as the "ON true" join condition between t1 and t2 means that
there shouldn't ever be any NULL t2.a rows. My thoughts are that if
we improve how varnullingrels are set in the future then this test
will be broken.

Also, I also like to write exactly what each test is testing so that
it's easier in the future to maintain the expected results. It's
often tricky when making planner changes to know if some planner
changes makes a test completely useless or if the expected results
just need to be updated. If someone changes varnullingrels to be
empty for this case, then if they accept the actual results as
expected results then the test becomes useless. I tend to do this
with comments in the .sql file along the lines of "-- Ensure ..."

I also would rather see the SQLs in the test wrap their lines before
each join and the keywords to be upper case.

Thanks for the suggestions on the tests. I had a go at improving the
test queries and their comments.

Thanks. I made a pass over this patch which resulted in just adding
and tweaking some comments.

The other thing that bothers me about this patch now is the lack of
simplification of OR clauses with a redundant condition. For example:

postgres=# explain (costs off) select * from pg_class where oid is
null or relname = 'non-existent';
QUERY PLAN
---------------------------------------------------------------------
Bitmap Heap Scan on pg_class
Recheck Cond: ((oid IS NULL) OR (relname = 'non-existant'::name))
-> BitmapOr
-> Bitmap Index Scan on pg_class_oid_index
Index Cond: (oid IS NULL)
-> Bitmap Index Scan on pg_class_relname_nsp_index
Index Cond: (relname = 'non-existant'::name)
(7 rows)

oid is null is const-false and if we simplified that to remove the
redundant OR branch and run it through the constant folding code, we'd
end up with just the relname = 'non-existent' and we'd end up with a
more simple plan as a result.

I don't think that's a blocker. I think the patch is ready to go even
without doing anything to improve that.

Happy to hear other people's thoughts on this patch. Otherwise, I
currently don't think the missed optimisation is a reason to block
what we've ended up with so far.

David

[1]: /messages/by-id/flat/17540-7aa1855ad5ec18b4@postgresql.org

Attachments:

v10-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchapplication/x-patch; name=v10-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchDownload
From e690e0f622f69e6896f16f1729ff1b531b65ef4e Mon Sep 17 00:00:00 2001
From: David Rowley <dgrowley@gmail.com>
Date: Thu, 7 Dec 2023 22:52:34 +1300
Subject: [PATCH v10] Reduce NullTest quals to constant TRUE or FALSE

---
 .../postgres_fdw/expected/postgres_fdw.out    |  16 +-
 contrib/postgres_fdw/sql/postgres_fdw.sql     |   4 +-
 src/backend/optimizer/plan/initsplan.c        | 202 +++++++++++++--
 src/backend/optimizer/util/joininfo.c         |  28 ++
 src/backend/optimizer/util/plancat.c          |  10 +
 src/backend/optimizer/util/relnode.c          |   3 +
 src/include/nodes/pathnodes.h                 |   7 +-
 src/include/optimizer/planmain.h              |   4 +
 src/test/regress/expected/equivclass.out      |  18 +-
 src/test/regress/expected/join.out            |  52 ++--
 src/test/regress/expected/predicate.out       | 244 ++++++++++++++++++
 src/test/regress/parallel_schedule            |   2 +-
 src/test/regress/sql/predicate.sql            | 122 +++++++++
 13 files changed, 648 insertions(+), 64 deletions(-)
 create mode 100644 src/test/regress/expected/predicate.out
 create mode 100644 src/test/regress/sql/predicate.sql

diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index c988745b92..bc231c15a2 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -656,20 +656,20 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 =
    Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-                                           QUERY PLAN                                            
--------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+                                          QUERY PLAN                                          
+----------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NULL))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
-                                             QUERY PLAN                                              
------------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
+                                            QUERY PLAN                                            
+--------------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NOT NULL))
 (3 rows)
 
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index cb40540702..731201f232 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -332,8 +332,8 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
 -- ===================================================================
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1;         -- Var, OpExpr(b), Const
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1;          -- OpExpr(l)
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index 8295e7753d..83bdc8b23a 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,192 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_base_clause_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted
+ *		by 'relid' with some prechecks to try to determine if the qual is
+ *		always true, in which case we ignore it rather than add it, or if the
+ *		qual is always false, in which case we replace it with constant-FALSE.
+ */
+static void
+add_base_clause_to_rel(PlannerInfo *root, Index relid,
+					   RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/*
+	 * Substitute the origin qual with constant-FALSE if it is provably always
+	 * false.  Note that we keep the same rinfo_serial.
+	 */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int			save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 0, /* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * expr_is_nonnullable
+ *	  Check to see if the Expr cannot be NULL
+ *
+ * If the Expr is a simple Var that is defined NOT NULL and meanwhile is not
+ * nulled by any outer joins, then we can know that it cannot be NULL.
+ */
+static bool
+expr_is_nonnullable(PlannerInfo *root, Expr *expr)
+{
+	RelOptInfo *rel;
+	Var		   *var;
+
+	/* For now only check simple Vars */
+	if (!IsA(expr, Var))
+		return false;
+
+	var = (Var *) expr;
+
+	/* could the Var be nulled by any outer joins? */
+	if (!bms_is_empty(var->varnullingrels))
+		return false;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		return true;
+
+	/* is the column defined NOT NULL? */
+	rel = find_base_rel(root, var->varno);
+	if (var->varattno > 0 &&
+		bms_is_member(var->varattno, rel->notnullattnums))
+		return true;
+
+	return false;
+}
+
+/*
+ * restriction_is_always_true
+ *	  Check to see if the RestrictInfo is always true.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_true(PlannerInfo *root,
+						   RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest   *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NOT_NULL qual? */
+		if (nulltest->nulltesttype != IS_NOT_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+
+		/*
+		 * if any of the given OR branches is provably always true then the
+		 * entire condition is true.
+		 */
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node	   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo))
+				continue;
+
+			if (restriction_is_always_true(root, (RestrictInfo *) orarg))
+				return true;
+		}
+	}
+
+	return false;
+}
+
+/*
+ * restriction_is_always_false
+ *	  Check to see if the RestrictInfo is always false.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_false(PlannerInfo *root,
+							RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest   *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NULL qual? */
+		if (nulltest->nulltesttype != IS_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+
+		/*
+		 * Currently, when processing OR expressions, we only return true when
+		 * all of the OR branches are always false.  This could perhaps be
+		 * expanded to remove OR branches that are provably false.  This may
+		 * be a useful thing to do as it could result in the OR being left
+		 * with a single arg.  That's useful as it would allow the OR
+		 * condition to be replaced with its single argument which may allow
+		 * use of an index for faster filtering on the remaining condition.
+		 */
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node	   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo) ||
+				!restriction_is_always_false(root, (RestrictInfo *) orarg))
+				return false;
+		}
+		return true;
+	}
+
+	return false;
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,27 +2818,13 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
 
 	if (!bms_is_empty(relids))
 	{
 		int			relid;
 
 		if (bms_get_singleton_member(relids, &relid))
-		{
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, relid);
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-		}
+			add_base_clause_to_rel(root, relid, restrictinfo);
 		else
 		{
 			/*
diff --git a/src/backend/optimizer/util/joininfo.c b/src/backend/optimizer/util/joininfo.c
index 968a5a488e..926f77b5e1 100644
--- a/src/backend/optimizer/util/joininfo.c
+++ b/src/backend/optimizer/util/joininfo.c
@@ -14,9 +14,12 @@
  */
 #include "postgres.h"
 
+#include "nodes/makefuncs.h"
 #include "optimizer/joininfo.h"
 #include "optimizer/pathnode.h"
 #include "optimizer/paths.h"
+#include "optimizer/planmain.h"
+#include "optimizer/restrictinfo.h"
 
 
 /*
@@ -98,6 +101,31 @@ add_join_clause_to_rels(PlannerInfo *root,
 {
 	int			cur_relid;
 
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/*
+	 * Substitute constant-FALSE for the origin qual if it is always false.
+	 * Note that we keep the same rinfo_serial.
+	 */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int			save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 0, /* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
 	cur_relid = -1;
 	while ((cur_relid = bms_next_member(join_relids, cur_relid)) >= 0)
 	{
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 7159c775fb..7b8da0fe31 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,16 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+			rel->notnullattnums = bms_add_member(rel->notnullattnums,
+												 attr->attnum);
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 5d83f60eb9..4edccd6da6 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -221,6 +221,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->relid = relid;
 	rel->rtekind = rte->rtekind;
 	/* min_attr, max_attr, attr_needed, attr_widths are set below */
+	rel->notnullattnums = NULL;
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
@@ -705,6 +706,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
@@ -903,6 +905,7 @@ build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index ed85dc7414..2c1623d520 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset  *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
@@ -2588,7 +2590,10 @@ typedef struct RestrictInfo
 	 * 2. If we manufacture a commuted version of a qual to use as an index
 	 * condition, it copies the original's rinfo_serial, since it is in
 	 * practice the same condition.
-	 * 3. RestrictInfos made for a child relation copy their parent's
+	 * 3. If we reduce a qual to constant-FALSE, the new constant-FALSE qual
+	 * copies the original's rinfo_serial, since it is in practice the same
+	 * condition.
+	 * 4. RestrictInfos made for a child relation copy their parent's
 	 * rinfo_serial.  Likewise, when an EquivalenceClass makes a derived
 	 * equality clause for a child relation, it copies the rinfo_serial of
 	 * the matching equality clause for the parent.  This allows detection
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index 2bc857745a..a4edd2f61d 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -76,6 +76,10 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern bool restriction_is_always_true(PlannerInfo *root,
+									   RestrictInfo *restrictinfo);
+extern bool restriction_is_always_false(PlannerInfo *root,
+										RestrictInfo *restrictinfo);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
diff --git a/src/test/regress/expected/equivclass.out b/src/test/regress/expected/equivclass.out
index de71441052..3d5de28354 100644
--- a/src/test/regress/expected/equivclass.out
+++ b/src/test/regress/expected/equivclass.out
@@ -438,15 +438,14 @@ set enable_mergejoin to off;
 explain (costs off)
   select * from ec0 m join ec0 n on m.ff = n.ff
   join ec1 p on m.ff + n.ff = p.f1;
-               QUERY PLAN               
-----------------------------------------
+              QUERY PLAN               
+---------------------------------------
  Nested Loop
    Join Filter: ((n.ff + n.ff) = p.f1)
-   ->  Seq Scan on ec1 p
+   ->  Seq Scan on ec0 n
    ->  Materialize
-         ->  Seq Scan on ec0 n
-               Filter: (ff IS NOT NULL)
-(6 rows)
+         ->  Seq Scan on ec1 p
+(5 rows)
 
 explain (costs off)
   select * from ec0 m join ec0 n on m.ff = n.ff
@@ -455,11 +454,10 @@ explain (costs off)
 ---------------------------------------------------------------
  Nested Loop
    Join Filter: ((p.f1)::bigint = ((n.ff + n.ff))::int8alias1)
-   ->  Seq Scan on ec1 p
+   ->  Seq Scan on ec0 n
    ->  Materialize
-         ->  Seq Scan on ec0 n
-               Filter: (ff IS NOT NULL)
-(6 rows)
+         ->  Seq Scan on ec1 p
+(5 rows)
 
 reset enable_mergejoin;
 -- this could be converted, but isn't at present
diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out
index 2c73270143..24d3004095 100644
--- a/src/test/regress/expected/join.out
+++ b/src/test/regress/expected/join.out
@@ -6357,14 +6357,14 @@ SELECT * FROM pg_am am WHERE am.amname IN (
     JOIN pg_class c2
     ON c1.oid=c2.oid AND c1.oid < 10
 );
-                             QUERY PLAN                              
----------------------------------------------------------------------
+                           QUERY PLAN                           
+----------------------------------------------------------------
  Nested Loop Semi Join
    Join Filter: (am.amname = c2.relname)
    ->  Seq Scan on pg_am am
    ->  Materialize
          ->  Index Scan using pg_class_oid_index on pg_class c2
-               Index Cond: ((oid < '10'::oid) AND (oid IS NOT NULL))
+               Index Cond: (oid < '10'::oid)
 (6 rows)
 
 --
@@ -6619,14 +6619,14 @@ SELECT COUNT(*) FROM tab_with_flag
 WHERE
 	(is_flag IS NULL OR is_flag = 0)
 	AND id IN (SELECT id FROM tab_with_flag WHERE id IN (2, 3));
-                                    QUERY PLAN                                    
-----------------------------------------------------------------------------------
+                        QUERY PLAN                         
+-----------------------------------------------------------
  Aggregate
    ->  Bitmap Heap Scan on tab_with_flag
-         Recheck Cond: ((id = ANY ('{2,3}'::integer[])) AND (id IS NOT NULL))
+         Recheck Cond: (id = ANY ('{2,3}'::integer[]))
          Filter: ((is_flag IS NULL) OR (is_flag = 0))
          ->  Bitmap Index Scan on tab_with_flag_pkey
-               Index Cond: ((id = ANY ('{2,3}'::integer[])) AND (id IS NOT NULL))
+               Index Cond: (id = ANY ('{2,3}'::integer[]))
 (6 rows)
 
 DROP TABLE tab_with_flag;
@@ -6745,11 +6745,11 @@ reset enable_seqscan;
 CREATE TABLE emp1 ( id SERIAL PRIMARY KEY NOT NULL, code int);
 explain (verbose, costs off)
 SELECT * FROM emp1 e1, emp1 e2 WHERE e1.id = e2.id AND e2.code <> e1.code;
-                        QUERY PLAN                        
-----------------------------------------------------------
+                QUERY PLAN                
+------------------------------------------
  Seq Scan on public.emp1 e2
    Output: e2.id, e2.code, e2.id, e2.code
-   Filter: ((e2.id IS NOT NULL) AND (e2.code <> e2.code))
+   Filter: (e2.code <> e2.code)
 (3 rows)
 
 -- Shuffle self-joined relations. Only in the case of iterative deletion
@@ -6758,31 +6758,31 @@ CREATE UNIQUE INDEX ON emp1((id*id));
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c1.id=c2.id AND c1.id*c2.id=c3.id*c3.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c1.id=c3.id AND c1.id*c3.id=c2.id*c2.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c3.id=c2.id AND c3.id*c2.id=c1.id*c1.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 -- Check the usage of a parse tree by the set operations (bug #18170)
@@ -6791,16 +6791,15 @@ SELECT c1.code FROM emp1 c1 LEFT JOIN emp1 c2 ON c1.id = c2.id
 WHERE c2.id IS NOT NULL
 EXCEPT ALL
 SELECT c3.code FROM emp1 c3;
-                  QUERY PLAN                  
-----------------------------------------------
+                QUERY PLAN                 
+-------------------------------------------
  HashSetOp Except All
    ->  Append
          ->  Subquery Scan on "*SELECT* 1"
                ->  Seq Scan on emp1 c2
-                     Filter: (id IS NOT NULL)
          ->  Subquery Scan on "*SELECT* 2"
                ->  Seq Scan on emp1 c3
-(7 rows)
+(6 rows)
 
 -- Check that SJE removes references from PHVs correctly
 explain (costs off)
@@ -6809,8 +6808,8 @@ select * from emp1 t1 left join
         left join (emp1 t3 join emp1 t4 on t3.id = t4.id)
         on true)
 on true;
-                     QUERY PLAN                     
-----------------------------------------------------
+                 QUERY PLAN                  
+---------------------------------------------
  Nested Loop Left Join
    ->  Seq Scan on emp1 t1
    ->  Materialize
@@ -6818,8 +6817,7 @@ on true;
                ->  Seq Scan on emp1 t2
                ->  Materialize
                      ->  Seq Scan on emp1 t4
-                           Filter: (id IS NOT NULL)
-(8 rows)
+(7 rows)
 
 -- Check that SJE does not remove self joins if a PHV references the removed
 -- rel laterally.
diff --git a/src/test/regress/expected/predicate.out b/src/test/regress/expected/predicate.out
new file mode 100644
index 0000000000..395ffb0fcd
--- /dev/null
+++ b/src/test/regress/expected/predicate.out
@@ -0,0 +1,244 @@
+--
+-- Tests for predicate handling
+--
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+CREATE TABLE pred_tab (a int NOT NULL, b int, c int NOT NULL);
+--
+-- Test restriction clauses
+--
+-- Ensure the IS_NOT_NULL qual is ignored when the column is non-nullable
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- Ensure the IS_NOT_NULL qual is not ignored on a nullable column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL;
+        QUERY PLAN         
+---------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NOT NULL)
+(2 rows)
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE for non-nullable
+-- columns
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE on nullable
+-- columns
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NULL)
+(2 rows)
+
+--
+-- Tests for OR clauses in restriction clauses
+--
+-- Ensure the OR clause is ignored when an OR branch is always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL OR t.b = 1;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- Ensure the OR clause is not ignored for NullTests that can't be proven
+-- always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL OR t.a = 1;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NOT NULL) OR (a = 1))
+(2 rows)
+
+-- Ensure the OR clause is reduced to constant-FALSE when all branches are
+-- provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL OR t.c IS NULL;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- Ensure the OR clause is not reduced to constant-FALSE when not all branches
+-- are provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL OR t.c IS NULL;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NULL) OR (c IS NULL))
+(2 rows)
+
+--
+-- Test join clauses
+--
+-- Ensure the IS_NOT_NULL qual is ignored, since a) it's on a NOT NULL column,
+-- and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Ensure the IS_NOT_NULL qual is not ignored when columns are made nullable
+-- by an outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NOT NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE, since a) it's on a NOT
+-- NULL column, and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL AND t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE when the column is
+-- nullable by an outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+--
+-- Tests for OR clauses in join clauses
+--
+-- Ensure the OR clause is ignored when an OR branch is provably always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Ensure the NullTest is not ignored when the column is nullable by an outer
+-- join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NOT NULL) OR (t2.b = 1))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- Ensure the OR clause is reduced to constant-FALSE when all OR branches are
+-- provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON (t2.a IS NULL OR t2.c IS NULL) AND t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+-- Ensure the OR clause is not reduced to constant-FALSE when a column is
+-- made nullable from an join join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL OR t2.c IS NULL;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NULL) OR (t2.c IS NULL))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+DROP TABLE pred_tab;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index f0987ff537..6f5a33c234 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr
 # The stats test resets stats, so nothing else needing stats access can be in
 # this group.
 # ----------
-test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
 
 # event_trigger depends on create_am and cannot run concurrently with
 # any test that runs DDL
diff --git a/src/test/regress/sql/predicate.sql b/src/test/regress/sql/predicate.sql
new file mode 100644
index 0000000000..338daf3255
--- /dev/null
+++ b/src/test/regress/sql/predicate.sql
@@ -0,0 +1,122 @@
+--
+-- Tests for predicate handling
+--
+
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+CREATE TABLE pred_tab (a int NOT NULL, b int, c int NOT NULL);
+
+--
+-- Test restriction clauses
+--
+
+-- Ensure the IS_NOT_NULL qual is ignored when the column is non-nullable
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL;
+
+-- Ensure the IS_NOT_NULL qual is not ignored on a nullable column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL;
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE for non-nullable
+-- columns
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL;
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE on nullable
+-- columns
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL;
+
+--
+-- Tests for OR clauses in restriction clauses
+--
+
+-- Ensure the OR clause is ignored when an OR branch is always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL OR t.b = 1;
+
+-- Ensure the OR clause is not ignored for NullTests that can't be proven
+-- always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL OR t.a = 1;
+
+-- Ensure the OR clause is reduced to constant-FALSE when all branches are
+-- provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL OR t.c IS NULL;
+
+-- Ensure the OR clause is not reduced to constant-FALSE when not all branches
+-- are provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL OR t.c IS NULL;
+
+--
+-- Test join clauses
+--
+
+-- Ensure the IS_NOT_NULL qual is ignored, since a) it's on a NOT NULL column,
+-- and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+
+-- Ensure the IS_NOT_NULL qual is not ignored when columns are made nullable
+-- by an outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE, since a) it's on a NOT
+-- NULL column, and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL AND t2.b = 1;
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE when the column is
+-- nullable by an outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL;
+
+--
+-- Tests for OR clauses in join clauses
+--
+
+-- Ensure the OR clause is ignored when an OR branch is provably always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+
+-- Ensure the NullTest is not ignored when the column is nullable by an outer
+-- join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+
+-- Ensure the OR clause is reduced to constant-FALSE when all OR branches are
+-- provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON (t2.a IS NULL OR t2.c IS NULL) AND t2.b = 1;
+
+-- Ensure the OR clause is not reduced to constant-FALSE when a column is
+-- made nullable from an join join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL OR t2.c IS NULL;
+
+DROP TABLE pred_tab;
-- 
2.40.1

#28Andy Fan
zhihuifan1213@163.com
In reply to: David Rowley (#27)
Re: Removing const-false IS NULL quals and redundant IS NOT NULL quals

Hi,

David Rowley <dgrowleyml@gmail.com> writes:

Happy to hear other people's thoughts on this patch. Otherwise, I
currently don't think the missed optimisation is a reason to block
what we've ended up with so far.

David

[1] /messages/by-id/flat/17540-7aa1855ad5ec18b4@postgresql.org

[2. application/x-patch; v10-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patch]...

Thanks for working on this, an I just get a complaint about this missed
optimisation 7 hours ago..

I also want to add notnullattnums for the UniqueKey stuff as well, by
comparing your implementation with mine, I found you didn't consider
the NOT NULL generated by filter. After apply your patch:

create table a(a int);
explain (costs off) select * from a where a > 3 and a is null;
QUERY PLAN
-------------------------------------
Seq Scan on a
Filter: ((a IS NULL) AND (a > 3))
(2 rows)

This is acutally needed by UniqueKey stuff, do you think it should be
added? To save some of your time, you can check what I did in UniqueKey

[1]: /messages/by-id/attachment/151254/v1-0001-uniquekey-on-base-relation-and-used-it-for-mark-d.patch -- Best Regards Andy Fan
/messages/by-id/attachment/151254/v1-0001-uniquekey-on-base-relation-and-used-it-for-mark-d.patch
--
Best Regards
Andy Fan

#29Richard Guo
guofenglinux@gmail.com
In reply to: Andy Fan (#28)
Re: Removing const-false IS NULL quals and redundant IS NOT NULL quals

On Wed, Dec 27, 2023 at 7:38 PM Andy Fan <zhihuifan1213@163.com> wrote:

I also want to add notnullattnums for the UniqueKey stuff as well, by
comparing your implementation with mine, I found you didn't consider
the NOT NULL generated by filter. After apply your patch:

create table a(a int);
explain (costs off) select * from a where a > 3 and a is null;
QUERY PLAN
-------------------------------------
Seq Scan on a
Filter: ((a IS NULL) AND (a > 3))
(2 rows)

The detection of self-inconsistent restrictions already exists in
planner.

# set constraint_exclusion to on;
SET
# explain (costs off) select * from a where a > 3 and a is null;
QUERY PLAN
--------------------------
Result
One-Time Filter: false
(2 rows)

Thanks
Richard

#30Andy Fan
zhihuifan1213@163.com
In reply to: Richard Guo (#29)
Re: Removing const-false IS NULL quals and redundant IS NOT NULL quals

Richard Guo <guofenglinux@gmail.com> writes:

The detection of self-inconsistent restrictions already exists in
planner.

# set constraint_exclusion to on;
SET
# explain (costs off) select * from a where a > 3 and a is null;
QUERY PLAN
--------------------------
Result
One-Time Filter: false
(2 rows)

It has a different scope and cost from what I suggested. I'd suggest
to detect the notnull constraint only with lower cost and it can be used
in another user case. the constaint_exclusion can covers more user
cases but more expensivly and default off.

Apart from the abve topic, I'm thinking if we should think about the
case like this:

create table t1(a int);
create table t2(a int);

explain (costs off) select * from t1 join t2 using(a) where a is NULL;
QUERY PLAN
-----------------------------------
Hash Join
Hash Cond: (t2.a = t1.a)
-> Seq Scan on t2
-> Hash
-> Seq Scan on t1
Filter: (a IS NULL)

Here a is nullable at the base relation side, but we know that the query
would not return anything at last. IIUC, there is no good place to
handle this in our current infrastructure, I still raise this up in case
I missed anything.

--
Best Regards
Andy Fan

#31Peter Smith
smithpb2250@gmail.com
In reply to: David Rowley (#27)
Re: Removing const-false IS NULL quals and redundant IS NOT NULL quals

2024-01 Commitfest.

Hi, This patch has a CF status of "Needs Review" [1]https://commitfest.postgresql.org/46/4459/, but it seems
there were CFbot test failures last time it was run [2]https://cirrus-ci.com/github/postgresql-cfbot/postgresql/commitfest/46/4459. Please
have a look and post an updated version if necessary.

======
[1]: https://commitfest.postgresql.org/46/4459/
[2]: https://cirrus-ci.com/github/postgresql-cfbot/postgresql/commitfest/46/4459

Kind Regards,
Peter Smith.

#32David Rowley
dgrowleyml@gmail.com
In reply to: Andy Fan (#28)
Re: Removing const-false IS NULL quals and redundant IS NOT NULL quals

On Thu, 28 Dec 2023 at 00:38, Andy Fan <zhihuifan1213@163.com> wrote:

I also want to add notnullattnums for the UniqueKey stuff as well, by
comparing your implementation with mine, I found you didn't consider
the NOT NULL generated by filter. After apply your patch:

create table a(a int);
explain (costs off) select * from a where a > 3 and a is null;
QUERY PLAN
-------------------------------------
Seq Scan on a
Filter: ((a IS NULL) AND (a > 3))
(2 rows)

[1]
/messages/by-id/attachment/151254/v1-0001-uniquekey-on-base-relation-and-used-it-for-mark-d.patch

I believe these are two different things and we should not mix the two up.

Looking at your patch, I see you have:

+ /* The not null attrs from catalogs or baserestrictinfo. */
+ Bitmapset  *notnullattrs;

Whereas, I have:

/* zero-based set containing attnums of NOT NULL columns */
Bitmapset *notnullattnums;

I'm a bit worried that your definition of notnullattrs could lead to
confusion about which optimisations will be possible.

Let's say for example I want to write some code that optimises the
expression evaluation code to transform EEOP_FUNCEXPR_STRICT into
EEOP_FUNCEXPR when all function arguments are Vars that have NOT NULL
constraints and are not nullable by any outer join. With my
definition, it should be safe to do this, but with your definition, we
can't trust we'll not see any NULLs as if the strict function is
evaluated before the strict base qual that filters the NULLs then the
strict function could be called with NULL.

Perhaps we'd want another Bitmapset that has members for strict OpExrs
that filter NULLs and we could document that it's only safe to assume
there are no NULLs beyond the scan level.... but I'd say that's
another patch and I don't want to feed you design ideas here and
derail this patch.

David

#33David Rowley
dgrowleyml@gmail.com
In reply to: Peter Smith (#31)
1 attachment(s)
Re: Removing const-false IS NULL quals and redundant IS NOT NULL quals

On Mon, 22 Jan 2024 at 17:32, Peter Smith <smithpb2250@gmail.com> wrote:

Hi, This patch has a CF status of "Needs Review" [1], but it seems
there were CFbot test failures last time it was run [2].

I've attached v11 which updates the expected results in some newly
added regression tests.

No other changes.

David

Attachments:

v11-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchtext/plain; charset=US-ASCII; name=v11-0001-Reduce-NullTest-quals-to-constant-TRUE-or-FALSE.patchDownload
From 095744f5583ab5446c1cdb75bfd3b40c7ab493d8 Mon Sep 17 00:00:00 2001
From: David Rowley <dgrowley@gmail.com>
Date: Thu, 7 Dec 2023 22:52:34 +1300
Subject: [PATCH v11] Reduce NullTest quals to constant TRUE or FALSE

---
 .../postgres_fdw/expected/postgres_fdw.out    |  16 +-
 contrib/postgres_fdw/sql/postgres_fdw.sql     |   4 +-
 src/backend/optimizer/plan/initsplan.c        | 202 +++++++++++++--
 src/backend/optimizer/util/joininfo.c         |  28 ++
 src/backend/optimizer/util/plancat.c          |  19 ++
 src/backend/optimizer/util/relnode.c          |   3 +
 src/include/nodes/pathnodes.h                 |   7 +-
 src/include/optimizer/planmain.h              |   4 +
 src/test/regress/expected/equivclass.out      |  18 +-
 src/test/regress/expected/join.out            |  67 +++--
 src/test/regress/expected/predicate.out       | 244 ++++++++++++++++++
 src/test/regress/parallel_schedule            |   2 +-
 src/test/regress/sql/predicate.sql            | 122 +++++++++
 13 files changed, 663 insertions(+), 73 deletions(-)
 create mode 100644 src/test/regress/expected/predicate.out
 create mode 100644 src/test/regress/sql/predicate.sql

diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index d83f6ae8cb..b5a38aeb21 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -656,20 +656,20 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 =
    Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-                                           QUERY PLAN                                            
--------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+                                          QUERY PLAN                                          
+----------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NULL))
 (3 rows)
 
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
-                                             QUERY PLAN                                              
------------------------------------------------------------------------------------------------------
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
+                                            QUERY PLAN                                            
+--------------------------------------------------------------------------------------------------
  Foreign Scan on public.ft1 t1
    Output: c1, c2, c3, c4, c5, c6, c7, c8
-   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c3 IS NOT NULL))
 (3 rows)
 
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 90c8fa4b70..f410c3db4e 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -332,8 +332,8 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
 -- ===================================================================
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1;         -- Var, OpExpr(b), Const
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
-EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NULL;        -- NullTest
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c3 IS NOT NULL;    -- NullTest
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1;          -- OpExpr(l)
 EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index a2c2df39da..30e8434287 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -2618,6 +2618,192 @@ check_redundant_nullability_qual(PlannerInfo *root, Node *clause)
 	return false;
 }
 
+/*
+ * add_base_clause_to_rel
+ *		Add 'restrictinfo' as a baserestrictinfo to the base relation denoted
+ *		by 'relid' with some prechecks to try to determine if the qual is
+ *		always true, in which case we ignore it rather than add it, or if the
+ *		qual is always false, in which case we replace it with constant-FALSE.
+ */
+static void
+add_base_clause_to_rel(PlannerInfo *root, Index relid,
+					   RestrictInfo *restrictinfo)
+{
+	RelOptInfo *rel = find_base_rel(root, relid);
+
+	Assert(bms_membership(restrictinfo->required_relids) == BMS_SINGLETON);
+
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/*
+	 * Substitute the origin qual with constant-FALSE if it is provably always
+	 * false.  Note that we keep the same rinfo_serial.
+	 */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int			save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 0, /* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
+	/* Add clause to rel's restriction list */
+	rel->baserestrictinfo = lappend(rel->baserestrictinfo, restrictinfo);
+
+	/* Update security level info */
+	rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
+										 restrictinfo->security_level);
+}
+
+/*
+ * expr_is_nonnullable
+ *	  Check to see if the Expr cannot be NULL
+ *
+ * If the Expr is a simple Var that is defined NOT NULL and meanwhile is not
+ * nulled by any outer joins, then we can know that it cannot be NULL.
+ */
+static bool
+expr_is_nonnullable(PlannerInfo *root, Expr *expr)
+{
+	RelOptInfo *rel;
+	Var		   *var;
+
+	/* For now only check simple Vars */
+	if (!IsA(expr, Var))
+		return false;
+
+	var = (Var *) expr;
+
+	/* could the Var be nulled by any outer joins? */
+	if (!bms_is_empty(var->varnullingrels))
+		return false;
+
+	/* system columns cannot be NULL */
+	if (var->varattno < 0)
+		return true;
+
+	/* is the column defined NOT NULL? */
+	rel = find_base_rel(root, var->varno);
+	if (var->varattno > 0 &&
+		bms_is_member(var->varattno, rel->notnullattnums))
+		return true;
+
+	return false;
+}
+
+/*
+ * restriction_is_always_true
+ *	  Check to see if the RestrictInfo is always true.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_true(PlannerInfo *root,
+						   RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest   *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NOT_NULL qual? */
+		if (nulltest->nulltesttype != IS_NOT_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+
+		/*
+		 * if any of the given OR branches is provably always true then the
+		 * entire condition is true.
+		 */
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node	   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo))
+				continue;
+
+			if (restriction_is_always_true(root, (RestrictInfo *) orarg))
+				return true;
+		}
+	}
+
+	return false;
+}
+
+/*
+ * restriction_is_always_false
+ *	  Check to see if the RestrictInfo is always false.
+ *
+ * Currently we only check for NullTest quals and OR clauses that include
+ * NullTest quals.  We may extend it in the future.
+ */
+bool
+restriction_is_always_false(PlannerInfo *root,
+							RestrictInfo *restrictinfo)
+{
+	/* Check for NullTest qual */
+	if (IsA(restrictinfo->clause, NullTest))
+	{
+		NullTest   *nulltest = (NullTest *) restrictinfo->clause;
+
+		/* is this NullTest an IS_NULL qual? */
+		if (nulltest->nulltesttype != IS_NULL)
+			return false;
+
+		return expr_is_nonnullable(root, nulltest->arg);
+	}
+
+	/* If it's an OR, check its sub-clauses */
+	if (restriction_is_or_clause(restrictinfo))
+	{
+		ListCell   *lc;
+
+		Assert(is_orclause(restrictinfo->orclause));
+
+		/*
+		 * Currently, when processing OR expressions, we only return true when
+		 * all of the OR branches are always false.  This could perhaps be
+		 * expanded to remove OR branches that are provably false.  This may
+		 * be a useful thing to do as it could result in the OR being left
+		 * with a single arg.  That's useful as it would allow the OR
+		 * condition to be replaced with its single argument which may allow
+		 * use of an index for faster filtering on the remaining condition.
+		 */
+		foreach(lc, ((BoolExpr *) restrictinfo->orclause)->args)
+		{
+			Node	   *orarg = (Node *) lfirst(lc);
+
+			if (!IsA(orarg, RestrictInfo) ||
+				!restriction_is_always_false(root, (RestrictInfo *) orarg))
+				return false;
+		}
+		return true;
+	}
+
+	return false;
+}
+
 /*
  * distribute_restrictinfo_to_rels
  *	  Push a completed RestrictInfo into the proper restriction or join
@@ -2632,27 +2818,13 @@ distribute_restrictinfo_to_rels(PlannerInfo *root,
 								RestrictInfo *restrictinfo)
 {
 	Relids		relids = restrictinfo->required_relids;
-	RelOptInfo *rel;
 
 	if (!bms_is_empty(relids))
 	{
 		int			relid;
 
 		if (bms_get_singleton_member(relids, &relid))
-		{
-			/*
-			 * There is only one relation participating in the clause, so it
-			 * is a restriction clause for that relation.
-			 */
-			rel = find_base_rel(root, relid);
-
-			/* Add clause to rel's restriction list */
-			rel->baserestrictinfo = lappend(rel->baserestrictinfo,
-											restrictinfo);
-			/* Update security level info */
-			rel->baserestrict_min_security = Min(rel->baserestrict_min_security,
-												 restrictinfo->security_level);
-		}
+			add_base_clause_to_rel(root, relid, restrictinfo);
 		else
 		{
 			/*
diff --git a/src/backend/optimizer/util/joininfo.c b/src/backend/optimizer/util/joininfo.c
index 585e9e06af..5fb0c17630 100644
--- a/src/backend/optimizer/util/joininfo.c
+++ b/src/backend/optimizer/util/joininfo.c
@@ -14,9 +14,12 @@
  */
 #include "postgres.h"
 
+#include "nodes/makefuncs.h"
 #include "optimizer/joininfo.h"
 #include "optimizer/pathnode.h"
 #include "optimizer/paths.h"
+#include "optimizer/planmain.h"
+#include "optimizer/restrictinfo.h"
 
 
 /*
@@ -98,6 +101,31 @@ add_join_clause_to_rels(PlannerInfo *root,
 {
 	int			cur_relid;
 
+	/* Don't add the clause if it is always true */
+	if (restriction_is_always_true(root, restrictinfo))
+		return;
+
+	/*
+	 * Substitute constant-FALSE for the origin qual if it is always false.
+	 * Note that we keep the same rinfo_serial.
+	 */
+	if (restriction_is_always_false(root, restrictinfo))
+	{
+		int			save_rinfo_serial = restrictinfo->rinfo_serial;
+
+		restrictinfo = make_restrictinfo(root,
+										 (Expr *) makeBoolConst(false, false),
+										 restrictinfo->is_pushed_down,
+										 restrictinfo->has_clone,
+										 restrictinfo->is_clone,
+										 restrictinfo->pseudoconstant,
+										 0, /* security_level */
+										 restrictinfo->required_relids,
+										 restrictinfo->incompatible_relids,
+										 restrictinfo->outer_relids);
+		restrictinfo->rinfo_serial = save_rinfo_serial;
+	}
+
 	cur_relid = -1;
 	while ((cur_relid = bms_next_member(join_relids, cur_relid)) >= 0)
 	{
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 9fab52c58f..b933eefa64 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -163,6 +163,25 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
 	rel->attr_widths = (int32 *)
 		palloc0((rel->max_attr - rel->min_attr + 1) * sizeof(int32));
 
+	/* record which columns are defined as NOT NULL */
+	for (int i = 0; i < relation->rd_att->natts; i++)
+	{
+		FormData_pg_attribute *attr = &relation->rd_att->attrs[i];
+
+		if (attr->attnotnull)
+		{
+			rel->notnullattnums = bms_add_member(rel->notnullattnums,
+												 attr->attnum);
+
+			/*
+			 * Per RemoveAttributeById(), dropped columns will have their
+			 * attnotnull unset, so we needn't check for dropped columns in
+			 * the above condition.
+			 */
+			Assert(!attr->attisdropped);
+		}
+	}
+
 	/*
 	 * Estimate relation size --- unless it's an inheritance parent, in which
 	 * case the size we want is not the rel's own size but the size of its
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 22d01cef5b..e5f4062bfb 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -222,6 +222,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
 	rel->relid = relid;
 	rel->rtekind = rte->rtekind;
 	/* min_attr, max_attr, attr_needed, attr_widths are set below */
+	rel->notnullattnums = NULL;
 	rel->lateral_vars = NIL;
 	rel->indexlist = NIL;
 	rel->statlist = NIL;
@@ -719,6 +720,7 @@ build_join_rel(PlannerInfo *root,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
@@ -917,6 +919,7 @@ build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
 	joinrel->max_attr = 0;
 	joinrel->attr_needed = NULL;
 	joinrel->attr_widths = NULL;
+	joinrel->notnullattnums = NULL;
 	joinrel->nulling_relids = NULL;
 	joinrel->lateral_vars = NIL;
 	joinrel->lateral_referencers = NULL;
diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h
index 137da178dc..534692bee1 100644
--- a/src/include/nodes/pathnodes.h
+++ b/src/include/nodes/pathnodes.h
@@ -913,6 +913,8 @@ typedef struct RelOptInfo
 	Relids	   *attr_needed pg_node_attr(read_write_ignore);
 	/* array indexed [min_attr .. max_attr] */
 	int32	   *attr_widths pg_node_attr(read_write_ignore);
+	/* zero-based set containing attnums of NOT NULL columns */
+	Bitmapset  *notnullattnums;
 	/* relids of outer joins that can null this baserel */
 	Relids		nulling_relids;
 	/* LATERAL Vars and PHVs referenced by rel */
@@ -2598,7 +2600,10 @@ typedef struct RestrictInfo
 	 * 2. If we manufacture a commuted version of a qual to use as an index
 	 * condition, it copies the original's rinfo_serial, since it is in
 	 * practice the same condition.
-	 * 3. RestrictInfos made for a child relation copy their parent's
+	 * 3. If we reduce a qual to constant-FALSE, the new constant-FALSE qual
+	 * copies the original's rinfo_serial, since it is in practice the same
+	 * condition.
+	 * 4. RestrictInfos made for a child relation copy their parent's
 	 * rinfo_serial.  Likewise, when an EquivalenceClass makes a derived
 	 * equality clause for a child relation, it copies the rinfo_serial of
 	 * the matching equality clause for the parent.  This allows detection
diff --git a/src/include/optimizer/planmain.h b/src/include/optimizer/planmain.h
index e0c578b996..f2e3fa4c2e 100644
--- a/src/include/optimizer/planmain.h
+++ b/src/include/optimizer/planmain.h
@@ -76,6 +76,10 @@ extern void add_vars_to_targetlist(PlannerInfo *root, List *vars,
 extern void find_lateral_references(PlannerInfo *root);
 extern void create_lateral_join_info(PlannerInfo *root);
 extern List *deconstruct_jointree(PlannerInfo *root);
+extern bool restriction_is_always_true(PlannerInfo *root,
+									   RestrictInfo *restrictinfo);
+extern bool restriction_is_always_false(PlannerInfo *root,
+										RestrictInfo *restrictinfo);
 extern void distribute_restrictinfo_to_rels(PlannerInfo *root,
 											RestrictInfo *restrictinfo);
 extern RestrictInfo *process_implied_equality(PlannerInfo *root,
diff --git a/src/test/regress/expected/equivclass.out b/src/test/regress/expected/equivclass.out
index de71441052..3d5de28354 100644
--- a/src/test/regress/expected/equivclass.out
+++ b/src/test/regress/expected/equivclass.out
@@ -438,15 +438,14 @@ set enable_mergejoin to off;
 explain (costs off)
   select * from ec0 m join ec0 n on m.ff = n.ff
   join ec1 p on m.ff + n.ff = p.f1;
-               QUERY PLAN               
-----------------------------------------
+              QUERY PLAN               
+---------------------------------------
  Nested Loop
    Join Filter: ((n.ff + n.ff) = p.f1)
-   ->  Seq Scan on ec1 p
+   ->  Seq Scan on ec0 n
    ->  Materialize
-         ->  Seq Scan on ec0 n
-               Filter: (ff IS NOT NULL)
-(6 rows)
+         ->  Seq Scan on ec1 p
+(5 rows)
 
 explain (costs off)
   select * from ec0 m join ec0 n on m.ff = n.ff
@@ -455,11 +454,10 @@ explain (costs off)
 ---------------------------------------------------------------
  Nested Loop
    Join Filter: ((p.f1)::bigint = ((n.ff + n.ff))::int8alias1)
-   ->  Seq Scan on ec1 p
+   ->  Seq Scan on ec0 n
    ->  Materialize
-         ->  Seq Scan on ec0 n
-               Filter: (ff IS NOT NULL)
-(6 rows)
+         ->  Seq Scan on ec1 p
+(5 rows)
 
 reset enable_mergejoin;
 -- this could be converted, but isn't at present
diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out
index a2fad81d7a..9c08d0134c 100644
--- a/src/test/regress/expected/join.out
+++ b/src/test/regress/expected/join.out
@@ -6357,14 +6357,14 @@ SELECT * FROM pg_am am WHERE am.amname IN (
     JOIN pg_class c2
     ON c1.oid=c2.oid AND c1.oid < 10
 );
-                             QUERY PLAN                              
----------------------------------------------------------------------
+                           QUERY PLAN                           
+----------------------------------------------------------------
  Nested Loop Semi Join
    Join Filter: (am.amname = c2.relname)
    ->  Seq Scan on pg_am am
    ->  Materialize
          ->  Index Scan using pg_class_oid_index on pg_class c2
-               Index Cond: ((oid < '10'::oid) AND (oid IS NOT NULL))
+               Index Cond: (oid < '10'::oid)
 (6 rows)
 
 --
@@ -6619,14 +6619,14 @@ SELECT COUNT(*) FROM tab_with_flag
 WHERE
 	(is_flag IS NULL OR is_flag = 0)
 	AND id IN (SELECT id FROM tab_with_flag WHERE id IN (2, 3));
-                                    QUERY PLAN                                    
-----------------------------------------------------------------------------------
+                        QUERY PLAN                         
+-----------------------------------------------------------
  Aggregate
    ->  Bitmap Heap Scan on tab_with_flag
-         Recheck Cond: ((id = ANY ('{2,3}'::integer[])) AND (id IS NOT NULL))
+         Recheck Cond: (id = ANY ('{2,3}'::integer[]))
          Filter: ((is_flag IS NULL) OR (is_flag = 0))
          ->  Bitmap Index Scan on tab_with_flag_pkey
-               Index Cond: ((id = ANY ('{2,3}'::integer[])) AND (id IS NOT NULL))
+               Index Cond: (id = ANY ('{2,3}'::integer[]))
 (6 rows)
 
 DROP TABLE tab_with_flag;
@@ -6745,11 +6745,11 @@ reset enable_seqscan;
 CREATE TABLE emp1 (id SERIAL PRIMARY KEY NOT NULL, code int);
 explain (verbose, costs off)
 SELECT * FROM emp1 e1, emp1 e2 WHERE e1.id = e2.id AND e2.code <> e1.code;
-                        QUERY PLAN                        
-----------------------------------------------------------
+                QUERY PLAN                
+------------------------------------------
  Seq Scan on public.emp1 e2
    Output: e2.id, e2.code, e2.id, e2.code
-   Filter: ((e2.id IS NOT NULL) AND (e2.code <> e2.code))
+   Filter: (e2.code <> e2.code)
 (3 rows)
 
 -- Shuffle self-joined relations. Only in the case of iterative deletion
@@ -6758,31 +6758,31 @@ CREATE UNIQUE INDEX ON emp1((id*id));
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c1.id=c2.id AND c1.id*c2.id=c3.id*c3.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c1.id=c3.id AND c1.id*c3.id=c2.id*c2.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 explain (costs off)
 SELECT count(*) FROM emp1 c1, emp1 c2, emp1 c3
 WHERE c3.id=c2.id AND c3.id*c2.id=c1.id*c1.id;
-                           QUERY PLAN                           
-----------------------------------------------------------------
+               QUERY PLAN                
+-----------------------------------------
  Aggregate
    ->  Seq Scan on emp1 c3
-         Filter: ((id IS NOT NULL) AND ((id * id) IS NOT NULL))
+         Filter: ((id * id) IS NOT NULL)
 (3 rows)
 
 -- Check the usage of a parse tree by the set operations (bug #18170)
@@ -6791,16 +6791,15 @@ SELECT c1.code FROM emp1 c1 LEFT JOIN emp1 c2 ON c1.id = c2.id
 WHERE c2.id IS NOT NULL
 EXCEPT ALL
 SELECT c3.code FROM emp1 c3;
-                  QUERY PLAN                  
-----------------------------------------------
+                QUERY PLAN                 
+-------------------------------------------
  HashSetOp Except All
    ->  Append
          ->  Subquery Scan on "*SELECT* 1"
                ->  Seq Scan on emp1 c2
-                     Filter: (id IS NOT NULL)
          ->  Subquery Scan on "*SELECT* 2"
                ->  Seq Scan on emp1 c3
-(7 rows)
+(6 rows)
 
 -- Check that SJE removes references from PHVs correctly
 explain (costs off)
@@ -6809,8 +6808,8 @@ select * from emp1 t1 left join
         left join (emp1 t3 join emp1 t4 on t3.id = t4.id)
         on true)
 on true;
-                     QUERY PLAN                     
-----------------------------------------------------
+                 QUERY PLAN                  
+---------------------------------------------
  Nested Loop Left Join
    ->  Seq Scan on emp1 t1
    ->  Materialize
@@ -6818,8 +6817,7 @@ on true;
                ->  Seq Scan on emp1 t2
                ->  Materialize
                      ->  Seq Scan on emp1 t4
-                           Filter: (id IS NOT NULL)
-(8 rows)
+(7 rows)
 
 -- Check that SJE removes the whole PHVs correctly
 explain (verbose, costs off)
@@ -6828,8 +6826,8 @@ select 1 from emp1 t1 left join
         (select * from emp1 t3) s2 on s1.id = s2.id)
     on true
 where s1.x = 1;
-                       QUERY PLAN                        
----------------------------------------------------------
+               QUERY PLAN               
+----------------------------------------
  Nested Loop
    Output: 1
    ->  Seq Scan on public.emp1 t1
@@ -6838,7 +6836,7 @@ where s1.x = 1;
          Output: t3.id
          ->  Seq Scan on public.emp1 t3
                Output: t3.id
-               Filter: ((t3.id IS NOT NULL) AND (1 = 1))
+               Filter: (1 = 1)
 (9 rows)
 
 -- Check that PHVs do not impose any constraints on removing self joins
@@ -6851,11 +6849,10 @@ select * from emp1 t1 join emp1 t2 on t1.id = t2.id left join
    Output: t2.id, t2.code, t2.id, t2.code, (t2.id), t3.t3
    ->  Seq Scan on public.emp1 t2
          Output: t2.id, t2.code
-         Filter: (t2.id IS NOT NULL)
    ->  Function Scan on pg_catalog.generate_series t3
          Output: t3.t3, t2.id
          Function Call: generate_series(1, 1)
-(8 rows)
+(7 rows)
 
 explain (verbose, costs off)
 select * from generate_series(1,10) t1(id) left join
@@ -6870,8 +6867,7 @@ on true;
          Function Call: generate_series(1, 10)
    ->  Seq Scan on public.emp1 t3
          Output: t3.id, t1.id
-         Filter: (t3.id IS NOT NULL)
-(8 rows)
+(7 rows)
 
 -- Check that SJE replaces join clauses involving the removed rel correctly
 explain (costs off)
@@ -6883,10 +6879,9 @@ select * from emp1 t1
  Nested Loop Left Join
    Join Filter: ((t2.id > 1) AND (t2.id < 2))
    ->  Seq Scan on emp1 t2
-         Filter: (id IS NOT NULL)
    ->  Materialize
          ->  Seq Scan on emp1 t3
-(6 rows)
+(5 rows)
 
 -- Check that SJE doesn't replace the target relation
 explain (costs off)
diff --git a/src/test/regress/expected/predicate.out b/src/test/regress/expected/predicate.out
new file mode 100644
index 0000000000..395ffb0fcd
--- /dev/null
+++ b/src/test/regress/expected/predicate.out
@@ -0,0 +1,244 @@
+--
+-- Tests for predicate handling
+--
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+CREATE TABLE pred_tab (a int NOT NULL, b int, c int NOT NULL);
+--
+-- Test restriction clauses
+--
+-- Ensure the IS_NOT_NULL qual is ignored when the column is non-nullable
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- Ensure the IS_NOT_NULL qual is not ignored on a nullable column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL;
+        QUERY PLAN         
+---------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NOT NULL)
+(2 rows)
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE for non-nullable
+-- columns
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE on nullable
+-- columns
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+   Filter: (b IS NULL)
+(2 rows)
+
+--
+-- Tests for OR clauses in restriction clauses
+--
+-- Ensure the OR clause is ignored when an OR branch is always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL OR t.b = 1;
+       QUERY PLAN       
+------------------------
+ Seq Scan on pred_tab t
+(1 row)
+
+-- Ensure the OR clause is not ignored for NullTests that can't be proven
+-- always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL OR t.a = 1;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NOT NULL) OR (a = 1))
+(2 rows)
+
+-- Ensure the OR clause is reduced to constant-FALSE when all branches are
+-- provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL OR t.c IS NULL;
+        QUERY PLAN        
+--------------------------
+ Result
+   One-Time Filter: false
+(2 rows)
+
+-- Ensure the OR clause is not reduced to constant-FALSE when not all branches
+-- are provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL OR t.c IS NULL;
+               QUERY PLAN               
+----------------------------------------
+ Seq Scan on pred_tab t
+   Filter: ((b IS NULL) OR (c IS NULL))
+(2 rows)
+
+--
+-- Test join clauses
+--
+-- Ensure the IS_NOT_NULL qual is ignored, since a) it's on a NOT NULL column,
+-- and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Ensure the IS_NOT_NULL qual is not ignored when columns are made nullable
+-- by an outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NOT NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE, since a) it's on a NOT
+-- NULL column, and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL AND t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE when the column is
+-- nullable by an outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL;
+                QUERY PLAN                 
+-------------------------------------------
+ Nested Loop Left Join
+   Join Filter: (t2.a IS NULL)
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+--
+-- Tests for OR clauses in join clauses
+--
+-- Ensure the OR clause is ignored when an OR branch is provably always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+                   QUERY PLAN                    
+-------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               ->  Seq Scan on pred_tab t2
+               ->  Materialize
+                     ->  Seq Scan on pred_tab t3
+(7 rows)
+
+-- Ensure the NullTest is not ignored when the column is nullable by an outer
+-- join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NOT NULL) OR (t2.b = 1))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+-- Ensure the OR clause is reduced to constant-FALSE when all OR branches are
+-- provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON (t2.a IS NULL OR t2.c IS NULL) AND t2.b = 1;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   ->  Seq Scan on pred_tab t1
+   ->  Materialize
+         ->  Nested Loop Left Join
+               Join Filter: (false AND (t2.b = 1))
+               ->  Seq Scan on pred_tab t2
+               ->  Result
+                     One-Time Filter: false
+(8 rows)
+
+-- Ensure the OR clause is not reduced to constant-FALSE when a column is
+-- made nullable from an join join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL OR t2.c IS NULL;
+                    QUERY PLAN                     
+---------------------------------------------------
+ Nested Loop Left Join
+   Join Filter: ((t2.a IS NULL) OR (t2.c IS NULL))
+   ->  Nested Loop Left Join
+         Join Filter: (t1.a = 1)
+         ->  Seq Scan on pred_tab t1
+         ->  Materialize
+               ->  Seq Scan on pred_tab t2
+   ->  Materialize
+         ->  Seq Scan on pred_tab t3
+(9 rows)
+
+DROP TABLE pred_tab;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index f0987ff537..6f5a33c234 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr
 # The stats test resets stats, so nothing else needing stats access can be in
 # this group.
 # ----------
-test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats
+test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats predicate
 
 # event_trigger depends on create_am and cannot run concurrently with
 # any test that runs DDL
diff --git a/src/test/regress/sql/predicate.sql b/src/test/regress/sql/predicate.sql
new file mode 100644
index 0000000000..338daf3255
--- /dev/null
+++ b/src/test/regress/sql/predicate.sql
@@ -0,0 +1,122 @@
+--
+-- Tests for predicate handling
+--
+
+--
+-- test that restrictions that are always true are ignored, and that are always
+-- false are replaced with constant-FALSE
+--
+-- currently we only check for NullTest quals and OR clauses that include
+-- NullTest quals.  We may extend it in the future.
+--
+CREATE TABLE pred_tab (a int NOT NULL, b int, c int NOT NULL);
+
+--
+-- Test restriction clauses
+--
+
+-- Ensure the IS_NOT_NULL qual is ignored when the column is non-nullable
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL;
+
+-- Ensure the IS_NOT_NULL qual is not ignored on a nullable column
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL;
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE for non-nullable
+-- columns
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL;
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE on nullable
+-- columns
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL;
+
+--
+-- Tests for OR clauses in restriction clauses
+--
+
+-- Ensure the OR clause is ignored when an OR branch is always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NOT NULL OR t.b = 1;
+
+-- Ensure the OR clause is not ignored for NullTests that can't be proven
+-- always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NOT NULL OR t.a = 1;
+
+-- Ensure the OR clause is reduced to constant-FALSE when all branches are
+-- provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.a IS NULL OR t.c IS NULL;
+
+-- Ensure the OR clause is not reduced to constant-FALSE when not all branches
+-- are provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t WHERE t.b IS NULL OR t.c IS NULL;
+
+--
+-- Test join clauses
+--
+
+-- Ensure the IS_NOT_NULL qual is ignored, since a) it's on a NOT NULL column,
+-- and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+
+-- Ensure the IS_NOT_NULL qual is not ignored when columns are made nullable
+-- by an outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL;
+
+-- Ensure the IS_NULL qual is reduced to constant-FALSE, since a) it's on a NOT
+-- NULL column, and b) its Var is not nullable by any outer joins
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL AND t2.b = 1;
+
+-- Ensure the IS_NULL qual is not reduced to constant-FALSE when the column is
+-- nullable by an outer join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL;
+
+--
+-- Tests for OR clauses in join clauses
+--
+
+-- Ensure the OR clause is ignored when an OR branch is provably always true
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+
+-- Ensure the NullTest is not ignored when the column is nullable by an outer
+-- join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NOT NULL OR t2.b = 1;
+
+-- Ensure the OR clause is reduced to constant-FALSE when all OR branches are
+-- provably false
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON TRUE
+    LEFT JOIN pred_tab t3 ON (t2.a IS NULL OR t2.c IS NULL) AND t2.b = 1;
+
+-- Ensure the OR clause is not reduced to constant-FALSE when a column is
+-- made nullable from an join join
+EXPLAIN (COSTS OFF)
+SELECT * FROM pred_tab t1
+    LEFT JOIN pred_tab t2 ON t1.a = 1
+    LEFT JOIN pred_tab t3 ON t2.a IS NULL OR t2.c IS NULL;
+
+DROP TABLE pred_tab;
-- 
2.40.1

#34David Rowley
dgrowleyml@gmail.com
In reply to: David Rowley (#33)
Re: Removing const-false IS NULL quals and redundant IS NOT NULL quals

On Tue, 23 Jan 2024 at 00:11, David Rowley <dgrowleyml@gmail.com> wrote:

I've attached v11 which updates the expected results in some newly
added regression tests.

I went over this again. I did a little more work adjusting comments
and pushed it.

Thanks for all your assistance with this, Richard.

David

#35Richard Guo
guofenglinux@gmail.com
In reply to: David Rowley (#34)
Re: Removing const-false IS NULL quals and redundant IS NOT NULL quals

On Tue, Jan 23, 2024 at 1:11 PM David Rowley <dgrowleyml@gmail.com> wrote:

I went over this again. I did a little more work adjusting comments
and pushed it.

Thanks for all your assistance with this, Richard.

Thanks for pushing! This is really great.

Thanks
Richard