Skip to content

Commit

Permalink
opt: normalize In with single-element list to Eq
Browse files Browse the repository at this point in the history
This commit adds a rule that normalizes `a IN (b)` to `a = b` (and
similarly `NOT IN` to `!=`).

This query confirms the equivalency holds even when NULLs are
involved:

```
WITH
  vals (v) AS (VALUES (1), (2), (NULL))
SELECT
  v1.v, v2.v, v1.v NOT IN (v2.v,) AS in, v1.v != v2.v AS eq
FROM
  vals AS v1, vals AS v2

   v   |  v   |  in   |  eq
-------+------+-------+--------
     1 |    1 | false | false
     1 |    2 | true  | true
     1 | NULL | NULL  | NULL
     2 |    1 | true  | true
     2 |    2 | false | false
     2 | NULL | NULL  | NULL
  NULL |    1 | NULL  | NULL
  NULL |    2 | NULL  | NULL
  NULL | NULL | NULL  | NULL
```

Release note: None
  • Loading branch information
RaduBerinde committed Apr 20, 2021
1 parent 22e4d64 commit 4c6e54e
Show file tree
Hide file tree
Showing 9 changed files with 132 additions and 14 deletions.
2 changes: 1 addition & 1 deletion pkg/sql/opt/exec/execbuilder/testdata/explain
Original file line number Diff line number Diff line change
Expand Up @@ -454,7 +454,7 @@ vectorized: true
│ order: +grantee,+privilege_type
└── • filter
│ filter: (table_catalog, table_schema, table_name) IN (('test', 'public', 'foo'),)
│ filter: ((table_catalog = 'test') AND (table_schema = 'public')) AND (table_name = 'foo')
└── • virtual table
table: table_privileges@primary
Expand Down
2 changes: 1 addition & 1 deletion pkg/sql/opt/exec/execbuilder/testdata/scalar
Original file line number Diff line number Diff line change
Expand Up @@ -1201,7 +1201,7 @@ vectorized: true
• filter
│ columns: (c0)
│ estimated row count: 333 (missing stats)
│ filter: CASE WHEN c0 IN (c0,) THEN ARRAY[NULL] ELSE ARRAY[] END IS NULL
│ filter: CASE WHEN (c0 IS DISTINCT FROM CAST(NULL AS DECIMAL)) OR CAST(NULL AS BOOL) THEN ARRAY[NULL] ELSE ARRAY[] END IS NULL
└── • scan
columns: (c0)
Expand Down
2 changes: 1 addition & 1 deletion pkg/sql/opt/exec/execbuilder/testdata/select_index
Original file line number Diff line number Diff line change
Expand Up @@ -823,7 +823,7 @@ vectorized: true
└── • filter
│ columns: (k, a, b)
│ estimated row count: 333 (missing stats)
│ filter: ((a IN (6,)) AND (a > 6)) OR (b >= 4)
│ filter: ((a = 6) AND (a > 6)) OR (b >= 4)
└── • scan
columns: (k, a, b)
Expand Down
2 changes: 1 addition & 1 deletion pkg/sql/opt/exec/execbuilder/testdata/virtual
Original file line number Diff line number Diff line change
Expand Up @@ -139,7 +139,7 @@ vectorized: true
│ equality: (oid) = (connamespace)
├── • filter
│ │ filter: nspname IN ('public',)
│ │ filter: nspname = 'public'
│ │
│ └── • virtual table
│ table: pg_namespace@primary
Expand Down
14 changes: 8 additions & 6 deletions pkg/sql/opt/memo/testdata/stats/scan
Original file line number Diff line number Diff line change
Expand Up @@ -537,18 +537,20 @@ project
│ ├── project
│ │ ├── columns: col1:27(bool)
│ │ ├── immutable
│ │ ├── stats: [rows=333333.333, distinct(27)=333333.333, null(27)=0]
│ │ ├── inner-join (cross)
│ │ ├── stats: [rows=10000, distinct(27)=10000, null(27)=0]
│ │ ├── inner-join (hash)
│ │ │ ├── columns: tab0.e:5(varchar) tab0.f:6("char") tab0.h:8(varchar) tab0.j:10(float!null) tab1.e:17(varchar) tab1.f:18("char") tab1.j:22(float!null)
│ │ │ ├── stats: [rows=333333.333, distinct(5,6,8,17,18)=333333.333, null(5,6,8,17,18)=3.33333333e-05]
│ │ │ ├── multiplicity: left-rows(one-or-more), right-rows(one-or-more)
│ │ │ ├── stats: [rows=10000, distinct(10)=100, null(10)=0, distinct(22)=100, null(22)=0, distinct(5,6,8,17,18)=10000, null(5,6,8,17,18)=1e-06]
│ │ │ ├── fd: (10)==(22), (22)==(10)
│ │ │ ├── scan t37953 [as=tab0]
│ │ │ │ ├── columns: tab0.e:5(varchar) tab0.f:6("char") tab0.h:8(varchar) tab0.j:10(float!null)
│ │ │ │ └── stats: [rows=1000, distinct(5,6,8)=1000, null(5,6,8)=0.001]
│ │ │ │ └── stats: [rows=1000, distinct(10)=100, null(10)=0, distinct(5,6,8)=1000, null(5,6,8)=0.001]
│ │ │ ├── scan t37953 [as=tab1]
│ │ │ │ ├── columns: tab1.e:17(varchar) tab1.f:18("char") tab1.j:22(float!null)
│ │ │ │ └── stats: [rows=1000, distinct(17,18)=1000, null(17,18)=0.1]
│ │ │ │ └── stats: [rows=1000, distinct(22)=100, null(22)=0, distinct(17,18)=1000, null(17,18)=0.1]
│ │ │ └── filters
│ │ │ └── tab0.j:10 IN (tab1.j:22,) [type=bool, outer=(10,22)]
│ │ │ └── tab0.j:10 = tab1.j:22 [type=bool, outer=(10,22), constraints=(/10: (/NULL - ]; /22: (/NULL - ]), fd=(10)==(22), (22)==(10)]
│ │ └── projections
│ │ └── CASE WHEN ilike_escape(regexp_replace(tab0.h:8, tab1.e:17, tab0.f:6, tab0.e:5::STRING), tab1.f:18, '') THEN true ELSE false END [as=col1:27, type=bool, outer=(5,6,8,17,18), immutable]
│ └── filters
Expand Down
10 changes: 10 additions & 0 deletions pkg/sql/opt/norm/rules/scalar.opt
Original file line number Diff line number Diff line change
Expand Up @@ -86,6 +86,16 @@ $input
=>
(Null (BoolType))

[SimplifyInSingleElement, Normalize]
(In $left:* (Tuple [ $right:* ]))
=>
(Eq $left $right)

[SimplifyNotInSingleElement, Normalize]
(NotIn $left:* (Tuple [ $right:* ]))
=>
(Ne $left $right)

# UnifyComparisonTypes takes a mixed-type comparison between a non-constant and
# a constant and, if appropriate, converts the constant to the type of the
# non-constant to allow constraints to be generated.
Expand Down
3 changes: 2 additions & 1 deletion pkg/sql/opt/norm/testdata/rules/assign_placeholders
Original file line number Diff line number Diff line change
Expand Up @@ -58,7 +58,8 @@ select
│ ├── key: (1-3)
│ └── fd: (1-3)-->(4)
└── filters
└── (a:1, b:2) IN ((1, 2),) [outer=(1,2), constraints=(/1/2: [/1/2 - /1/2]; /2: [/2 - /2]; tight), fd=()-->(1,2)]
├── a:1 = 1 [outer=(1), constraints=(/1: [/1 - /1]; tight), fd=()-->(1)]
└── b:2 = 2 [outer=(2), constraints=(/2: [/2 - /2]; tight), fd=()-->(2)]

# The normalized expression above can be explored into a constrained scan.
opt
Expand Down
107 changes: 106 additions & 1 deletion pkg/sql/opt/norm/testdata/rules/scalar
Original file line number Diff line number Diff line change
Expand Up @@ -239,7 +239,7 @@ project
├── scan a
│ └── columns: s:4
└── projections
└── s:4 NOT IN ('foo',) [as=r:7, outer=(4)]
└── s:4 != 'foo' [as=r:7, outer=(4)]

# Don't sort, since the list is not constant.
norm expect-not=NormalizeInConst
Expand Down Expand Up @@ -275,6 +275,111 @@ values
├── fd: ()-->(1)
└── (true IN (NULL, NULL, ('201.249.149.90/18' & '97a7:3650:3dd8:d4e9:35fe:6cfb:a714:1c17/61') << 'e22f:2067:2ed2:7b07:b167:206f:f17b:5b7d/82'),)

# --------------------------------------------------
# SimplifyInSingleElement
# --------------------------------------------------
norm expect=SimplifyInSingleElement
SELECT * FROM a WHERE k IN (1)
----
select
├── columns: k:1!null i:2 f:3 s:4 arr:5
├── cardinality: [0 - 1]
├── key: ()
├── fd: ()-->(1-5)
├── scan a
│ ├── columns: k:1!null i:2 f:3 s:4 arr:5
│ ├── key: (1)
│ └── fd: (1)-->(2-5)
└── filters
└── k:1 = 1 [outer=(1), constraints=(/1: [/1 - /1]; tight), fd=()-->(1)]

norm expect=SimplifyInSingleElement
SELECT 1 IN (k) FROM a
----
project
├── columns: "?column?":7!null
├── scan a
│ ├── columns: k:1!null
│ └── key: (1)
└── projections
└── k:1 = 1 [as="?column?":7, outer=(1)]

norm expect=SimplifyInSingleElement
SELECT k+1 IN (i*2) FROM a
----
project
├── columns: "?column?":7
├── immutable
├── scan a
│ ├── columns: k:1!null i:2
│ ├── key: (1)
│ └── fd: (1)-->(2)
└── projections
└── (k:1 + 1) = (i:2 * 2) [as="?column?":7, outer=(1,2), immutable]

norm expect-not=SimplifyInSingleElement
SELECT k IN (1,2) FROM a
----
project
├── columns: "?column?":7!null
├── scan a
│ ├── columns: k:1!null
│ └── key: (1)
└── projections
└── k:1 IN (1, 2) [as="?column?":7, outer=(1)]

# --------------------------------------------------
# SimplifyNotInSingleElement
# --------------------------------------------------
norm expect=SimplifyNotInSingleElement
SELECT * FROM a WHERE k NOT IN (1)
----
select
├── columns: k:1!null i:2 f:3 s:4 arr:5
├── key: (1)
├── fd: (1)-->(2-5)
├── scan a
│ ├── columns: k:1!null i:2 f:3 s:4 arr:5
│ ├── key: (1)
│ └── fd: (1)-->(2-5)
└── filters
└── k:1 != 1 [outer=(1), constraints=(/1: (/NULL - /0] [/2 - ]; tight)]

norm expect=SimplifyNotInSingleElement
SELECT 1 NOT IN (k) FROM a
----
project
├── columns: "?column?":7!null
├── scan a
│ ├── columns: k:1!null
│ └── key: (1)
└── projections
└── k:1 != 1 [as="?column?":7, outer=(1)]

norm expect=SimplifyNotInSingleElement
SELECT k+1 NOT IN (i*2) FROM a
----
project
├── columns: "?column?":7
├── immutable
├── scan a
│ ├── columns: k:1!null i:2
│ ├── key: (1)
│ └── fd: (1)-->(2)
└── projections
└── (k:1 + 1) != (i:2 * 2) [as="?column?":7, outer=(1,2), immutable]

norm expect-not=SimplifyNotInSingleElement
SELECT k NOT IN (1,2) FROM a
----
project
├── columns: "?column?":7!null
├── scan a
│ ├── columns: k:1!null
│ └── key: (1)
└── projections
└── k:1 NOT IN (1, 2) [as="?column?":7, outer=(1)]

# --------------------------------------------------
# EliminateExistsZeroRows
# --------------------------------------------------
Expand Down
4 changes: 2 additions & 2 deletions pkg/sql/opt/partialidx/testdata/implicator/or-expr
Original file line number Diff line number Diff line change
Expand Up @@ -55,7 +55,7 @@ a IN (1)
a = 1 OR a = 2
----
true
└── remaining filters: a IN (1,)
└── remaining filters: a = 1

predtest vars=(a int)
a IN (1, 2, 3)
Expand Down Expand Up @@ -146,7 +146,7 @@ a IN (1) OR a IN (2)
a = 1 OR a = 2
----
true
└── remaining filters: (a IN (1,)) OR (a IN (2,))
└── remaining filters: none

predtest vars=(a int, b int)
a IN (1, 2)
Expand Down

0 comments on commit 4c6e54e

Please sign in to comment.