Skip to content

Commit

Permalink
opt: make lookup join more expensive
Browse files Browse the repository at this point in the history
This change adds a constant factor to the cost of fetching a row for a
lookup join scan. This constant was picked somewhat arbitrarily and can
be made more principled going forward.

This change was motivated by this query:

```
SELECT count(*) FROM lineitem JOIN supplier ON l_suppkey = s_suppkey
```

This query runs an approximately 1:600 join, supplier having around
10,000 rows and lineitem having around 6,000,000.

Previously a lookup-join was chosen. After this change, a merge-join is
chosen, which is roughly 2x as fast.

Run locally, the times for each join strategy are (recall `INNER HASH
JOIN` and `INNER LOOKUP JOIN` are not commutative):

```
SELECT count(*) FROM lineitem INNER HASH JOIN supplier ON l_suppkey = s_suppkey

  => 4.67s
  => cost: 6,446,371

SELECT count(*) FROM supplier INNER HASH JOIN lineitem ON l_suppkey = s_suppkey

  => 4.48s
  => cost: 6,476,327

SELECT count(*) FROM lineitem INNER MERGE JOIN supplier ON l_suppkey = s_suppkey

  => 3.68s
  => cost: 6,431,793

SELECT count(*) FROM lineitem INNER LOOKUP JOIN supplier ON l_suppkey = s_suppkey

  => 10.16s
  => old cost: 36,765,282
  => new cost: 42,746,162

SELECT count(*) FROM supplier INNER LOOKUP JOIN lineitem ON l_suppkey = s_suppkey

  => 6.53s
  => old cost:  6,330,224
  => new cost: 12,311,104
```

This was validated experimentally by running the following three
parameterized queries via exprgen:

Merge Join
----------

```
(MergeJoin
  (Scan
	[
	  (Table "lineitem")
	  (Cols "l_suppkey")
	  (Index "lineitem@l_sk")
	  (HardLimit $lineitem_rows)
	]
  )
  (Scan
	[
	  (Table "supplier")
	  (Cols "s_suppkey")
	  (HardLimit $supplier_rows)
	]
  )
  [ ]
  [
	(JoinType "inner-join")
	(LeftEq "+l_suppkey")
	(RightEq "+s_suppkey")
	(LeftOrdering "+l_suppkey")
	(RightOrdering "+s_suppkey")
  ]
)
```

Hash Join
---------

```
(InnerJoin
  (Scan
    [
      (Table "supplier")
      (Cols "s_suppkey")
      (Index "supplier@s_nk")
      (HardLimit $supplier_rows)
    ]
  )
  (Scan
    [
      (Table "lineitem")
      (Cols "l_suppkey")
      (Index "lineitem@l_sk")
      (HardLimit $lineitem_rows)
    ]
  )
  [
    (Eq (Var "l_suppkey") (Var "s_suppkey"))
  ]
  [ ]
)
```

Lookup Join
-----------

```
(MakeLookupJoin
  (Scan
    [
      (Table "supplier")
      (Index "supplier@s_nk")
      (Cols "s_suppkey")
      (HardLimit $supplier_rows)
    ]
  )
  [
    (JoinType "inner-join")
    (Table "lineitem")
    (Index "lineitem@l_sk")
    (KeyCols "s_suppkey")
    (Cols "l_suppkey")
  ]
  [ ]
)
```

Release note (sql change): the cost-based optimizer will now pick
lookup-joins less frequently.
  • Loading branch information
Justin Jaffray committed Mar 12, 2019
1 parent 6be06f2 commit 97ad0e9
Show file tree
Hide file tree
Showing 12 changed files with 123 additions and 77 deletions.
4 changes: 2 additions & 2 deletions pkg/sql/opt/norm/testdata/rules/combo
Original file line number Diff line number Diff line change
Expand Up @@ -376,7 +376,7 @@ GenerateMergeJoins
+ └── filters (true)
================================================================================
GenerateLookupJoins
Cost: 1139.94
Cost: 1149.84
================================================================================
project
├── columns: s:4(string)
Expand Down Expand Up @@ -417,7 +417,7 @@ GenerateLookupJoinsWithFilter (no changes)
--------------------------------------------------------------------------------
================================================================================
Final best expression
Cost: 1139.94
Cost: 1149.84
================================================================================
project
├── columns: s:4(string)
Expand Down
2 changes: 1 addition & 1 deletion pkg/sql/opt/optgen/exprgen/testdata/join
Original file line number Diff line number Diff line change
Expand Up @@ -66,7 +66,7 @@ left-join (lookup abc@ab)
├── columns: t.public.abc.a:5(int) t.public.abc.b:6(int)
├── key columns: [5] = [5]
├── stats: [rows=333333.333]
├── cost: 358393.353
├── cost: 691726.687
├── scan t.public.def
│ ├── columns: t.public.def.d:1(int) t.public.def.e:2(int)
│ ├── stats: [rows=1000]
Expand Down
10 changes: 9 additions & 1 deletion pkg/sql/opt/xform/coster.go
Original file line number Diff line number Diff line change
Expand Up @@ -102,6 +102,13 @@ const (
seqIOCostFactor = 1
randIOCostFactor = 4

// TODO(justin): make this more sophisticated.
// lookupJoinRetrieveRowCost is the cost to retrieve a single row during a
// lookup join.
// See https://github.com/cockroachdb/cockroach/pull/35561 for the initial
// justification for this constant.
lookupJoinRetrieveRowCost = 2 * seqIOCostFactor

// latencyCostFactor represents the throughput impact of doing scans on an
// index that may be remotely located in a different locality. If latencies
// are higher, then overall cluster throughput will suffer somewhat, as there
Expand Down Expand Up @@ -362,7 +369,8 @@ func (c *coster) computeLookupJoinCost(join *memo.LookupJoinExpr) memo.Cost {
// rows (relevant when we expect many resulting rows per lookup) and the CPU
// cost of emitting the rows.
numLookupCols := join.Cols.Difference(join.Input.Relational().OutputCols).Len()
perRowCost := seqIOCostFactor + c.rowScanCost(join.Table, join.Index, numLookupCols)
perRowCost := lookupJoinRetrieveRowCost +
c.rowScanCost(join.Table, join.Index, numLookupCols)

// Add a cost if we have to evaluate an ON condition on every row. The more
// leftover conditions, the more expensive it should be. We want to
Expand Down
30 changes: 19 additions & 11 deletions pkg/sql/opt/xform/testdata/coster/join
Original file line number Diff line number Diff line change
Expand Up @@ -92,7 +92,7 @@ inner-join (lookup a)
├── flags: no-merge-join;no-hash-join
├── key columns: [1] = [4]
├── stats: [rows=1000, distinct(1)=100, null(1)=0, distinct(4)=100, null(4)=0]
├── cost: 6090.02
├── cost: 7090.02
├── fd: (1)==(4), (4)==(1)
├── scan b
│ ├── columns: x:1(int)
Expand Down Expand Up @@ -283,7 +283,7 @@ project
├── columns: w:1(string!null) x:2(uuid!null) y:3(uuid!null) z:4(string!null) [hidden: d:8(string!null)]
├── cardinality: [0 - 10]
├── stats: [rows=10]
├── cost: 122481.301
├── cost: 164278.036
├── key: (8)
├── fd: ()-->(1,2), (3)-->(4,8), (8)-->(3,4)
├── ordering: +8 opt(1,2) [actual: +8]
Expand All @@ -292,22 +292,23 @@ project
├── internal-ordering: +8 opt(1,2,5,6)
├── cardinality: [0 - 10]
├── stats: [rows=10]
├── cost: 122481.191
├── cost: 164277.926
├── key: (7)
├── fd: ()-->(1,2,5,6), (3)-->(4), (7)-->(8), (8)-->(7), (1)==(5), (5)==(1), (2)==(6), (6)==(2), (3)==(7), (7)==(3)
├── ordering: +8 opt(1,2,5,6) [actual: +8]
├── sort
│ ├── columns: w:1(string!null) x:2(uuid!null) y:3(uuid!null) z:4(string!null) a:5(string!null) b:6(uuid!null) c:7(uuid!null) d:8(string!null)
│ ├── stats: [rows=50048.8759, distinct(1)=1, null(1)=0, distinct(2)=1, null(2)=0, distinct(3)=2500, null(3)=0, distinct(4)=1000, null(4)=0, distinct(5)=1, null(5)=0, distinct(6)=1, null(6)=0, distinct(7)=2500, null(7)=0, distinct(8)=38781.1698, null(8)=0]
│ ├── cost: 122481.081
│ ├── cost: 164277.816
│ ├── key: (7)
│ ├── fd: ()-->(1,2,5,6), (3)-->(4), (7)-->(8), (8)-->(7), (1)==(5), (5)==(1), (2)==(6), (6)==(2), (3)==(7), (7)==(3)
│ ├── ordering: +8 opt(1,2,5,6) [actual: +8]
│ └── inner-join (lookup abcde@idx_abcd)
│ └── inner-join (merge)
│ ├── columns: w:1(string!null) x:2(uuid!null) y:3(uuid!null) z:4(string!null) a:5(string!null) b:6(uuid!null) c:7(uuid!null) d:8(string!null)
│ ├── key columns: [1 2 3] = [5 6 7]
│ ├── left ordering: +1,+2,+3
│ ├── right ordering: +5,+6,+7
│ ├── stats: [rows=50048.8759, distinct(1)=1, null(1)=0, distinct(2)=1, null(2)=0, distinct(3)=2500, null(3)=0, distinct(4)=1000, null(4)=0, distinct(5)=1, null(5)=0, distinct(6)=1, null(6)=0, distinct(7)=2500, null(7)=0, distinct(8)=38781.1698, null(8)=0]
│ ├── cost: 105853.783
│ ├── cost: 147650.519
│ ├── key: (7)
│ ├── fd: ()-->(1,2,5,6), (3)-->(4), (7)-->(8), (8)-->(7), (1)==(5), (5)==(1), (2)==(6), (6)==(2), (3)==(7), (7)==(3)
│ ├── scan wxyz
Expand All @@ -316,8 +317,15 @@ project
│ │ ├── stats: [rows=10000, distinct(1)=1, null(1)=0, distinct(2)=1, null(2)=0, distinct(3)=2500, null(3)=0, distinct(4)=1000, null(4)=0]
│ │ ├── cost: 10800.01
│ │ ├── key: (3)
│ │ └── fd: ()-->(1,2), (3)-->(4)
│ └── filters
│ ├── a = 'foo' [type=bool, outer=(5), constraints=(/5: [/'foo' - /'foo']; tight), fd=()-->(5)]
│ └── b = '2ab23800-06b1-4e19-a3bb-df3768b808d2' [type=bool, outer=(6), constraints=(/6: [/'2ab23800-06b1-4e19-a3bb-df3768b808d2' - /'2ab23800-06b1-4e19-a3bb-df3768b808d2']; tight), fd=()-->(6)]
│ │ ├── fd: ()-->(1,2), (3)-->(4)
│ │ └── ordering: +3 opt(1,2) [actual: +3]
│ ├── scan abcde@idx_abcd
│ │ ├── columns: a:5(string!null) b:6(uuid!null) c:7(uuid!null) d:8(string!null)
│ │ ├── constraint: /5/6/7/8: [/'foo'/'2ab23800-06b1-4e19-a3bb-df3768b808d2' - /'foo'/'2ab23800-06b1-4e19-a3bb-df3768b808d2']
│ │ ├── stats: [rows=125000, distinct(5)=1, null(5)=0, distinct(6)=1, null(6)=0, distinct(7)=24975.5859, null(7)=0, distinct(8)=93750, null(8)=0]
│ │ ├── cost: 135000.01
│ │ ├── key: (7)
│ │ ├── fd: ()-->(5,6), (7)-->(8), (8)-->(7)
│ │ └── ordering: +7 opt(5,6) [actual: +7]
│ └── filters (true)
└── const: 10 [type=int]
4 changes: 2 additions & 2 deletions pkg/sql/opt/xform/testdata/coster/zone
Original file line number Diff line number Diff line change
Expand Up @@ -317,7 +317,7 @@ inner-join (lookup xy@y2)
├── flags: no-merge-join;no-hash-join
├── key columns: [2] = [5]
├── stats: [rows=98.01, distinct(1)=9.9, null(1)=0, distinct(2)=1, null(2)=0, distinct(4)=9.9, null(4)=0, distinct(5)=1, null(5)=0]
├── cost: 153.0245
├── cost: 251.0345
├── key: (1,4)
├── fd: ()-->(2,5), (1)-->(3), (2,3)~~>(1), (2)==(5), (5)==(2)
├── prune: (1,3,4)
Expand Down Expand Up @@ -359,7 +359,7 @@ inner-join (lookup xy@y1)
├── flags: no-merge-join;no-hash-join
├── key columns: [2] = [5]
├── stats: [rows=98.01, distinct(1)=9.9, null(1)=0, distinct(2)=1, null(2)=0, distinct(4)=9.9, null(4)=0, distinct(5)=1, null(5)=0]
├── cost: 153.0245
├── cost: 251.0345
├── key: (1,4)
├── fd: ()-->(2,5), (1)-->(3), (2,3)~~>(1), (2)==(5), (5)==(2)
├── prune: (1,3,4)
Expand Down
10 changes: 7 additions & 3 deletions pkg/sql/opt/xform/testdata/external/liquibase
Original file line number Diff line number Diff line change
Expand Up @@ -301,10 +301,13 @@ project
│ │ │ │ ├── columns: c.oid:1(oid!null) c.relname:2(string!null) c.relnamespace:3(oid!null) c.relowner:5(oid!null) c.reltablespace:8(oid!null) c.reltuples:10(float!null) c.relhasindex:13(bool!null) c.relpersistence:15(string!null) c.relkind:17(string!null) c.relhasoids:20(bool!null) c.relhasrules:22(bool!null) c.relhastriggers:23(bool!null) c.relacl:26(string[]) c.reloptions:27(string[]) n.oid:28(oid!null) n.nspname:29(string!null) t.oid:32(oid) spcname:33(string) i.inhrelid:38(oid) i.inhparent:39(oid) c2.oid:41(oid) c2.relname:42(string) c2.relnamespace:43(oid) n2.oid:68(oid) n2.nspname:69(string) indexrelid:72(oid) indrelid:73(oid) indisclustered:79(bool) ci.oid:91(oid) ci.relname:92(string) ftrelid:118(oid) ftserver:119(oid) ftoptions:120(string[])
│ │ │ │ ├── key columns: [1] = [118]
│ │ │ │ ├── fd: ()-->(3,28,29), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(28), (28)==(3), (32)-->(33), (33)-->(32), (41)-->(42,43), (42,43)-->(41), (39)==(41), (41)==(39), (68)~~>(69), (69)~~>(68), (72)-->(73), ()~~>(79), (91)-->(92), (118)-->(119,120)
│ │ │ │ ├── left-join (lookup pg_class)
│ │ │ │ ├── right-join
│ │ │ │ │ ├── columns: c.oid:1(oid!null) c.relname:2(string!null) c.relnamespace:3(oid!null) c.relowner:5(oid!null) c.reltablespace:8(oid!null) c.reltuples:10(float!null) c.relhasindex:13(bool!null) c.relpersistence:15(string!null) c.relkind:17(string!null) c.relhasoids:20(bool!null) c.relhasrules:22(bool!null) c.relhastriggers:23(bool!null) c.relacl:26(string[]) c.reloptions:27(string[]) n.oid:28(oid!null) n.nspname:29(string!null) t.oid:32(oid) spcname:33(string) i.inhrelid:38(oid) i.inhparent:39(oid) c2.oid:41(oid) c2.relname:42(string) c2.relnamespace:43(oid) n2.oid:68(oid) n2.nspname:69(string) indexrelid:72(oid) indrelid:73(oid) indisclustered:79(bool) ci.oid:91(oid) ci.relname:92(string)
│ │ │ │ │ ├── key columns: [72] = [91]
│ │ │ │ │ ├── fd: ()-->(3,28,29), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(28), (28)==(3), (32)-->(33), (33)-->(32), (41)-->(42,43), (42,43)-->(41), (39)==(41), (41)==(39), (68)~~>(69), (69)~~>(68), (72)-->(73), ()~~>(79), (91)-->(92)
│ │ │ │ │ ├── scan ci@pg_class_relname_nsp_index
│ │ │ │ │ │ ├── columns: i.inhrelid:38(oid) i.inhparent:39(oid) c2.oid:41(oid) c2.relname:42(string) c2.relnamespace:43(oid) n2.oid:68(oid) n2.nspname:69(string) indexrelid:72(oid) indrelid:73(oid) indisclustered:79(bool) ci.oid:91(oid!null) ci.relname:92(string!null)
│ │ │ │ │ │ ├── key: (91)
│ │ │ │ │ │ └── fd: (91)-->(92)
│ │ │ │ │ ├── right-join
│ │ │ │ │ │ ├── columns: c.oid:1(oid!null) c.relname:2(string!null) c.relnamespace:3(oid!null) c.relowner:5(oid!null) c.reltablespace:8(oid!null) c.reltuples:10(float!null) c.relhasindex:13(bool!null) c.relpersistence:15(string!null) c.relkind:17(string!null) c.relhasoids:20(bool!null) c.relhasrules:22(bool!null) c.relhastriggers:23(bool!null) c.relacl:26(string[]) c.reloptions:27(string[]) n.oid:28(oid!null) n.nspname:29(string!null) t.oid:32(oid) spcname:33(string) i.inhrelid:38(oid) i.inhparent:39(oid) c2.oid:41(oid) c2.relname:42(string) c2.relnamespace:43(oid) n2.oid:68(oid) n2.nspname:69(string) indexrelid:72(oid) indrelid:73(oid) indisclustered:79(bool)
│ │ │ │ │ │ ├── fd: ()-->(3,28,29), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(28), (28)==(3), (32)-->(33), (33)-->(32), (41)-->(42,43), (42,43)-->(41), (39)==(41), (41)==(39), (68)~~>(69), (69)~~>(68), (72)-->(73), ()~~>(79)
Expand Down Expand Up @@ -373,7 +376,8 @@ project
│ │ │ │ │ │ │ └── i.inhrelid = c.oid [type=bool, outer=(1,38), constraints=(/1: (/NULL - ]; /38: (/NULL - ]), fd=(1)==(38), (38)==(1)]
│ │ │ │ │ │ └── filters
│ │ │ │ │ │ └── indrelid = c.oid [type=bool, outer=(1,73), constraints=(/1: (/NULL - ]; /73: (/NULL - ]), fd=(1)==(73), (73)==(1)]
│ │ │ │ │ └── filters (true)
│ │ │ │ │ └── filters
│ │ │ │ │ └── ci.oid = indexrelid [type=bool, outer=(72,91), constraints=(/72: (/NULL - ]; /91: (/NULL - ]), fd=(72)==(91), (91)==(72)]
│ │ │ │ └── filters (true)
│ │ │ └── filters (true)
│ │ └── filters
Expand Down
10 changes: 7 additions & 3 deletions pkg/sql/opt/xform/testdata/external/navicat
Original file line number Diff line number Diff line change
Expand Up @@ -304,10 +304,13 @@ sort
│ │ │ │ ├── columns: c.oid:1(oid!null) c.relname:2(string!null) c.relnamespace:3(oid!null) c.relowner:5(oid!null) c.reltablespace:8(oid!null) c.reltuples:10(float!null) c.relhasindex:13(bool!null) c.relpersistence:15(string!null) c.relkind:17(string!null) c.relhasoids:20(bool!null) c.relhasrules:22(bool!null) c.relhastriggers:23(bool!null) c.relacl:26(string[]) c.reloptions:27(string[]) n.oid:28(oid!null) n.nspname:29(string!null) t.oid:32(oid) spcname:33(string) i.inhrelid:38(oid) i.inhparent:39(oid) c2.oid:41(oid) c2.relname:42(string) c2.relnamespace:43(oid) n2.oid:68(oid) n2.nspname:69(string) indexrelid:72(oid) indrelid:73(oid) indisclustered:79(bool) ci.oid:91(oid) ci.relname:92(string) ftrelid:118(oid) ftserver:119(oid) ftoptions:120(string[])
│ │ │ │ ├── key columns: [1] = [118]
│ │ │ │ ├── fd: ()-->(3,28,29), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(28), (28)==(3), (32)-->(33), (33)-->(32), (41)-->(42,43), (42,43)-->(41), (39)==(41), (41)==(39), (68)~~>(69), (69)~~>(68), (72)-->(73), ()~~>(79), (91)-->(92), (118)-->(119,120)
│ │ │ │ ├── left-join (lookup pg_class)
│ │ │ │ ├── right-join
│ │ │ │ │ ├── columns: c.oid:1(oid!null) c.relname:2(string!null) c.relnamespace:3(oid!null) c.relowner:5(oid!null) c.reltablespace:8(oid!null) c.reltuples:10(float!null) c.relhasindex:13(bool!null) c.relpersistence:15(string!null) c.relkind:17(string!null) c.relhasoids:20(bool!null) c.relhasrules:22(bool!null) c.relhastriggers:23(bool!null) c.relacl:26(string[]) c.reloptions:27(string[]) n.oid:28(oid!null) n.nspname:29(string!null) t.oid:32(oid) spcname:33(string) i.inhrelid:38(oid) i.inhparent:39(oid) c2.oid:41(oid) c2.relname:42(string) c2.relnamespace:43(oid) n2.oid:68(oid) n2.nspname:69(string) indexrelid:72(oid) indrelid:73(oid) indisclustered:79(bool) ci.oid:91(oid) ci.relname:92(string)
│ │ │ │ │ ├── key columns: [72] = [91]
│ │ │ │ │ ├── fd: ()-->(3,28,29), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(28), (28)==(3), (32)-->(33), (33)-->(32), (41)-->(42,43), (42,43)-->(41), (39)==(41), (41)==(39), (68)~~>(69), (69)~~>(68), (72)-->(73), ()~~>(79), (91)-->(92)
│ │ │ │ │ ├── scan ci@pg_class_relname_nsp_index
│ │ │ │ │ │ ├── columns: i.inhrelid:38(oid) i.inhparent:39(oid) c2.oid:41(oid) c2.relname:42(string) c2.relnamespace:43(oid) n2.oid:68(oid) n2.nspname:69(string) indexrelid:72(oid) indrelid:73(oid) indisclustered:79(bool) ci.oid:91(oid!null) ci.relname:92(string!null)
│ │ │ │ │ │ ├── key: (91)
│ │ │ │ │ │ └── fd: (91)-->(92)
│ │ │ │ │ ├── right-join
│ │ │ │ │ │ ├── columns: c.oid:1(oid!null) c.relname:2(string!null) c.relnamespace:3(oid!null) c.relowner:5(oid!null) c.reltablespace:8(oid!null) c.reltuples:10(float!null) c.relhasindex:13(bool!null) c.relpersistence:15(string!null) c.relkind:17(string!null) c.relhasoids:20(bool!null) c.relhasrules:22(bool!null) c.relhastriggers:23(bool!null) c.relacl:26(string[]) c.reloptions:27(string[]) n.oid:28(oid!null) n.nspname:29(string!null) t.oid:32(oid) spcname:33(string) i.inhrelid:38(oid) i.inhparent:39(oid) c2.oid:41(oid) c2.relname:42(string) c2.relnamespace:43(oid) n2.oid:68(oid) n2.nspname:69(string) indexrelid:72(oid) indrelid:73(oid) indisclustered:79(bool)
│ │ │ │ │ │ ├── fd: ()-->(3,28,29), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(28), (28)==(3), (32)-->(33), (33)-->(32), (41)-->(42,43), (42,43)-->(41), (39)==(41), (41)==(39), (68)~~>(69), (69)~~>(68), (72)-->(73), ()~~>(79)
Expand Down Expand Up @@ -376,7 +379,8 @@ sort
│ │ │ │ │ │ │ └── i.inhrelid = c.oid [type=bool, outer=(1,38), constraints=(/1: (/NULL - ]; /38: (/NULL - ]), fd=(1)==(38), (38)==(1)]
│ │ │ │ │ │ └── filters
│ │ │ │ │ │ └── indrelid = c.oid [type=bool, outer=(1,73), constraints=(/1: (/NULL - ]; /73: (/NULL - ]), fd=(1)==(73), (73)==(1)]
│ │ │ │ │ └── filters (true)
│ │ │ │ │ └── filters
│ │ │ │ │ └── ci.oid = indexrelid [type=bool, outer=(72,91), constraints=(/72: (/NULL - ]; /91: (/NULL - ]), fd=(72)==(91), (91)==(72)]
│ │ │ │ └── filters (true)
│ │ │ └── filters (true)
│ │ └── filters
Expand Down
4 changes: 2 additions & 2 deletions pkg/sql/opt/xform/testdata/external/tpcc
Original file line number Diff line number Diff line change
Expand Up @@ -904,15 +904,15 @@ scalar-group-by
├── columns: count:28(int)
├── cardinality: [1 - 1]
├── stats: [rows=1]
├── cost: 1.84111111
├── cost: 2.84111111
├── key: ()
├── fd: ()-->(28)
├── prune: (28)
├── inner-join (lookup stock)
│ ├── columns: ol_o_id:1(int!null) ol_d_id:2(int!null) ol_w_id:3(int!null) ol_i_id:5(int!null) s_i_id:11(int!null) s_w_id:12(int!null) s_quantity:13(int!null)
│ ├── key columns: [3 5] = [12 11]
│ ├── stats: [rows=1, distinct(1)=0.11109736, null(1)=0, distinct(2)=0.111097416, null(2)=0, distinct(3)=0.111111111, null(3)=0, distinct(5)=0.111111056, null(5)=0, distinct(11)=0.111111056, null(11)=0, distinct(12)=0.111111111, null(12)=0, distinct(13)=1, null(13)=0]
│ ├── cost: 1.81111111
│ ├── cost: 2.81111111
│ ├── fd: ()-->(2,3,12), (11)-->(13), (5)==(11), (11)==(5), (3)==(12), (12)==(3)
│ ├── interesting orderings: (+3,+2,-1)
│ ├── scan order_line
Expand Down
Loading

0 comments on commit 97ad0e9

Please sign in to comment.