Skip to content

Commit

Permalink
Implement show stats command
Browse files Browse the repository at this point in the history
  • Loading branch information
nineinchnick authored and kenshaw committed Oct 11, 2021
1 parent fe434ab commit 78a3c2f
Show file tree
Hide file tree
Showing 9 changed files with 483 additions and 38 deletions.
1 change: 1 addition & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -653,6 +653,7 @@ Informational
\dt[S+] [PATTERN] list tables
\dv[S+] [PATTERN] list views
\l[+] list databases
\ss[+] [TABLE|QUERY] [k] show stats for a table or a query
Formatting
\pset [NAME [VALUE]] set table output option
Expand Down
79 changes: 79 additions & 0 deletions drivers/metadata/metadata.go
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,7 @@ type ExtendedReader interface {
SchemaReader
TableReader
ColumnReader
ColumnStatReader
IndexReader
IndexColumnReader
TriggerReader
Expand Down Expand Up @@ -56,6 +57,12 @@ type ColumnReader interface {
Columns(Filter) (*ColumnSet, error)
}

// ColumnStatsReader lists table column statistics.
type ColumnStatReader interface {
Reader
ColumnStats(Filter) (*ColumnStatSet, error)
}

// IndexReader lists table indexes.
type IndexReader interface {
Reader
Expand Down Expand Up @@ -144,6 +151,8 @@ type Writer interface {
ListSchemas(string, bool, bool) error
// ListIndexes \di
ListIndexes(string, bool, bool) error
// ShowStats \ss
ShowStats(string, string, bool, int) error
}

type CatalogSet struct {
Expand Down Expand Up @@ -224,6 +233,7 @@ func NewTableSet(v []Table) *TableSet {
"Name",
"Type",

"Rows",
"Size",
"Comment",
},
Expand All @@ -240,6 +250,7 @@ type Table struct {
Schema string
Name string
Type string
Rows int64
Size string
Comment string
}
Expand All @@ -250,6 +261,7 @@ func (t Table) values() []interface{} {
t.Schema,
t.Name,
t.Type,
t.Rows,
t.Size,
t.Comment,
}
Expand Down Expand Up @@ -330,6 +342,73 @@ func (c Column) values() []interface{} {
}
}

type ColumnStatSet struct {
resultSet
}

func NewColumnStatSet(v []ColumnStat) *ColumnStatSet {
r := make([]Result, len(v))
for i := range v {
r[i] = &v[i]
}
return &ColumnStatSet{
resultSet: resultSet{
results: r,
columns: []string{
"Catalog",
"Schema",
"Table",
"Name",

"Average width",
"Nulls fraction",
"Distinct values",
"Minimum value",
"Maximum value",
"Mean value",
"Top N common values",
"Top N values freqs",
},
},
}
}

func (c ColumnStatSet) Get() *ColumnStat {
return c.results[c.current-1].(*ColumnStat)
}

type ColumnStat struct {
Catalog string
Schema string
Table string
Name string
AvgWidth int
NullFrac float64
NumDistinct int64
Min string
Max string
Mean string
TopN []string
TopNFreqs []float64
}

func (c ColumnStat) values() []interface{} {
return []interface{}{
c.Catalog,
c.Schema,
c.Table,
c.Name,
c.AvgWidth,
c.NullFrac,
c.NumDistinct,
c.Min,
c.Max,
c.Mean,
c.TopN,
c.TopNFreqs,
}
}

type IndexSet struct {
resultSet
}
Expand Down
145 changes: 142 additions & 3 deletions drivers/metadata/postgres/metadata.go
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@ import (
"fmt"
"strings"

"github.com/lib/pq"
"github.com/xo/usql/drivers"
"github.com/xo/usql/drivers/metadata"
infos "github.com/xo/usql/drivers/metadata/informationschema"
Expand All @@ -17,6 +18,8 @@ type metaReader struct {
}

var _ metadata.CatalogReader = &metaReader{}
var _ metadata.TableReader = &metaReader{}
var _ metadata.ColumnStatReader = &metaReader{}
var _ metadata.IndexReader = &metaReader{}
var _ metadata.IndexColumnReader = &metaReader{}
var _ metadata.TriggerReader = &metaReader{}
Expand Down Expand Up @@ -70,6 +73,144 @@ FROM pg_catalog.pg_database d`
return metadata.NewCatalogSet(results), nil
}

func (r metaReader) Tables(f metadata.Filter) (*metadata.TableSet, error) {
qstr := `SELECT n.nspname as "Schema",
c.relname as "Name",
CASE c.relkind WHEN 'r' THEN 'table' WHEN 'v' THEN 'view' WHEN 'm' THEN 'materialized view' WHEN 'i' THEN 'index' WHEN 'S' THEN 'sequence' WHEN 's' THEN 'special' WHEN 'f' THEN 'foreign table' WHEN 'p' THEN 'partitioned table' WHEN 'I' THEN 'partitioned index' END as "Type",
COALESCE((c.reltuples / NULLIF(c.relpages, 0)) * (pg_catalog.pg_relation_size(c.oid) / current_setting('block_size')::int), 0)::bigint as "Rows",
pg_catalog.pg_size_pretty(pg_catalog.pg_table_size(c.oid)) as "Size",
COALESCE(pg_catalog.obj_description(c.oid, 'pg_class'), '') as "Description"
FROM pg_catalog.pg_class c
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
`
conds := []string{"n.nspname !~ '^pg_toast'"}
vals := []interface{}{}
if f.OnlyVisible {
conds = append(conds, "pg_catalog.pg_table_is_visible(c.oid)")
}
if !f.WithSystem {
conds = append(conds, "n.nspname NOT IN ('pg_catalog', 'information_schema')")
}
if f.Schema != "" {
vals = append(vals, f.Schema)
conds = append(conds, fmt.Sprintf("n.nspname LIKE $%d", len(vals)))
}
if f.Name != "" {
vals = append(vals, f.Name)
conds = append(conds, fmt.Sprintf("c.relname LIKE $%d", len(vals)))
}
if len(f.Types) != 0 {
tableTypes := map[string][]rune{
"TABLE": {'r', 'p', 's', 'f'},
"VIEW": {'v'},
"MATERIALIZED VIEW": {'m'},
"SEQUENCE": {'S'},
}
pholders := []string{"''"}
for _, t := range f.Types {
for _, k := range tableTypes[t] {
vals = append(vals, string(k))
pholders = append(pholders, fmt.Sprintf("$%d", len(vals)))
}
}
conds = append(conds, fmt.Sprintf("c.relkind IN (%s)", strings.Join(pholders, ", ")))
}
rows, closeRows, err := r.query(qstr, conds, "1, 2", vals...)
if err != nil {
if err == sql.ErrNoRows {
return metadata.NewTableSet([]metadata.Table{}), nil
}
return nil, err
}
defer closeRows()

results := []metadata.Table{}
for rows.Next() {
rec := metadata.Table{}
err = rows.Scan(&rec.Schema, &rec.Name, &rec.Type, &rec.Rows, &rec.Size, &rec.Comment)
if err != nil {
return nil, err
}
results = append(results, rec)
}
if rows.Err() != nil {
return nil, rows.Err()
}
return metadata.NewTableSet(results), nil
}

func (r metaReader) ColumnStats(f metadata.Filter) (*metadata.ColumnStatSet, error) {
tables, err := r.Tables(metadata.Filter{Schema: f.Schema, Name: f.Parent, WithSystem: true})
if err != nil {
return nil, err
}
rowNum := int64(0)
if tables.Next() {
rowNum = tables.Get().Rows
}

qstr := `
SELECT
s.schemaname,
s.tablename,
s.attname,
s.avg_width,
s.null_frac,
CASE WHEN n_distinct >= 0 THEN n_distinct ELSE (-n_distinct * $1)::bigint END,
COALESCE((histogram_bounds::text::text[])[1], ''),
COALESCE((histogram_bounds::text::text[])[array_length(histogram_bounds::text::text[], 1)], ''),
most_common_vals::text::text[],
most_common_freqs::text::text[]
FROM pg_catalog.pg_stats s
JOIN pg_catalog.pg_namespace n ON n.nspname = s.schemaname
JOIN pg_catalog.pg_class c ON c.relnamespace = n.oid AND c.relname = s.tablename
JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid AND a.attname = s.attname`
conds := []string{}
vals := []interface{}{rowNum}
if f.Schema != "" {
vals = append(vals, f.Schema)
conds = append(conds, fmt.Sprintf("s.schemaname LIKE $%d", len(vals)))
}
if f.Parent != "" {
vals = append(vals, f.Parent)
conds = append(conds, fmt.Sprintf("s.tablename LIKE $%d", len(vals)))
}
if f.Name != "" {
vals = append(vals, f.Name)
conds = append(conds, fmt.Sprintf("s.attname LIKE $%d", len(vals)))
}
rows, closeRows, err := r.query(qstr, conds, "a.attnum", vals...)
if err != nil {
return nil, err
}
defer closeRows()

results := []metadata.ColumnStat{}
for rows.Next() {
rec := metadata.ColumnStat{}
err = rows.Scan(
&rec.Schema,
&rec.Table,
&rec.Name,
&rec.AvgWidth,
&rec.NullFrac,
&rec.NumDistinct,
&rec.Min,
&rec.Max,
pq.Array(&rec.TopN),
pq.Array(&rec.TopNFreqs),
)
if err != nil {
return nil, err
}
results = append(results, rec)
}
if rows.Err() != nil {
return nil, rows.Err()
}
return metadata.NewColumnStatSet(results), nil
}

func (r metaReader) Indexes(f metadata.Filter) (*metadata.IndexSet, error) {
qstr := `
SELECT
Expand All @@ -86,16 +227,14 @@ FROM pg_catalog.pg_class c
LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid`
conds := []string{
"c.relkind IN ('i','I','')",
"n.nspname <> 'pg_catalog'",
"n.nspname <> 'information_schema'",
"n.nspname !~ '^pg_toast'",
}
if f.OnlyVisible {
conds = append(conds, "pg_catalog.pg_table_is_visible(c.oid)")
}
vals := []interface{}{}
if !f.WithSystem {
conds = append(conds, "n.nspname NOT IN ('pg_catalog', 'pg_toast', 'information_schema')")
conds = append(conds, "n.nspname NOT IN ('pg_catalog', 'information_schema')")
}
if f.Schema != "" {
vals = append(vals, f.Schema)
Expand Down
11 changes: 11 additions & 0 deletions drivers/metadata/reader.go
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,7 @@ type PluginReader struct {
schemas func(Filter) (*SchemaSet, error)
tables func(Filter) (*TableSet, error)
columns func(Filter) (*ColumnSet, error)
columnStats func(Filter) (*ColumnStatSet, error)
indexes func(Filter) (*IndexSet, error)
indexColumns func(Filter) (*IndexColumnSet, error)
triggers func(Filter) (*TriggerSet, error)
Expand Down Expand Up @@ -40,6 +41,9 @@ func NewPluginReader(readers ...Reader) Reader {
if r, ok := i.(ColumnReader); ok {
p.columns = r.Columns
}
if r, ok := i.(ColumnStatReader); ok {
p.columnStats = r.ColumnStats
}
if r, ok := i.(IndexReader); ok {
p.indexes = r.Indexes
}
Expand Down Expand Up @@ -96,6 +100,13 @@ func (p PluginReader) Columns(f Filter) (*ColumnSet, error) {
return p.columns(f)
}

func (p PluginReader) ColumnStats(f Filter) (*ColumnStatSet, error) {
if p.columnStats == nil {
return nil, ErrNotSupported
}
return p.columnStats(f)
}

func (p PluginReader) Indexes(f Filter) (*IndexSet, error) {
if p.indexes == nil {
return nil, ErrNotSupported
Expand Down
Loading

0 comments on commit 78a3c2f

Please sign in to comment.