Skip to content

Commit

Permalink
sql: improve SHOW TABLES to show row count
Browse files Browse the repository at this point in the history
This change adds column "estimated_row_count" into result of the "SHOW TABLES"
to show estimated (not real) number of rows.

Besides that the body of the `delegator.delegateShowTables` was a bit
simplified (we do not need two almost similar versions of the query) and
new virtual table `crdb_internal.table_row_statistics` was added (to
show stats for non-root users).

Release note (sql change): This change modifies SHOW TABLES to return
estimates number of rows.
  • Loading branch information
ekalinin committed Aug 4, 2020
1 parent 0df9caf commit 28bac8f
Show file tree
Hide file tree
Showing 26 changed files with 662 additions and 570 deletions.
1 change: 1 addition & 0 deletions pkg/cli/zip.go
Original file line number Diff line number Diff line change
Expand Up @@ -76,6 +76,7 @@ var debugZipTablesPerCluster = []string{
"crdb_internal.schema_changes",
"crdb_internal.partitions",
"crdb_internal.zones",
"crdb_internal.table_row_statistics",
}

// Tables collected from each node in a debug zip.
Expand Down
2 changes: 1 addition & 1 deletion pkg/server/admin.go
Original file line number Diff line number Diff line change
Expand Up @@ -327,7 +327,7 @@ func (s *adminServer) DatabaseDetails(
// Marshal table names.
{
scanner := makeResultScanner(cols)
if a, e := len(cols), 3; a != e {
if a, e := len(cols), 4; a != e {
return nil, s.serverErrorf("show tables columns mismatch: %d != expected %d", a, e)
}
for _, row := range rows {
Expand Down
54 changes: 54 additions & 0 deletions pkg/sql/crdb_internal.go
Original file line number Diff line number Diff line change
Expand Up @@ -106,6 +106,7 @@ var crdbInternal = virtualSchema{
sqlbase.CrdbInternalTableColumnsTableID: crdbInternalTableColumnsTable,
sqlbase.CrdbInternalTableIndexesTableID: crdbInternalTableIndexesTable,
sqlbase.CrdbInternalTablesTableID: crdbInternalTablesTable,
sqlbase.CrdbInternalTablesTableLastStatsID: crdbInternalTablesTableLastStats,
sqlbase.CrdbInternalTxnStatsTableID: crdbInternalTxnStatsTable,
sqlbase.CrdbInternalZonesTableID: crdbInternalZonesTable,
},
Expand Down Expand Up @@ -337,6 +338,59 @@ CREATE TABLE crdb_internal.tables (
},
}

var crdbInternalTablesTableLastStats = virtualSchemaTable{
comment: "the latest stats for all tables accessible by current user in current database (KV scan)",
schema: `
CREATE TABLE crdb_internal.table_row_statistics (
table_id INT NOT NULL,
table_name STRING NOT NULL,
estimated_row_count INT NOT NULL
)`,
populate: func(ctx context.Context, p *planner, db *sqlbase.ImmutableDatabaseDescriptor, addRow func(...tree.Datum) error) error {
// Collect the latests statistics for all tables.
query := `` +
`SELECT s."tableID", max(s."rowCount")` +
` FROM system.table_statistics AS s ` +
` JOIN (` +
` SELECT "tableID", MAX("createdAt") AS last_dt ` +
` FROM system.table_statistics ` +
` GROUP BY "tableID"` +
` ) AS l ON l."tableID" = s."tableID" ` +
` AND l.last_dt = s."createdAt"` +
` GROUP BY s."tableID"`
statRows, err := p.ExtendedEvalContext().ExecCfg.InternalExecutor.QueryEx(
ctx, "crdb-internal-statistics-table", p.txn,
sqlbase.InternalExecutorSessionDataOverride{User: security.RootUser},
query)
if err != nil {
return err
}

// Convert statistics into map: tableID -> rowCount.
statMap := make(map[tree.DInt]tree.DInt)
for _, r := range statRows {
statMap[tree.MustBeDInt(r[0])] = tree.MustBeDInt(r[1])
}

// Walk over all available tables and show row count for each of them
// using collected statistics.
return forEachTableDescAll(ctx, p, db, virtualMany,
func(db *sqlbase.ImmutableDatabaseDescriptor, _ string, table *ImmutableTableDescriptor) error {
tableID := tree.DInt(table.ID)
rowCount := tree.DInt(0)
if cnt, ok := statMap[tableID]; ok {
rowCount = cnt
}
return addRow(
tree.NewDInt(tableID),
tree.NewDString(table.Name),
&rowCount,
)
},
)
},
}

// TODO(tbg): prefix with kv_.
var crdbInternalSchemaChangesTable = virtualSchemaTable{
comment: `ongoing schema changes, across all descriptors accessible by current user (KV scan; expensive!)`,
Expand Down
76 changes: 30 additions & 46 deletions pkg/sql/delegate/show_tables.go
Original file line number Diff line number Diff line change
Expand Up @@ -43,53 +43,37 @@ func (d *delegator) delegateShowTables(n *tree.ShowTables) (tree.Statement, erro
schemaClause = "AND ns.nspname NOT IN ('information_schema', 'pg_catalog', 'crdb_internal', 'pg_extension')"
}

var query string
if n.WithComment {
const getTablesQuery = `
SELECT
ns.nspname AS schema_name,
pc.relname AS table_name,
(CASE
WHEN pc.relkind = 'v' THEN 'view'
WHEN pc.relkind = 'S' THEN 'sequence'
ELSE 'table'
END) AS "type",
COALESCE(pd.description, '') AS comment
FROM %[1]s.pg_catalog.pg_class AS pc
JOIN %[1]s.pg_catalog.pg_namespace AS ns ON (ns.oid = pc.relnamespace)
LEFT JOIN %[1]s.pg_catalog.pg_description AS pd ON (pc.oid = pd.objoid AND pd.objsubid = 0)
WHERE pc.relkind IN ('r', 'v', 'S') %[2]s
ORDER BY schema_name, table_name
`

query = fmt.Sprintf(
getTablesQuery,
&name.CatalogName,
schemaClause,
)

} else {
const getTablesQuery = `
SELECT
ns.nspname AS schema_name,
pc.relname AS table_name,
(CASE
WHEN pc.relkind = 'v' THEN 'view'
WHEN pc.relkind = 'S' THEN 'sequence'
ELSE 'table'
END) AS "type"
FROM %[1]s.pg_catalog.pg_class AS pc
JOIN %[1]s.pg_catalog.pg_namespace AS ns ON (ns.oid = pc.relnamespace)
WHERE pc.relkind IN ('r', 'v', 'S') %[2]s
ORDER BY schema_name, table_name
const getTablesQuery = `
SELECT ns.nspname AS schema_name
, pc.relname AS table_name
, CASE
WHEN pc.relkind = 'v' THEN 'view'
WHEN pc.relkind = 'S' THEN 'sequence'
ELSE 'table'
END AS type
, (
SELECT estimated_row_count
FROM crdb_internal.table_row_statistics
WHERE table_id = pc.oid::int
) AS estimated_row_count
%[3]s
FROM %[1]s.pg_catalog.pg_class AS pc
JOIN %[1]s.pg_catalog.pg_namespace AS ns ON (ns.oid = pc.relnamespace)
LEFT
JOIN %[1]s.pg_catalog.pg_description AS pd ON (pc.oid = pd.objoid AND pd.objsubid = 0)
WHERE pc.relkind IN ('r', 'v', 'S')
%[2]s
ORDER BY schema_name, table_name
`

query = fmt.Sprintf(
getTablesQuery,
&name.CatalogName,
schemaClause,
)
var comment string
if n.WithComment {
comment = `, COALESCE(pd.description, '') AS "comment"`
}

query := fmt.Sprintf(
getTablesQuery,
&name.CatalogName,
schemaClause,
comment,
)
return parse(query)
}
Original file line number Diff line number Diff line change
Expand Up @@ -36,10 +36,10 @@ DROP TABLE t
statement error schema change cannot be initiated in this version until the version upgrade is finalized
TRUNCATE TABLE t

query TTT
query TTTI
SHOW TABLES
----
public t table
public t table 0

subtest columns

Expand Down Expand Up @@ -143,10 +143,10 @@ CREATE TABLE db.t (a INT)
statement error schema change cannot be initiated in this version until the version upgrade is finalized
DROP DATABASE db

query TTT
query TTTI
SHOW TABLES FROM db
----
public t table
public t table NULL

subtest non_backfill_schema_changes

Expand Down
81 changes: 41 additions & 40 deletions pkg/sql/logictest/testdata/logic_test/crdb_internal
Original file line number Diff line number Diff line change
Expand Up @@ -8,48 +8,49 @@ CREATE TABLE crdb_internal.t (x INT)
query error database "crdb_internal" does not exist
DROP DATABASE crdb_internal

query TTT
query TTTI
SHOW TABLES FROM crdb_internal
----
crdb_internal backward_dependencies table
crdb_internal builtin_functions table
crdb_internal cluster_queries table
crdb_internal cluster_sessions table
crdb_internal cluster_settings table
crdb_internal cluster_transactions table
crdb_internal create_statements table
crdb_internal create_type_statements table
crdb_internal databases table
crdb_internal feature_usage table
crdb_internal forward_dependencies table
crdb_internal gossip_alerts table
crdb_internal gossip_liveness table
crdb_internal gossip_network table
crdb_internal gossip_nodes table
crdb_internal index_columns table
crdb_internal jobs table
crdb_internal kv_node_status table
crdb_internal kv_store_status table
crdb_internal leases table
crdb_internal node_build_info table
crdb_internal node_metrics table
crdb_internal node_queries table
crdb_internal node_runtime_info table
crdb_internal node_sessions table
crdb_internal node_statement_statistics table
crdb_internal node_transactions table
crdb_internal node_txn_stats table
crdb_internal partitions table
crdb_internal predefined_comments table
crdb_internal ranges view
crdb_internal ranges_no_leases table
crdb_internal schema_changes table
crdb_internal session_trace table
crdb_internal session_variables table
crdb_internal table_columns table
crdb_internal table_indexes table
crdb_internal tables table
crdb_internal zones table
crdb_internal backward_dependencies table 0
crdb_internal builtin_functions table 0
crdb_internal cluster_queries table 0
crdb_internal cluster_sessions table 0
crdb_internal cluster_settings table 0
crdb_internal cluster_transactions table 0
crdb_internal create_statements table 0
crdb_internal create_type_statements table 0
crdb_internal databases table 0
crdb_internal feature_usage table 0
crdb_internal forward_dependencies table 0
crdb_internal gossip_alerts table 0
crdb_internal gossip_liveness table 0
crdb_internal gossip_network table 0
crdb_internal gossip_nodes table 0
crdb_internal index_columns table 0
crdb_internal jobs table 0
crdb_internal kv_node_status table 0
crdb_internal kv_store_status table 0
crdb_internal leases table 0
crdb_internal node_build_info table 0
crdb_internal node_metrics table 0
crdb_internal node_queries table 0
crdb_internal node_runtime_info table 0
crdb_internal node_sessions table 0
crdb_internal node_statement_statistics table 0
crdb_internal node_transactions table 0
crdb_internal node_txn_stats table 0
crdb_internal partitions table 0
crdb_internal predefined_comments table 0
crdb_internal ranges view 0
crdb_internal ranges_no_leases table 0
crdb_internal schema_changes table 0
crdb_internal session_trace table 0
crdb_internal session_variables table 0
crdb_internal table_columns table 0
crdb_internal table_indexes table 0
crdb_internal table_row_statistics table 0
crdb_internal tables table 0
crdb_internal zones table 0

statement ok
CREATE DATABASE testdb; CREATE TABLE testdb.foo(x INT)
Expand Down
12 changes: 6 additions & 6 deletions pkg/sql/logictest/testdata/logic_test/drop_index
Original file line number Diff line number Diff line change
Expand Up @@ -170,12 +170,12 @@ users foo true 2 id ASC false
statement ok
CREATE VIEW v2 AS SELECT name FROM v

query TTT
query TTTI
SHOW TABLES
----
public users table
public v view
public v2 view
public users table 0
public v view 0
public v2 view 0

statement ok
GRANT ALL ON users to testuser
Expand All @@ -199,10 +199,10 @@ SHOW INDEXES FROM users
table_name index_name non_unique seq_in_index column_name direction storing implicit
users primary false 1 id ASC false false

query TTT
query TTTI
SHOW TABLES
----
public users table
public users table 0

# Test the syntax without a '@'

Expand Down
10 changes: 5 additions & 5 deletions pkg/sql/logictest/testdata/logic_test/drop_table
Original file line number Diff line number Diff line change
Expand Up @@ -6,11 +6,11 @@ CREATE TABLE a (id INT PRIMARY KEY)
statement ok
CREATE TABLE b (id INT PRIMARY KEY)

query TTT
query TTTI
SHOW TABLES FROM test
----
public a table
public b table
public a table 0
public b table 0

statement ok
INSERT INTO a VALUES (3),(7),(2)
Expand All @@ -35,10 +35,10 @@ SELECT job_type, status FROM [SHOW JOBS] WHERE job_type = 'SCHEMA CHANGE GC' OR
SCHEMA CHANGE succeeded
SCHEMA CHANGE GC running

query TTT
query TTTI
SHOW TABLES FROM test
----
public b table
public b table 0

statement error pgcode 42P01 relation "a" does not exist
SELECT * FROM a
Expand Down
Loading

0 comments on commit 28bac8f

Please sign in to comment.