Skip to content

Commit

Permalink
opt: normalize x=True, x=False, x != True, and x != False to x or NOT x
Browse files Browse the repository at this point in the history
This commit adds four normalization rules, FoldEqTrue, FoldEqFalse,
FoldNeTrue, and FoldNeFalse, which normalize x=True to x, x=False to
NOT x, x != True to NOT x, and x != False to x. These rules are
important since they can unlock other types of optimizations, such
as constrained index scans.

Fixes #65684

Release note (performance improvement): Fixed an issue in the optimizer
that prevented spatial predicates of the form `(column && value) = true` from
being index-accelerated. These queries can now use a spatial index if one is
available.
  • Loading branch information
rytaft committed Jun 1, 2021
1 parent eea0d2f commit 33babf1
Show file tree
Hide file tree
Showing 10 changed files with 216 additions and 42 deletions.
8 changes: 4 additions & 4 deletions pkg/sql/opt/idxconstraint/testdata/single-column
Original file line number Diff line number Diff line change
Expand Up @@ -153,12 +153,12 @@ NOT a
index-constraints vars=(a bool) index=(a)
a != true
----
(/NULL - /false]
[/false - /false]

index-constraints vars=(a bool) index=(a)
a != false
----
[/true - ]
[/true - /true]

index-constraints vars=(a bool) index=(a)
a IS TRUE
Expand Down Expand Up @@ -195,12 +195,12 @@ a IS DISTINCT FROM 5
index-constraints vars=(a bool) index=(a desc)
a != true
----
[/false - /NULL)
[/false - /false]

index-constraints vars=(a bool) index=(a desc)
a != false
----
[ - /true]
[/true - /true]

index-constraints vars=(a bool) index=(a desc)
a IS TRUE
Expand Down
11 changes: 5 additions & 6 deletions pkg/sql/opt/memo/testdata/logprops/constraints
Original file line number Diff line number Diff line change
Expand Up @@ -545,28 +545,27 @@ SELECT * FROM abc WHERE b != true
----
select
├── columns: a:1(int) b:2(bool!null) c:3(string)
├── fd: ()-->(2)
├── prune: (1,3)
├── scan abc
│ ├── columns: a:1(int) b:2(bool) c:3(string)
│ └── prune: (1-3)
└── filters
└── ne [type=bool, outer=(2), constraints=(/2: (/NULL - /false]; tight)]
├── variable: b:2 [type=bool]
└── true [type=bool]
└── not [type=bool, outer=(2), constraints=(/2: [/false - /false]; tight), fd=()-->(2)]
└── variable: b:2 [type=bool]

opt
SELECT * FROM abc WHERE b != false
----
select
├── columns: a:1(int) b:2(bool!null) c:3(string)
├── fd: ()-->(2)
├── prune: (1,3)
├── scan abc
│ ├── columns: a:1(int) b:2(bool) c:3(string)
│ └── prune: (1-3)
└── filters
└── ne [type=bool, outer=(2), constraints=(/2: [/true - ]; tight)]
├── variable: b:2 [type=bool]
└── false [type=bool]
└── variable: b:2 [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]

opt
SELECT * FROM abc WHERE b IS NOT true
Expand Down
12 changes: 6 additions & 6 deletions pkg/sql/opt/memo/testdata/stats/scan
Original file line number Diff line number Diff line change
Expand Up @@ -1128,7 +1128,7 @@ select
│ └── fd: ()-->(3), (7)-->(5)
└── filters
├── a:1 = '37685f26-4b07-40ba-9bbf-42916ed9bc61' [type=bool, outer=(1), constraints=(/1: [/'37685f26-4b07-40ba-9bbf-42916ed9bc61' - /'37685f26-4b07-40ba-9bbf-42916ed9bc61']; tight), fd=()-->(1)]
├── b:2 = true [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
├── b:2 [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
├── d:4 = 'foo' [type=bool, outer=(4), constraints=(/4: [/'foo' - /'foo']; tight), fd=()-->(4)]
└── f:6 > 0.0 [type=bool, outer=(6), constraints=(/6: [/5e-324 - ]; tight)]

Expand Down Expand Up @@ -1194,7 +1194,7 @@ select
│ └── f:6 > 0.0 [type=bool, outer=(6), constraints=(/6: [/5e-324 - ]; tight)]
└── filters
├── a:1 = '37685f26-4b07-40ba-9bbf-42916ed9bc61' [type=bool, outer=(1), constraints=(/1: [/'37685f26-4b07-40ba-9bbf-42916ed9bc61' - /'37685f26-4b07-40ba-9bbf-42916ed9bc61']; tight), fd=()-->(1)]
├── b:2 = true [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
├── b:2 [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
└── c:3 = 5 [type=bool, outer=(3), constraints=(/3: [/5 - /5]; tight), fd=()-->(3)]

# A different combination of predicates.
Expand Down Expand Up @@ -1225,7 +1225,7 @@ select
│ ├── key: (7)
│ └── fd: ()-->(3), (7)-->(5)
└── filters
├── b:2 = true [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
├── b:2 [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
└── f:6 > 0.0 [type=bool, outer=(6), constraints=(/6: [/5e-324 - ]; tight)]

# Force the alternate index.
Expand Down Expand Up @@ -1514,7 +1514,7 @@ select
│ ├── key: (7)
│ └── fd: ()-->(3), (7)-->(5)
└── filters
├── b:2 = true [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
├── b:2 [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
└── f:6 > 0.0 [type=bool, outer=(6), constraints=(/6: [/5e-324 - ]; tight)]

# Force the alternate index.
Expand Down Expand Up @@ -1855,7 +1855,7 @@ select
│ ├── key: (7)
│ └── fd: ()-->(3), (7)-->(5)
└── filters
├── b:2 = true [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
├── b:2 [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
└── f:6 > 0.0 [type=bool, outer=(6), constraints=(/6: [/5e-324 - ]; tight)]

# Force the alternate index.
Expand Down Expand Up @@ -1959,7 +1959,7 @@ select
│ └── fd: ()-->(4-6)
└── filters
├── a:1 = '37685f26-4b07-40ba-9bbf-42916ed9bc61' [type=bool, outer=(1), constraints=(/1: [/'37685f26-4b07-40ba-9bbf-42916ed9bc61' - /'37685f26-4b07-40ba-9bbf-42916ed9bc61']; tight), fd=()-->(1)]
└── b:2 = true [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
└── b:2 [type=bool, outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]

opt
SELECT * FROM multi_col
Expand Down
2 changes: 1 addition & 1 deletion pkg/sql/opt/memo/testdata/stats/select
Original file line number Diff line number Diff line change
Expand Up @@ -1730,7 +1730,7 @@ select
│ histogram(2)= 0 900 0 100
│ <--- false --- true
└── filters
└── b:2 = false [type=bool, outer=(2), constraints=(/2: [/false - /false]; tight), fd=()-->(2)]
└── NOT b:2 [type=bool, outer=(2), constraints=(/2: [/false - /false]; tight), fd=()-->(2)]

exec-ddl
CREATE TABLE t0(c0 INT)
Expand Down
24 changes: 24 additions & 0 deletions pkg/sql/opt/norm/rules/comp.opt
Original file line number Diff line number Diff line change
Expand Up @@ -295,3 +295,27 @@
)
=>
(MakeSTDFullyWithinRight (OpName) $args $left)

# FoldEqTrue replaces x = True with x.
[FoldEqTrue, Normalize]
(Eq $left:* (True))
=>
$left

# FoldEqFalse replaces x = False with NOT x.
[FoldEqFalse, Normalize]
(Eq $left:* (False))
=>
(Not $left)

# FoldNeTrue replaces x != True with NOT x.
[FoldNeTrue, Normalize]
(Ne $left:* (True))
=>
(Not $left)

# FoldNeFalse replaces x != False with x.
[FoldNeFalse, Normalize]
(Ne $left:* (False))
=>
$left
151 changes: 151 additions & 0 deletions pkg/sql/opt/norm/testdata/rules/comp
Original file line number Diff line number Diff line change
Expand Up @@ -1114,3 +1114,154 @@ select
│ └── columns: geom:1 geog:2 val:3
└── filters
└── st_dfullywithinexclusive(geom:1, '010100000000000000000000000000000000000000', val:3) [outer=(1,3), immutable, constraints=(/1: (/NULL - ]; /3: (/NULL - ])]

# --------------------------------------------------
# FoldEqTrue + FoldEqFalse
# --------------------------------------------------

exec-ddl
CREATE TABLE tbl (k INT PRIMARY KEY, b BOOL)
----

norm expect=FoldEqTrue
SELECT * FROM tbl WHERE b=TRUE
----
select
├── columns: k:1!null b:2!null
├── key: (1)
├── fd: ()-->(2)
├── scan tbl
│ ├── columns: k:1!null b:2
│ ├── key: (1)
│ └── fd: (1)-->(2)
└── filters
└── b:2 [outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]

norm expect=FoldEqTrue
SELECT b=TRUE FROM tbl
----
project
├── columns: "?column?":4
├── scan tbl
│ └── columns: b:2
└── projections
└── b:2 [as="?column?":4, outer=(2)]

norm expect=FoldEqFalse
SELECT * FROM tbl WHERE b=FALSE
----
select
├── columns: k:1!null b:2!null
├── key: (1)
├── fd: ()-->(2)
├── scan tbl
│ ├── columns: k:1!null b:2
│ ├── key: (1)
│ └── fd: (1)-->(2)
└── filters
└── NOT b:2 [outer=(2), constraints=(/2: [/false - /false]; tight), fd=()-->(2)]

norm expect=FoldEqFalse
SELECT b=FALSE FROM tbl
----
project
├── columns: "?column?":4
├── scan tbl
│ └── columns: b:2
└── projections
└── NOT b:2 [as="?column?":4, outer=(2)]

exec-ddl
CREATE INVERTED INDEX ON geom_geog(geom)
----

# Regression test for #65684.
# We use opt here to show that the inverted index is used.
opt expect=FoldEqTrue
SELECT count(*) FROM geom_geog WHERE (geom && st_geomfromewkt('SRID=4326;POLYGON((0 0,0 100,100 100,100 0,0 0))'))=TRUE;
----
scalar-group-by
├── columns: count:7!null
├── cardinality: [1 - 1]
├── immutable
├── key: ()
├── fd: ()-->(7)
├── select
│ ├── columns: geom:1!null
│ ├── immutable
│ ├── index-join geom_geog
│ │ ├── columns: geom:1
│ │ └── inverted-filter
│ │ ├── columns: rowid:4!null
│ │ ├── inverted expression: /6
│ │ │ ├── tight: false, unique: false
│ │ │ └── union spans
│ │ │ ├── ["B\x89", "B\xfd \x00\x00\x00\x00\x00\x00\x00")
│ │ │ └── ["B\xfd\xff\xff\xff\xff\xff\xff\xff\xff", "B\xfd\xff\xff\xff\xff\xff\xff\xff\xff"]
│ │ ├── pre-filterer expression
│ │ │ └── st_intersects('0103000020E610000001000000050000000000000000000000000000000000000000000000000000000000000000005940000000000000594000000000000059400000000000005940000000000000000000000000000000000000000000000000', geom:1)
│ │ ├── key: (4)
│ │ └── scan geom_geog@secondary
│ │ ├── columns: rowid:4!null geom_inverted_key:6!null
│ │ ├── inverted constraint: /6/4
│ │ │ └── spans
│ │ │ ├── ["B\x89", "B\xfd \x00\x00\x00\x00\x00\x00\x00")
│ │ │ └── ["B\xfd\xff\xff\xff\xff\xff\xff\xff\xff", "B\xfd\xff\xff\xff\xff\xff\xff\xff\xff"]
│ │ ├── key: (4)
│ │ └── fd: (4)-->(6)
│ └── filters
│ └── geom:1 && '0103000020E610000001000000050000000000000000000000000000000000000000000000000000000000000000005940000000000000594000000000000059400000000000005940000000000000000000000000000000000000000000000000' [outer=(1), immutable, constraints=(/1: (/NULL - ])]
└── aggregations
└── count-rows [as=count_rows:7]

# --------------------------------------------------
# FoldNeTrue + FoldNeFalse
# --------------------------------------------------

norm expect=FoldNeTrue
SELECT * FROM tbl WHERE b != TRUE
----
select
├── columns: k:1!null b:2!null
├── key: (1)
├── fd: ()-->(2)
├── scan tbl
│ ├── columns: k:1!null b:2
│ ├── key: (1)
│ └── fd: (1)-->(2)
└── filters
└── NOT b:2 [outer=(2), constraints=(/2: [/false - /false]; tight), fd=()-->(2)]

norm expect=FoldNeTrue
SELECT b != TRUE FROM tbl
----
project
├── columns: "?column?":4
├── scan tbl
│ └── columns: b:2
└── projections
└── NOT b:2 [as="?column?":4, outer=(2)]

norm expect=FoldNeFalse
SELECT * FROM tbl WHERE b != FALSE
----
select
├── columns: k:1!null b:2!null
├── key: (1)
├── fd: ()-->(2)
├── scan tbl
│ ├── columns: k:1!null b:2
│ ├── key: (1)
│ └── fd: (1)-->(2)
└── filters
└── b:2 [outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]

norm expect=FoldNeFalse
SELECT b != FALSE FROM tbl
----
project
├── columns: "?column?":4
├── scan tbl
│ └── columns: b:2
└── projections
└── b:2 [as="?column?":4, outer=(2)]
2 changes: 1 addition & 1 deletion pkg/sql/opt/norm/testdata/rules/select
Original file line number Diff line number Diff line change
Expand Up @@ -215,7 +215,7 @@ select
├── scan c
│ └── columns: a:1 b:2 c:3 d:4 e:5
└── filters
├── a:1 AND (a:1 = true) [outer=(1), constraints=(/1: [/true - /true]; tight), fd=()-->(1)]
├── a:1 [outer=(1), constraints=(/1: [/true - /true]; tight), fd=()-->(1)]
├── b:2 [outer=(2), constraints=(/2: [/true - /true]; tight), fd=()-->(2)]
└── b:2 = c:3 [outer=(2,3), constraints=(/2: (/NULL - ]; /3: (/NULL - ]), fd=(2)==(3), (3)==(2)]

Expand Down
2 changes: 1 addition & 1 deletion pkg/sql/opt/xform/testdata/external/liquibase
Original file line number Diff line number Diff line change
Expand Up @@ -217,7 +217,7 @@ project
│ │ │ │ │ │ │ │ ├── key: (78)
│ │ │ │ │ │ │ │ └── fd: (78)-->(79,85)
│ │ │ │ │ │ │ └── filters
│ │ │ │ │ │ │ └── indisclustered:85 = true [outer=(85), constraints=(/85: [/true - /true]; tight), fd=()-->(85)]
│ │ │ │ │ │ │ └── indisclustered:85 [outer=(85), constraints=(/85: [/true - /true]; tight), fd=()-->(85)]
│ │ │ │ │ │ ├── left-join (lookup pg_tablespace [as=t])
│ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:29!null n.nspname:30!null t.oid:34 spcname:35 ftrelid:126 ftserver:127 ftoptions:128 fs.oid:130 srvname:131
│ │ │ │ │ │ │ ├── key columns: [8] = [34]
Expand Down
2 changes: 1 addition & 1 deletion pkg/sql/opt/xform/testdata/external/navicat
Original file line number Diff line number Diff line change
Expand Up @@ -221,7 +221,7 @@ sort
│ │ │ │ │ │ │ │ ├── key: (78)
│ │ │ │ │ │ │ │ └── fd: (78)-->(79,85)
│ │ │ │ │ │ │ └── filters
│ │ │ │ │ │ │ └── indisclustered:85 = true [outer=(85), constraints=(/85: [/true - /true]; tight), fd=()-->(85)]
│ │ │ │ │ │ │ └── indisclustered:85 [outer=(85), constraints=(/85: [/true - /true]; tight), fd=()-->(85)]
│ │ │ │ │ │ ├── left-join (lookup pg_tablespace [as=t])
│ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:29!null n.nspname:30!null t.oid:34 spcname:35 ftrelid:126 ftserver:127 ftoptions:128 fs.oid:130 srvname:131
│ │ │ │ │ │ │ ├── key columns: [8] = [34]
Expand Down
Loading

0 comments on commit 33babf1

Please sign in to comment.