Skip to content

Commit

Permalink
opt: add cost for table descriptor fetch during virtual scan
Browse files Browse the repository at this point in the history
This commit adds a cost equal to 10*randIOCostFactor for each virtual
scan in order to represent the cost of fetching table descriptors.
This cost is especially important when perfoming lookup joins, because
the descriptors may need to be fetched on each lookup. As a result of
this change, the optimizer is much less likely to plan a lookup join
into a virtual table.

This commit also includes some fixes to the test catalog to provide
better support for testing virtual tables with indexes.

Fixes cockroachdb#55140

Release note (performance improvement): Adjusted the cost model in
the optimizer so that the optimizer is less likely to plan a lookup
join into a virtual table. Performing a lookup join into a virtual
table is expensive, so this change will generally result in better
performance for queries involving joins with virtual tables.
  • Loading branch information
rytaft committed Nov 6, 2020
1 parent 4384efb commit 387bb51
Show file tree
Hide file tree
Showing 6 changed files with 358 additions and 90 deletions.
8 changes: 4 additions & 4 deletions pkg/sql/logictest/testdata/logic_test/orms
Original file line number Diff line number Diff line change
Expand Up @@ -250,17 +250,17 @@ a 57 true false false

# Hibernate query.

query TTTOBIIITTOT
query TTTOBIIITTOT rowsort
SELECT * FROM (SELECT n.nspname, c.relname, a.attname, a.atttypid, a.attnotnull OR ((t.typtype = 'd') AND t.typnotnull) AS attnotnull, a.atttypmod, a.attlen, row_number() OVER (PARTITION BY a.attrelid ORDER BY a.attnum) AS attnum, pg_get_expr(def.adbin, def.adrelid) AS adsrc, dsc.description, t.typbasetype, t.typtype FROM pg_catalog.pg_namespace AS n JOIN pg_catalog.pg_class AS c ON (c.relnamespace = n.oid) JOIN pg_catalog.pg_attribute AS a ON (a.attrelid = c.oid) JOIN pg_catalog.pg_type AS t ON (a.atttypid = t.oid) LEFT JOIN pg_catalog.pg_attrdef AS def ON ((a.attrelid = def.adrelid) AND (a.attnum = def.adnum)) LEFT JOIN pg_catalog.pg_description AS dsc ON ((c.oid = dsc.objoid) AND (a.attnum = dsc.objsubid)) LEFT JOIN pg_catalog.pg_class AS dc ON ((dc.oid = dsc.classoid) AND (dc.relname = 'pg_class')) LEFT JOIN pg_catalog.pg_namespace AS dn ON ((dc.relnamespace = dn.oid) AND (dn.nspname = 'pg_catalog')) WHERE (((c.relkind IN ('r', 'v', 'f', 'm')) AND (a.attnum > 0)) AND (NOT a.attisdropped)) AND (n.nspname LIKE 'public')) AS c;
----
public a id 20 false -1 8 1 NULL NULL 0 b
public a name 25 false -1 -1 2 NULL NULL 0 b
public a rowid 20 true -1 8 3 unique_rowid() NULL 0 b
public customers name 25 true -1 -1 1 NULL NULL 0 b
public a name 25 false -1 -1 2 NULL NULL 0 b
public customers id 20 false -1 8 2 NULL NULL 0 b
public customers name 25 true -1 -1 1 NULL NULL 0 b
public b rowid 20 true -1 8 3 unique_rowid() NULL 0 b
public b id 20 false -1 8 1 NULL NULL 0 b
public b a_id 20 false -1 8 2 NULL NULL 0 b
public b rowid 20 true -1 8 3 unique_rowid() NULL 0 b
public c a 20 true -1 8 1 NULL NULL 0 b
public c b 20 true -1 8 2 NULL NULL 0 b
public metatest a 20 true -1 8 1 NULL NULL 0 b
Expand Down
41 changes: 38 additions & 3 deletions pkg/sql/opt/testutils/testcat/create_table.go
Original file line number Diff line number Diff line change
Expand Up @@ -57,9 +57,11 @@ func (tc *Catalog) CreateTable(stmt *tree.CreateTable) *Table {
// Update the table name to include catalog and schema if not provided.
tc.qualifyTableName(&stmt.Table)

// Assume that every table in the "system" or "information_schema" catalog
// is a virtual table. This is a simplified assumption for testing purposes.
if stmt.Table.CatalogName == "system" || stmt.Table.SchemaName == "information_schema" {
// Assume that every table in the "system", "information_schema" or
// "pg_catalog" catalog is a virtual table. This is a simplified assumption
// for testing purposes.
if stmt.Table.CatalogName == "system" || stmt.Table.SchemaName == "information_schema" ||
stmt.Table.SchemaName == "pg_catalog" {
return tc.createVirtualTable(stmt)
}

Expand Down Expand Up @@ -274,6 +276,18 @@ func (tc *Catalog) createVirtualTable(stmt *tree.CreateTable) *Table {
}

tab.addPrimaryColumnIndex(string(tab.Columns[0].ColName()))

// Search for index definitions.
for _, def := range stmt.Defs {
switch def := def.(type) {
case *tree.IndexTableDef:
tab.addIndex(def, nonUniqueIndex)
}
}

// Add the new table to the catalog.
tc.AddTable(tab)

return tab
}

Expand Down Expand Up @@ -620,6 +634,27 @@ func (tt *Table) addIndex(def *tree.IndexTableDef, typ indexType) *Index {
idx.addColumn(tt, string(name), tree.Ascending, nonKeyCol)
}
}
if tt.IsVirtual {
// All indexes of virtual tables automatically STORE all other columns in
// the table.
idxCols := idx.Columns
for _, col := range tt.Columns {
found := false
for _, idxCol := range idxCols {
if col.ColName() == idxCol.ColName() {
found = true
break
}
}
if !found {
elem := tree.IndexElem{
Column: col.ColName(),
Direction: tree.Ascending,
}
idx.addColumn(tt, elem, nonKeyCol, false /* isLastIndexCol */)
}
}
}

// Add partial index predicate.
if def.Predicate != nil {
Expand Down
14 changes: 14 additions & 0 deletions pkg/sql/opt/xform/coster.go
Original file line number Diff line number Diff line change
Expand Up @@ -108,6 +108,10 @@ const (
// justification for this constant.
lookupJoinRetrieveRowCost = 2 * seqIOCostFactor

// virtualScanTableDescriptorFetchCost is the cost to retrieve the table
// descriptors when performing a virtual table scan.
virtualScanTableDescriptorFetchCost = 10 * randIOCostFactor

// Input rows to a join are processed in batches of this size.
// See joinreader.go.
joinReaderBatchSize = 100.0
Expand Down Expand Up @@ -579,6 +583,11 @@ func (c *coster) computeScanCost(scan *memo.ScanExpr, required *physical.Require
}
baseCost := memo.Cost(numSpans * randIOCostFactor)

// If this is a virtual scan, add the cost of fetching table descriptors.
if c.mem.Metadata().Table(scan.Table).IsVirtualTable() {
baseCost += virtualScanTableDescriptorFetchCost
}

// Add a small cost if the scan is unconstrained, so all else being equal, we
// will prefer a constrained scan. This is important if our row count
// estimate turns out to be smaller than the actual row count.
Expand Down Expand Up @@ -750,6 +759,11 @@ func (c *coster) computeLookupJoinCost(
// slower.
perLookupCost *= 5
}
if c.mem.Metadata().Table(table).IsVirtualTable() {
// It's expensive to perform a lookup join into a virtual table because
// we need to fetch the table descriptors on each lookup.
perLookupCost += virtualScanTableDescriptorFetchCost
}
cost := memo.Cost(lookupCount) * perLookupCost

filterSetup, filterPerRow := c.computeFiltersCost(join.On, util.FastIntMap{})
Expand Down
87 changes: 87 additions & 0 deletions pkg/sql/opt/xform/testdata/coster/join
Original file line number Diff line number Diff line change
Expand Up @@ -838,3 +838,90 @@ insert c
│ ├── key: ()
│ └── fd: ()-->(6)
└── filters (true)

# Avoid performing a lookup join with virtual tables if the filter is
# not extremely selective.

opt
SELECT
a.attname,
a.atttypid,
t.typbasetype,
t.typtype
FROM
pg_catalog.pg_attribute AS a
JOIN pg_catalog.pg_type AS t ON (a.atttypid = t.oid)
WHERE
a.attname IN ('descriptor_id', 'descriptor_name')
----
project
├── columns: attname:3!null atttypid:4!null typbasetype:50 typtype:32
├── stats: [rows=198]
├── cost: 2724.37877
└── inner-join (merge)
├── columns: attname:3!null atttypid:4!null oid:26!null typtype:32 typbasetype:50
├── left ordering: +26
├── right ordering: +4
├── stats: [rows=198, distinct(4)=17.2927193, null(4)=0, distinct(26)=17.2927193, null(26)=0]
├── cost: 2722.38877
├── fd: (4)==(26), (26)==(4)
├── scan t@secondary
│ ├── columns: oid:26!null typtype:32 typbasetype:50
│ ├── stats: [rows=1000, distinct(26)=100, null(26)=0]
│ ├── cost: 1394.02
│ └── ordering: +26
├── sort
│ ├── columns: attname:3!null atttypid:4
│ ├── stats: [rows=20, distinct(3)=2, null(3)=0, distinct(4)=18.2927193, null(4)=0.2]
│ ├── cost: 1316.17877
│ ├── ordering: +4
│ └── select
│ ├── columns: attname:3!null atttypid:4
│ ├── stats: [rows=20, distinct(3)=2, null(3)=0, distinct(4)=18.2927193, null(4)=0.2]
│ ├── cost: 1314.04
│ ├── scan a
│ │ ├── columns: attname:3 atttypid:4
│ │ ├── stats: [rows=1000, distinct(3)=100, null(3)=10, distinct(4)=100, null(4)=10]
│ │ └── cost: 1304.02
│ └── filters
│ └── attname:3 IN ('descriptor_id', 'descriptor_name') [outer=(3), constraints=(/3: [/'descriptor_id' - /'descriptor_id'] [/'descriptor_name' - /'descriptor_name']; tight)]
└── filters (true)


# A lookup join should be performed with a virtual table if the filter
# is very selective.
opt
SELECT
a.attname,
a.atttypid,
t.typbasetype,
t.typtype
FROM
pg_catalog.pg_attribute AS a
JOIN pg_catalog.pg_type AS t ON (a.atttypid = t.oid)
WHERE
a.attname = 'descriptor_id'
----
project
├── columns: attname:3!null atttypid:4!null typbasetype:50 typtype:32
├── stats: [rows=99]
├── cost: 2148.69
├── fd: ()-->(3)
└── inner-join (lookup pg_type@secondary)
├── columns: attname:3!null atttypid:4!null oid:26!null typtype:32 typbasetype:50
├── key columns: [4] = [26]
├── stats: [rows=99, distinct(4)=8.5617925, null(4)=0, distinct(26)=8.5617925, null(26)=0]
├── cost: 2147.69
├── fd: ()-->(3), (4)==(26), (26)==(4)
├── select
│ ├── columns: attname:3!null atttypid:4
│ ├── stats: [rows=10, distinct(3)=1, null(3)=0, distinct(4)=9.5617925, null(4)=0.1]
│ ├── cost: 1314.04
│ ├── fd: ()-->(3)
│ ├── scan a
│ │ ├── columns: attname:3 atttypid:4
│ │ ├── stats: [rows=1000, distinct(3)=100, null(3)=10, distinct(4)=100, null(4)=10]
│ │ └── cost: 1304.02
│ └── filters
│ └── attname:3 = 'descriptor_id' [outer=(3), constraints=(/3: [/'descriptor_id' - /'descriptor_id']; tight), fd=()-->(3)]
└── filters (true)
4 changes: 2 additions & 2 deletions pkg/sql/opt/xform/testdata/coster/virtual-scan
Original file line number Diff line number Diff line change
Expand Up @@ -4,11 +4,11 @@ SELECT * FROM information_schema.schemata WHERE SCHEMA_NAME='public'
select
├── columns: catalog_name:2!null schema_name:3!null default_character_set_name:4 sql_path:5 crdb_is_user_defined:6
├── stats: [rows=10, distinct(3)=1, null(3)=0]
├── cost: 1124.04
├── cost: 1164.04
├── fd: ()-->(3)
├── scan information_schema.schemata
│ ├── columns: catalog_name:2!null schema_name:3!null default_character_set_name:4 sql_path:5 crdb_is_user_defined:6
│ ├── stats: [rows=1000, distinct(2)=100, null(2)=0, distinct(3)=100, null(3)=0]
│ └── cost: 1114.02
│ └── cost: 1154.02
└── filters
└── schema_name:3 = 'public' [outer=(3), constraints=(/3: [/'public' - /'public']; tight), fd=()-->(3)]
Loading

0 comments on commit 387bb51

Please sign in to comment.