Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

add pg_views table to pg_catalog and views displayed on \d psql cmd #454

Merged
merged 15 commits into from
Jul 2, 2024
4 changes: 2 additions & 2 deletions go.mod
Original file line number Diff line number Diff line change
Expand Up @@ -6,9 +6,10 @@ toolchain go1.22.3

require (
github.com/PuerkitoBio/goquery v1.8.1
github.com/cespare/xxhash/v2 v2.2.0
github.com/cockroachdb/apd/v2 v2.0.3-0.20200518165714-d020e156310a
github.com/cockroachdb/errors v1.7.5
github.com/dolthub/dolt/go v0.40.5-0.20240627215315-861b7795c60b
github.com/dolthub/dolt/go v0.40.5-0.20240701213509-be3893ab26d6
github.com/dolthub/dolt/go/gen/proto/dolt/services/eventsapi v0.0.0-20240529071237-4a099b896ce8
github.com/dolthub/flatbuffers/v23 v23.3.3-dh.2
github.com/dolthub/go-mysql-server v0.18.2-0.20240627195919-9e5cc178ea5e
Expand Down Expand Up @@ -59,7 +60,6 @@ require (
github.com/bcicen/jstream v1.0.0 // indirect
github.com/beorn7/perks v1.0.1 // indirect
github.com/cenkalti/backoff/v4 v4.1.3 // indirect
github.com/cespare/xxhash/v2 v2.2.0 // indirect
github.com/cockroachdb/logtags v0.0.0-20190617123548-eb05cc24525f // indirect
github.com/cockroachdb/redact v1.0.6 // indirect
github.com/cockroachdb/sentry-go v0.6.1-cockroachdb.2 // indirect
Expand Down
4 changes: 2 additions & 2 deletions go.sum
Original file line number Diff line number Diff line change
Expand Up @@ -214,8 +214,8 @@ github.com/dgrijalva/jwt-go v3.2.0+incompatible/go.mod h1:E3ru+11k8xSBh+hMPgOLZm
github.com/dgryski/go-farm v0.0.0-20190423205320-6a90982ecee2/go.mod h1:SqUrOPUnsFjfmXRMNPybcSiG0BgUW2AuFH8PAnS2iTw=
github.com/docker/go-connections v0.4.0/go.mod h1:Gbd7IOopHjR8Iph03tsViu4nIes5XhDvyHbTtUxmeec=
github.com/docker/go-units v0.4.0/go.mod h1:fgPhTUdO+D/Jk86RDLlptpiXQzgHJF7gydDDbaIK4Dk=
github.com/dolthub/dolt/go v0.40.5-0.20240627215315-861b7795c60b h1:Pi1BTQ/pQ6dz9hzY9wqtYwbSZcwgSYoZSj5M6Mop8zU=
github.com/dolthub/dolt/go v0.40.5-0.20240627215315-861b7795c60b/go.mod h1:7nCm/4+o777+RdCihNLRTQU448V/+lvYgriYnTuRxBU=
github.com/dolthub/dolt/go v0.40.5-0.20240701213509-be3893ab26d6 h1:zCeMViVMArmvuNZ55fwQ+H4pw6sRZHgSGkGAAYKxd18=
github.com/dolthub/dolt/go v0.40.5-0.20240701213509-be3893ab26d6/go.mod h1:7nCm/4+o777+RdCihNLRTQU448V/+lvYgriYnTuRxBU=
github.com/dolthub/dolt/go/gen/proto/dolt/services/eventsapi v0.0.0-20240529071237-4a099b896ce8 h1:izuogF6KRc6Pr5g5KevRtn8JK/KwyEGjbpqWJIORbQo=
github.com/dolthub/dolt/go/gen/proto/dolt/services/eventsapi v0.0.0-20240529071237-4a099b896ce8/go.mod h1:L5RDYZbC9BBWmoU2+TjTekeqqhFXX5EqH9ln00O0stY=
github.com/dolthub/flatbuffers/v23 v23.3.3-dh.2 h1:u3PMzfF8RkKd3lB9pZ2bfn0qEG+1Gms9599cr0REMww=
Expand Down
4 changes: 2 additions & 2 deletions server/connection_handler.go
Original file line number Diff line number Diff line change
Expand Up @@ -794,14 +794,14 @@ func (h *ConnectionHandler) handledPSQLCommands(statement string) (bool, error)
// Command: \d
if statement == "select n.nspname as \"schema\",\n c.relname as \"name\",\n 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 't' then 'toast table' when 'f' then 'foreign table' when 'p' then 'partitioned table' when 'i' then 'partitioned index' end as \"type\",\n pg_catalog.pg_get_userbyid(c.relowner) as \"owner\"\nfrom pg_catalog.pg_class c\n left join pg_catalog.pg_namespace n on n.oid = c.relnamespace\n left join pg_catalog.pg_am am on am.oid = c.relam\nwhere c.relkind in ('r','p','v','m','s','f','')\n and n.nspname <> 'pg_catalog'\n and n.nspname !~ '^pg_toast'\n and n.nspname <> 'information_schema'\n and pg_catalog.pg_table_is_visible(c.oid)\norder by 1,2;" {
return true, h.query(ConvertedQuery{
String: `SELECT table_schema AS 'Schema', TABLE_NAME AS 'Name', 'table' AS 'Type', 'postgres' AS 'Owner' FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA <> 'pg_catalog' AND CONVERT(TABLE_TYPE, CHAR) = 'BASE TABLE' ORDER BY 2;`,
String: `SELECT table_schema AS 'Schema', TABLE_NAME AS 'Name', IF(TABLE_TYPE = 'VIEW', 'view', 'table') AS 'Type', 'postgres' AS 'Owner' FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA <> 'pg_catalog' AND CONVERT(TABLE_TYPE, CHAR) = 'BASE TABLE' OR CONVERT(TABLE_TYPE, CHAR) = 'VIEW' ORDER BY 2;`,
StatementTag: "SELECT",
})
}
// Alternate \d for psql 14
if statement == "select n.nspname as \"schema\",\n c.relname as \"name\",\n 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 't' then 'toast table' when 'f' then 'foreign table' when 'p' then 'partitioned table' when 'i' then 'partitioned index' end as \"type\",\n pg_catalog.pg_get_userbyid(c.relowner) as \"owner\"\nfrom pg_catalog.pg_class c\n left join pg_catalog.pg_namespace n on n.oid = c.relnamespace\n left join pg_catalog.pg_am am on am.oid = c.relam\nwhere c.relkind in ('r','p','v','m','s','f','')\n and n.nspname <> 'pg_catalog'\n and n.nspname !~ '^pg_toast'\n and n.nspname <> 'information_schema'\n and pg_catalog.pg_table_is_visible(c.oid)\norder by 1,2;" {
return true, h.query(ConvertedQuery{
String: `SELECT table_schema AS 'Schema', TABLE_NAME AS 'Name', 'table' AS 'Type', 'postgres' AS 'Owner' FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA <> 'pg_catalog' AND CONVERT(TABLE_TYPE, CHAR) = 'BASE TABLE' ORDER BY 2;`,
String: `SELECT table_schema AS 'Schema', TABLE_NAME AS 'Name', IF(TABLE_TYPE = 'VIEW', 'view', 'table') AS 'Type', 'postgres' AS 'Owner' FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA <> 'pg_catalog' AND CONVERT(TABLE_TYPE, CHAR) = 'BASE TABLE' OR CONVERT(TABLE_TYPE, CHAR) = 'VIEW' ORDER BY 2;`,
StatementTag: "SELECT",
})
}
Expand Down
41 changes: 19 additions & 22 deletions server/tables/pgcatalog/pg_class.go
Original file line number Diff line number Diff line change
Expand Up @@ -50,7 +50,7 @@ func (p PgClassHandler) RowIter(ctx *sql.Context) (sql.RowIter, error) {

var classes []Class

currentDB, err := currentDatabaseSchemaIter(ctx, c, func(db sql.DatabaseSchema) (bool, error) {
_, err := currentDatabaseSchemaIter(ctx, c, func(db sql.DatabaseSchema) (bool, error) {
dbName := db.Name()
schName := db.SchemaName()
schOid := genOid(dbName, schName)
Expand Down Expand Up @@ -94,33 +94,30 @@ func (p PgClassHandler) RowIter(ctx *sql.Context) (sql.RowIter, error) {
return false, err
}

// Get views
if vdb, ok := db.(sql.ViewDatabase); ok {
views, err := vdb.AllViews(ctx)
if err != nil {
return false, err
}

for _, view := range views {
classes = append(classes, Class{
oid: genOid(dbName, schName, view.Name),
name: view.Name,
hasIndexes: false,
kind: "v",
schemaOid: schOid,
})
}
}

return true, nil
})
if err != nil {
return nil, err
}

// Get views
if vdb, ok := currentDB.(sql.ViewDatabase); ok {
dbName := currentDB.Name()
views, err := vdb.AllViews(ctx)
if err != nil {
return nil, err
}

for _, view := range views {
// TODO: OIDs should use schemaName when this issue is fixed
// https://github.com/dolthub/doltgresql/issues/456
classes = append(classes, Class{
oid: genOid(dbName, view.Name),
name: view.Name,
hasIndexes: false,
kind: "v",
schemaOid: genOid(dbName),
})
}
}

return &pgClassRowIter{
classes: classes,
idx: 0,
Expand Down
69 changes: 66 additions & 3 deletions server/tables/pgcatalog/pg_views.go
Original file line number Diff line number Diff line change
Expand Up @@ -15,10 +15,15 @@
package pgcatalog

import (
"fmt"
"io"

"github.com/dolthub/dolt/go/libraries/doltcore/sqle/dsess"
sqle "github.com/dolthub/go-mysql-server"
"github.com/dolthub/go-mysql-server/sql"

"github.com/dolthub/doltgresql/postgres/parser/parser"
"github.com/dolthub/doltgresql/postgres/parser/sem/tree"
"github.com/dolthub/doltgresql/server/tables"
pgtypes "github.com/dolthub/doltgresql/server/types"
)
Expand All @@ -43,8 +48,34 @@ func (p PgViewsHandler) Name() string {

// RowIter implements the interface tables.Handler.
func (p PgViewsHandler) RowIter(ctx *sql.Context) (sql.RowIter, error) {
// TODO: Implement pg_views row iter
return emptyRowIter()
doltSession := dsess.DSessFromSess(ctx.Session)
c := sqle.NewDefault(doltSession.Provider()).Analyzer.Catalog

var views []sql.ViewDefinition
var schemas []string
_, err := currentDatabaseSchemaIter(ctx, c, func(sch sql.DatabaseSchema) (bool, error) {
if vdb, ok := sch.(sql.ViewDatabase); ok {
vws, err := vdb.AllViews(ctx)
if err != nil {
return false, err
}
for _, vw := range vws {
views = append(views, vw)
schemas = append(schemas, sch.SchemaName())
}

}
return true, nil
})
if err != nil {
return nil, err
}

return &pgViewsRowIter{
views: views,
schemas: schemas,
idx: 0,
}, nil
}

// Schema implements the interface tables.Handler.
Expand All @@ -65,13 +96,45 @@ var pgViewsSchema = sql.Schema{

// pgViewsRowIter is the sql.RowIter for the pg_views table.
type pgViewsRowIter struct {
views []sql.ViewDefinition
schemas []string
idx int
}

var _ sql.RowIter = (*pgViewsRowIter)(nil)

// Next implements the interface sql.RowIter.
func (iter *pgViewsRowIter) Next(ctx *sql.Context) (sql.Row, error) {
return nil, io.EOF
if iter.idx >= len(iter.views) {
return nil, io.EOF
}
iter.idx++
view := iter.views[iter.idx-1]
schema := iter.schemas[iter.idx-1]

textDef := view.TextDefinition
if textDef == "" {
stmts, err := parser.Parse(view.CreateViewStatement)
if err != nil {
return nil, err
}
if len(stmts) == 0 {
return nil, fmt.Errorf("expected Create View statement, got none")
}
cv, ok := stmts[0].AST.(*tree.CreateView)
if !ok {
return nil, fmt.Errorf("expected Create View statement, got %s", stmts[0].SQL)
}

textDef = cv.AsSource.String()
}

return sql.Row{
schema, // schemaname
view.Name, // viewname
"", // viewowner
textDef, // definition
}, nil
}

// Close implements the interface sql.RowIter.
Expand Down
3 changes: 2 additions & 1 deletion testing/bats/psql-commands.bats
Original file line number Diff line number Diff line change
Expand Up @@ -39,7 +39,8 @@ teardown() {
[ "$status" -eq 0 ]
[[ "$output" =~ "public,test1,table,postgres" ]] || false
[[ "$output" =~ "public,test2,table,postgres" ]] || false
[ "${#lines[@]}" -eq 3 ]
[[ "$output" =~ "public,testview,view,postgres" ]] || false
[ "${#lines[@]}" -eq 4 ]
}

@test 'psql-commands: \d table' {
Expand Down
40 changes: 40 additions & 0 deletions testing/go/create_view_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -42,6 +42,46 @@ var createViewStmts = []ScriptTest{
},
},
},
{
Name: "views on different schemas",
SetUpScript: []string{
"CREATE SCHEMA testschema;",
"SET search_path TO testschema;",
"CREATE TABLE testing (pk INT primary key, v2 TEXT);",
"INSERT INTO testing VALUES (1,'a'), (2,'b'), (3,'c');",
"CREATE VIEW testview AS SELECT * FROM testing;",
"CREATE SCHEMA myschema;",
"SET search_path TO myschema;",
"CREATE TABLE mytable (pk INT primary key, v1 INT);",
"INSERT INTO mytable VALUES (1,4), (2,5), (3,6);",
"CREATE VIEW myview AS SELECT * FROM mytable;",
},
Assertions: []ScriptTestAssertion{
{
Query: "SHOW search_path;",
Expected: []sql.Row{{"myschema"}},
},
{
Query: "select v1 from myview order by pk;",
Expected: []sql.Row{{4}, {5}, {6}},
},
{
Query: "SET search_path = 'testschema';",
},
{
Query: "SHOW search_path;",
Expected: []sql.Row{{"testschema"}},
},
{
Query: "select * from myview order by pk; /* err */",
ExpectedErr: "table not found: myview",
},
{
Query: "select v2 from testview order by pk;",
Expected: []sql.Row{{"a"}, {"b"}, {"c"}},
},
},
},
{
Name: "create view from view",
SetUpScript: []string{
Expand Down
18 changes: 12 additions & 6 deletions testing/go/pgcatalog_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -370,7 +370,7 @@ func TestPgClass(t *testing.T) {
// View
{
Query: `SELECT * FROM "pg_catalog"."pg_class" WHERE relname='testview';`,
Expected: []sql.Row{{2993650152, "testview", 3906608034, 0, 0, 0, 0, 0, 0, 0, float32(0), 0, 0, "f", "f", "p", "v", 0, 0, "f", "f", "f", "f", "f", "t", "d", "f", 0, 0, 0, nil, nil, nil}},
Expected: []sql.Row{{3365776452, "testview", 3874471750, 0, 0, 0, 0, 0, 0, 0, float32(0), 0, 0, "f", "f", "p", "v", 0, 0, "f", "f", "f", "f", "f", "t", "d", "f", 0, 0, 0, nil, nil, nil}},
},
{ // Different cases and quoted, so it fails
Query: `SELECT * FROM "PG_catalog"."pg_class";`,
Expand All @@ -393,8 +393,7 @@ func TestPgClass(t *testing.T) {
Expected: []sql.Row{
{"PRIMARY"},
{"testing"},
// TODO: Uncomment when views exist on schema
// {"testview"},
{"testview"},
},
},
{
Expand Down Expand Up @@ -3725,10 +3724,17 @@ func TestPgViews(t *testing.T) {
RunScripts(t, []ScriptTest{
{
Name: "pg_views",
SetUpScript: []string{
`CREATE SCHEMA testschema;`,
`SET search_path TO testschema;`,
"CREATE TABLE testing (pk INT primary key, v1 INT);",
`CREATE VIEW testview AS SELECT * FROM testing LIMIT 1;`,
`CREATE VIEW testview2 AS SELECT * FROM testing LIMIT 2;`,
},
Assertions: []ScriptTestAssertion{
{
Query: `SELECT * FROM "pg_catalog"."pg_views";`,
Expected: []sql.Row{},
Query: `SELECT * FROM "pg_catalog"."pg_views" WHERE viewname='testview';`,
Expected: []sql.Row{{"testschema", "testview", "", "SELECT * FROM testing LIMIT 1"}},
},
{ // Different cases and quoted, so it fails
Query: `SELECT * FROM "PG_catalog"."pg_views";`,
Expand All @@ -3740,7 +3746,7 @@ func TestPgViews(t *testing.T) {
},
{ // Different cases but non-quoted, so it works
Query: "SELECT viewname FROM PG_catalog.pg_VIEWS ORDER BY viewname;",
Expected: []sql.Row{},
Expected: []sql.Row{{"testview"}, {"testview2"}},
},
},
},
Expand Down
Loading