diff --git a/pkg/bench/rttanalysis/testdata/benchmark_expectations b/pkg/bench/rttanalysis/testdata/benchmark_expectations index f5f127ac4463..7a9c8fa40964 100644 --- a/pkg/bench/rttanalysis/testdata/benchmark_expectations +++ b/pkg/bench/rttanalysis/testdata/benchmark_expectations @@ -64,8 +64,8 @@ exp,benchmark 4,ORMQueries/django_column_introspection_1_table 4,ORMQueries/django_column_introspection_4_tables 4,ORMQueries/django_column_introspection_8_tables -3,ORMQueries/django_table_introspection_1_table -3,ORMQueries/django_table_introspection_8_tables +5,ORMQueries/django_table_introspection_1_table +5,ORMQueries/django_table_introspection_8_tables 0,ORMQueries/has_column_privilege_using_attnum 0,ORMQueries/has_column_privilege_using_column_name 0,ORMQueries/has_schema_privilege diff --git a/pkg/cli/cliflags/flags.go b/pkg/cli/cliflags/flags.go index e028b470214a..57e845515a44 100644 --- a/pkg/cli/cliflags/flags.go +++ b/pkg/cli/cliflags/flags.go @@ -793,9 +793,9 @@ Note: that --external-io-disable-http or --external-io-disable-implicit-credenti TenantScope = FlagInfo{ Name: "tenant-scope", Description: `Assign a tenant scope to the certificate. -This will allow for the certificate to only be used specifically for a particular -tenant. This flag is optional, when omitted, the certificate is scoped to the -system tenant.`, +This will restrict the certificate to only be valid for the specified tenants. +This flag is optional. When omitted, the certificate is not scoped; i.e. +it can be used with all tenants.`, } GeneratePKCS8Key = FlagInfo{ diff --git a/pkg/cli/clisqlshell/BUILD.bazel b/pkg/cli/clisqlshell/BUILD.bazel index 0403124fddee..829ba04f282a 100644 --- a/pkg/cli/clisqlshell/BUILD.bazel +++ b/pkg/cli/clisqlshell/BUILD.bazel @@ -7,6 +7,7 @@ go_library( "api.go", "complete.go", "context.go", + "describe.go", "doc.go", "editor.go", "editor_bimodal.go", @@ -51,6 +52,7 @@ go_test( name = "clisqlshell_test", srcs = [ "complete_test.go", + "describe_test.go", "editor_bubbline_test.go", "main_test.go", "sql_internal_test.go", diff --git a/pkg/cli/clisqlshell/describe.go b/pkg/cli/clisqlshell/describe.go new file mode 100644 index 000000000000..01c996793795 --- /dev/null +++ b/pkg/cli/clisqlshell/describe.go @@ -0,0 +1,1162 @@ +// Copyright 2022 The Cockroach Authors. +// +// Use of this software is governed by the Business Source License +// included in the file licenses/BSL.txt. +// +// As of the Change Date specified in that file, in accordance with +// the Business Source License, use of this software will be governed +// by the Apache License, Version 2.0, included in the file +// licenses/APL.txt. + +package clisqlshell + +import ( + "fmt" + "regexp" + "strings" + + "github.com/cockroachdb/cockroach/pkg/sql/lexbase" + "github.com/cockroachdb/errors" +) + +var fnDescribeCmdRe = regexp.MustCompile(`^df[anptw]*$`) +var tbDescribeCmdRe = regexp.MustCompile(`^d[tivmsE]*$`) + +// describeStage corresponds to the production of one output tables +// during the execution of a describe command. Each stage has a +// title, and a SQL statement with a number of positional arguments. +type describeStage struct { + title string + sql string + qargs []interface{} +} + +func pgInspect( + args []string, +) (title, sql string, qargs []interface{}, foreach func([]string) []describeStage, err error) { + origCmd := args[0] + args = args[1:] + // Strip the leading `\`. + cmd := origCmd[1:] + + plus := strings.Contains(cmd, "+") + inclSystem := strings.Contains(cmd, "S") + // Remove the characters "S" and "+" from the describe command. + cmd = strings.TrimRight(cmd, "S+") + + var hasPattern bool + switch len(args) { + case 0: + // OK + case 1: + hasPattern = true + qargs = []interface{}{lexbase.EscapeSQLString(args[0])} + default: + return "", "", nil, nil, errors.WithHint( + errors.Newf("unsupported command: %s with %d arguments", origCmd, len(args)), + "Use the SQL SHOW statement to inspect your schema.") + } + + if cmd == `d` && hasPattern { + return "", describeTableDetails(), qargs, describeOneTableDetails(plus), nil + } + + switch { + case cmd == "l": + title, sql = listAllDbs(hasPattern, plus) + case cmd == "dn": + title, sql = listSchemas(hasPattern, plus, inclSystem) + case cmd == "dC": + title, sql = listCasts(hasPattern, plus) + case cmd == "dT": + title, sql = describeTypes(hasPattern, plus, inclSystem) + case cmd == "dd": + title, sql = objectDescription(hasPattern, inclSystem) + case cmd == "dg" || cmd == "du": + title, sql = describeRoles(hasPattern, plus, inclSystem) + case fnDescribeCmdRe.MatchString(cmd): + flags := strings.TrimPrefix(cmd, "df") + title, sql = describeFunctions(flags, hasPattern, plus, inclSystem) + case tbDescribeCmdRe.MatchString(cmd): + flags := strings.TrimPrefix(cmd, "d") + title, sql = listTables(flags, hasPattern, plus, inclSystem) + default: + return "", "", nil, nil, errors.WithHint( + errors.Newf("unsupported command: %s with %d arguments", origCmd, len(args)), + "Use the SQL SHOW statement to inspect your schema.") + } + + return title, sql, qargs, nil, nil +} + +// listAllDbs is adapted from the function of the same name in the +// PostgreSQL sources, file src/bin/psql/describe.c. +// Please keep them in sync. +func listAllDbs(hasPattern bool, verbose bool) (string, string) { + var buf strings.Builder + + buf.WriteString(`SELECT d.datname AS "Name", + pg_catalog.pg_get_userbyid(d.datdba) AS "Owner", + pg_catalog.pg_encoding_to_char(d.encoding) AS "Encoding", + d.datcollate AS "Collate", + d.datctype AS "Ctype",`) + // TODO(sql-sessions): "ICU Locale" and "Locale Provider" + // are omitted because we don't have custom locales in CockroachDB yet. + printACLColumn(&buf, "d.datacl") + if verbose { + // TODO(sql-sessions): "Tablespace" is omitted. + // TODO(sql-sessions): "Size" is omited. + // (pg_database_size is not yet supported.) + buf.WriteString(`, + CASE + WHEN pg_catalog.has_database_privilege(d.datname, 'CONNECT') + THEN IF(d.datconnlimit < 0, 'Unlimited', d.datconnlimit::STRING) + ELSE 'No Access' + END AS "Connections", + COALESCE(pg_catalog.shobj_description(d.oid, 'pg_database'), '') AS "Description"`) + } + buf.WriteString(` + FROM pg_catalog.pg_database d`) + + if hasPattern { + buf.WriteString(` + WHERE d.datname LIKE %[1]s`) + } + + buf.WriteString(` +ORDER BY 1`) + + return "List of databases", buf.String() +} + +// listSchemas is adapted from the function of the same name in the +// PostgreSQL sources, file src/bin/psql/describe.c. +// Please keep them in sync. +func listSchemas(hasPattern bool, verbose, showSystem bool) (string, string) { + var buf strings.Builder + + buf.WriteString(`SELECT n.nspname AS "Name", + pg_catalog.pg_get_userbyid(n.nspowner) AS "Owner"`) + if verbose { + buf.WriteByte(',') + printACLColumn(&buf, "n.nspacl") + buf.WriteString(`, + COALESCE(pg_catalog.obj_description(n.oid, 'pg_namespace'), '') AS "Description"`) + } + buf.WriteString(` + FROM pg_catalog.pg_namespace n + WHERE TRUE`) + + if !showSystem && !hasPattern { + buf.WriteString(` + AND n.nspname !~ '^pg_' + AND n.nspname <> 'crdb_internal' + AND n.nspname <> 'information_schema'`) + } + if hasPattern { + buf.WriteString(` AND n.nspname LIKE %[1]s`) + } + + buf.WriteString(` +ORDER BY 1`) + + return "List of schemas", buf.String() +} + +// objectDescription is adapted from the function of the same name in the +// PostgreSQL sources, file src/bin/psql/describe.c. +// Please keep them in sync. +func objectDescription(hasPattern bool, showSystem bool) (string, string) { + var buf strings.Builder + + buf.WriteString(`SELECT DISTINCT + tt.nspname AS "Schema", + tt.name AS "Name", + tt.object AS "Object", + d.description AS "Description" + FROM (`) + + // Table constraint descriptions. + buf.WriteString(` + SELECT pgc.oid as oid, pgc.conrelid AS tableoid, + n.nspname as nspname, + CAST(pgc.conname AS pg_catalog.text) as name, + CAST('table constraint' AS pg_catalog.text) as object + FROM pg_catalog.pg_constraint pgc + JOIN pg_catalog.pg_class c ON c.oid = pgc.conrelid + LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE TRUE`) + if !showSystem && !hasPattern { + buf.WriteString(` + AND n.nspname !~ '^pg_' + AND n.nspname <> 'crdb_internal' + AND n.nspname <> 'information_schema'`) + } + if hasPattern { + buf.WriteString(` AND pgc.conname LIKE %[1]s`) + } else { + buf.WriteString(` AND pg_catalog.pg_table_is_visible(c.oid)`) + } + + // Domain constraint descriptions. + buf.WriteString(` +UNION ALL + SELECT pgc.oid as oid, pgc.conrelid AS tableoid, + n.nspname as nspname, + CAST(pgc.conname AS pg_catalog.text) AS name, + CAST('domain constraint' AS pg_catalog.text) AS object + FROM pg_catalog.pg_constraint pgc + JOIN pg_catalog.pg_type t ON t.oid = pgc.contypid + LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace + WHERE TRUE`) + if !showSystem && !hasPattern { + buf.WriteString(` + AND n.nspname !~ '^pg_' + AND n.nspname <> 'crdb_internal' + AND n.nspname <> 'information_schema'`) + } + if hasPattern { + buf.WriteString(` AND pgc.conname LIKE %[1]s`) + } else { + buf.WriteString(` AND pg_catalog.pg_type_is_visible(t.oid)`) + } + + // TODO(sql-sessions): The operator class descriptions have been + // omitted here. (pg_opclass is not supported) + // TODO(sql-sessions): The operator family descriptions have been + // omitted here. (pg_opfamily is not supported) + // TODO(sql-sessions): Rewrite rules for view have been omitted + // here. (pg_rewrite is not supported) + + buf.WriteString(`) AS tt + JOIN pg_catalog.pg_description d + ON (tt.oid = d.objoid AND tt.tableoid = d.classoid AND d.objsubid = 0) +ORDER BY 1,2,3`) + + return "Object descriptions", buf.String() +} + +// describeFunctions is adapted from the function fo the same name +// PostgreSQL sources, file src/bin/psql/describe.c. +// Please keep them in sync. +func describeFunctions( + funcTypes string, hasPattern bool, verbose, showSystem bool, +) (string, string) { + showAggregate := strings.IndexByte(funcTypes, 'a') >= 0 + showNormal := strings.IndexByte(funcTypes, 'n') >= 0 + showProcedure := strings.IndexByte(funcTypes, 'p') >= 0 + showTrigger := strings.IndexByte(funcTypes, 't') >= 0 + showWindow := strings.IndexByte(funcTypes, 'w') >= 0 + + if !(showAggregate || showNormal || showProcedure || showTrigger || showWindow) { + showAggregate = true + showNormal = true + showProcedure = true + showTrigger = true + showWindow = true + } + + var buf strings.Builder + buf.WriteString(` SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type"`) + if verbose { + buf.WriteString(`, CASE p.provolatile + WHEN 'i' THEN 'immutable' + WHEN 's' THEN 'stable' + WHEN 'v' THEN 'volatile' + ELSE p.provolatile + END AS "Volatility",`) + // TODO(sql-sessions): Column "Parallel" omitted. + // (pg_proc.proparallel is not supported) + buf.WriteString(` + pg_catalog.pg_get_userbyid(p.proowner) AS "Owner", + CASE WHEN p.prosecdef THEN 'definer' ELSE 'invoker' END AS "Security",`) + printACLColumn(&buf, "p.proacl") + // TODO(sql-sessions): Column "Language" omitted. + // (pg_language is not supported) + // + // TODO(sql-sessions): pg_get_function_sqlbody is not called here + // because it is not supported. + // + // TODO(sql-sessions): The "Description" column is currently + // ineffective for UDFs because of + // https://github.com/cockroachdb/cockroach/issues/44135 + buf.WriteString(`, + p.prosrc AS "Source code", + pg_catalog.obj_description(p.oid, 'pg_proc') AS "Description"`) + } + buf.WriteString(` + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE `) + // TODO(sql-sessions): Filtering based on argument types like + // in PostgreSQL. + // TODO(sql-sessions): join on pg_language when verbose; pg_language + // is not supported. + if showNormal && showAggregate && showProcedure && showTrigger && showWindow { + // Do noting. + } else if showNormal { + if !showAggregate { + // TODO(sql-sessions): Use prokind here. + buf.WriteString(` AND NOT p.proisagg`) + } + if !showProcedure { + buf.WriteString(` AND (p.prokind IS NULL OR p.prokind <> 'p')`) + } + if !showTrigger { + // TODO(sql-session): Use prorettype like in PostgreSQL here. + _ = 0 // disable lint SA9003 + } + if !showWindow { + // TODO(sql-sessions): Use prokind here. + buf.WriteString(` AND NOT p.proiswindow`) + } + } else { + buf.WriteString(` AND (FALSE`) + // Note: at least one of these must be true. + if showAggregate { + // TODO(sql-sessions): Use prokind here. + buf.WriteString(` OR p.proisagg`) + } + if showTrigger { + // TODO(sql-sessions): Use prorettype here. + _ = 0 // disable lint SA9003 + } + if showProcedure { + buf.WriteString(` OR (p.prokind IS NOT NULL AND p.prokind = 'p')`) + } + if showWindow { + buf.WriteString(` OR p.proiswindow`) + } + buf.WriteByte(')') + } + + if !showSystem && !hasPattern { + buf.WriteString(` + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal'`) + } + + if hasPattern { + // TODO(knz): translate pattern to filter on schema name. + buf.WriteString(` AND p.proname LIKE %[1]s`) + // TODO(sql-sessions): Filter by argument types. + } else { + // Only show visible functions. + buf.WriteString(` + AND pg_catalog.pg_function_is_visible(p.oid)`) + } + + buf.WriteString(` ORDER BY 1, 2, 4`) + + return "List of functions", buf.String() +} + +// listTables is adapted from the function of the same name in the +// PostgreSQL sources, file src/bin/psql/describe.c. +// Please keep them in sync. +func listTables(tabTypes string, hasPattern bool, verbose, showSystem bool) (string, string) { + showTables := strings.IndexByte(tabTypes, 't') >= 0 + showIndexes := strings.IndexByte(tabTypes, 'i') >= 0 + showViews := strings.IndexByte(tabTypes, 'v') >= 0 + showMatViews := strings.IndexByte(tabTypes, 'm') >= 0 + showSeq := strings.IndexByte(tabTypes, 's') >= 0 + showForeign := strings.IndexByte(tabTypes, 'E') >= 0 + + if !(showTables || showIndexes || showViews || showMatViews || showSeq || showForeign) { + showTables = true + showIndexes = true + showViews = true + showMatViews = true + showSeq = true + showForeign = true + } + + var buf strings.Builder + buf.WriteString(` 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner"`) + + if showIndexes { + buf.WriteString(`, + c2.relname AS "Table"`) + } + + if verbose { + buf.WriteString(`, + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence"`) + + if showTables || showMatViews || showIndexes { + buf.WriteString(`, + am.amname AS "Access Method"`) + } + + // TODO(sql-sessions): Column "Size" omitted here. + // This is because pg_table_size() is not supported yet. + buf.WriteString(`, + COALESCE(pg_catalog.obj_description(c.oid, 'pg_class'),'') as "Description"`) + } + + buf.WriteString(` + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace`) + + if showTables || showMatViews || showIndexes { + buf.WriteString(` +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam`) + } + if showIndexes { + buf.WriteString(` +LEFT JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid +LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid`) + } + + buf.WriteString(` + WHERE c.relkind IN (`) + + if showTables { + buf.WriteString(`'r','p',`) + if showSystem || hasPattern { + buf.WriteString(`'t',`) + } + } + + if showViews { + buf.WriteString(`'v',`) + } + if showMatViews { + buf.WriteString(`'m',`) + } + if showIndexes { + buf.WriteString(`'i',`) + } + if showSeq { + buf.WriteString(`'S',`) + } + if showSystem || hasPattern { + buf.WriteString(`'s',`) + } + if showForeign { + buf.WriteString(`'f',`) + } + buf.WriteString(`''`) // dummy + buf.WriteString(`)`) + + if !showSystem && !hasPattern { + buf.WriteString(` + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal'`) + } + + if hasPattern { + // TODO(knz): translate pattern to filter on schema name. + buf.WriteString(` + AND c.relname LIKE %[1]s`) + } else { + // Only show visible tables. + buf.WriteString(` + AND pg_catalog.pg_table_is_visible(c.oid)`) + } + + buf.WriteString(` + ORDER BY 1,2`) + + return "List of relations", buf.String() +} + +// listCasts is adapted from the function of the same name in the +// PostgreSQL sources, file src/bin/psql/describe.c. +// Please keep them in sync. +func listCasts(hasPattern bool, verbose bool) (string, string) { + var buf strings.Builder + + buf.WriteString(` SELECT pg_catalog.format_type(castsource, NULL) AS "Source type", + pg_catalog.format_type(casttarget, NULL) AS "Target type", + CASE WHEN c.castmethod = 'b' THEN '(binary coercible)' + WHEN c.castmethod = 'i' THEN '(with inout)' + ELSE p.proname + END AS "Function", + CASE WHEN c.castcontext = 'e' THEN 'no' + WHEN c.castcontext = 'a' THEN 'in assignment' + ELSE 'yes' + END AS "Implicit?"`) + + if verbose { + buf.WriteString(`, + d.description AS "Description"`) + } + + /* + * We need a left join to pg_proc for binary casts; the others are just + * paranoia. + */ + buf.WriteString(` + FROM pg_catalog.pg_cast c +LEFT JOIN pg_catalog.pg_proc p ON c.castfunc = p.oid +LEFT JOIN pg_catalog.pg_type ts ON c.castsource = ts.oid +LEFT JOIN pg_catalog.pg_namespace ns ON ns.oid = ts.typnamespace +LEFT JOIN pg_catalog.pg_type tt ON c.casttarget = tt.oid +LEFT JOIN pg_catalog.pg_namespace nt ON nt.oid = tt.typnamespace`) + + if verbose { + buf.WriteString(` +LEFT JOIN pg_catalog.pg_description d ON d.classoid = c.tableoid AND d.objoid = c.oid AND d.objsubid = 0`) + } + + buf.WriteString(` + WHERE ((true`) + + if hasPattern { + buf.WriteString(` + AND (ts.typname LIKE %[1]s + OR pg_catalog.format_type(ts.oid, NULL) LIKE %[1]s)`) + } else { + buf.WriteString(` + AND pg_catalog.pg_type_is_visible(ts.oid)`) + } + + buf.WriteString(`) + OR (true`) + + if hasPattern { + buf.WriteString(` + AND (tt.typname LIKE %[1]s + OR pg_catalog.format_type(tt.oid, NULL) LIKE %[1]s)`) + } else { + buf.WriteString(` + AND pg_catalog.pg_type_is_visible(tt.oid)`) + } + + buf.WriteString(`)) +ORDER BY 1, 2`) + + return "List of casts", buf.String() +} + +// describeTypes is adapted from the function of the same name in the +// PostgreSQL sources, file src/bin/psql/describe.c. +// Please keep them in sync. +func describeTypes(hasPattern bool, verbose, showSystem bool) (string, string) { + var buf strings.Builder + + buf.WriteString(` SELECT n.nspname AS "Schema", + pg_catalog.format_type(t.oid, NULL) AS "Name",`) + + if verbose { + buf.WriteString(` + t.typname AS "Internal name", + CASE + WHEN t.typrelid != 0 THEN CAST('tuple' AS pg_catalog.text) + WHEN t.typlen < 0 THEN CAST('var' AS pg_catalog.text) + ELSE CAST(t.typlen AS pg_catalog.text) + END AS "Size", + pg_catalog.array_to_string( + ARRAY( + SELECT e.enumlabel + FROM pg_catalog.pg_enum e + WHERE e.enumtypid = t.oid + ORDER BY e.enumsortorder + ), e'\n') AS "Elements", + pg_catalog.pg_get_userbyid(t.typowner) AS "Owner",`) + printACLColumn(&buf, "t.typacl") + buf.WriteByte(',') + } + + buf.WriteString(` + COALESCE(pg_catalog.obj_description(t.oid, 'pg_type'),'') AS "Description" + FROM pg_catalog.pg_type t +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace`) + + // Do not include complex types (typrelid!=0) unless they are standalone + // composite types. + buf.WriteString(` + WHERE (t.typrelid = 0 + OR (SELECT c.relkind = 'c' + FROM pg_catalog.pg_class c + WHERE c.oid = t.typrelid))`) + + // Do not include array types unless the pattern contains []. + // The original source code is: + // if (pattern == NULL || strstr(pattern, "[]") == NULL) + // ... avoid array types using NOT EXISTS ... + // + // Alhough we have an equivalent of "pattern == NULL" here, we + // cannot evaluate the pattern here for "[]": it will only be + // provided later during query expansion in the caller. So what we + // do instead is evaluate it inside SQL. + // + // For this, we transform the original C code to predicate logic: + // P: pattern != NULL + // TA: pattern contains "[]" + // X: type is an array (EXISTS) + // + // The expression from the original source code, expressed in + // predicate logic, is: IF ((!P) OR (!TA)) THEN (!X) + // Boolean formula for "IF A THEN B" is ((!A) OR B) + // + // So the above is equivalent to: + // !((!P) OR (!TA)) OR (!X) + // which is: + // (P AND TA) OR (!X) + buf.WriteString(` + AND (`) + if hasPattern { + buf.WriteString(`%[1]s LIKE '%%[]%%' OR `) + } + buf.WriteString(`NOT EXISTS( + SELECT 1 + FROM pg_catalog.pg_type el + WHERE el.oid = t.typelem AND el.typarray = t.oid))`) + + if !showSystem && !hasPattern { + buf.WriteString(` + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal'`) + } + + if hasPattern { + buf.WriteString(` + AND (t.typname LIKE %[1]s + OR pg_catalog.format_type(t.oid, NULL) LIKE %[1]s)`) + } else { + buf.WriteString(` + AND pg_catalog.pg_type_is_visible(t.oid)`) + } + + buf.WriteString(` +ORDER BY 1, 2`) + + return "List of data types", buf.String() +} + +func printACLColumn(buf *strings.Builder, colname string) { + buf.WriteString(` + COALESCE(pg_catalog.array_to_string(`) + buf.WriteString(colname) + buf.WriteString(`, e'\n'), '') AS "Access privileges"`) +} + +// describeRoles is adapted from the function of the same name in the +// PostgreSQL sources, file src/bin/psql/describe.c. +// Please keep them in sync. +func describeRoles(hasPattern bool, verbose, showSystem bool) (string, string) { + var buf strings.Builder + + buf.WriteString(`WITH roles AS ( +SELECT r.rolname, r.rolsuper, r.rolinherit, + r.rolcreaterole, r.rolcreatedb, r.rolcanlogin, + r.rolconnlimit, r.rolvaliduntil, + ARRAY(SELECT b.rolname + FROM pg_catalog.pg_auth_members m + JOIN pg_catalog.pg_roles b ON (m.roleid = b.oid) + WHERE m.member = r.oid) as memberof`) + + if verbose { + buf.WriteString(`, + pg_catalog.shobj_description(r.oid, 'pg_authid') AS description`) + } + + buf.WriteString(`, + r.rolreplication, r.rolbypassrls + FROM pg_catalog.pg_roles r`) + + if !showSystem && !hasPattern { + buf.WriteString(` + WHERE r.rolname !~ '^pg_'`) + } else if hasPattern { + buf.WriteString(` + WHERE r.rolname LIKE %[1]s`) + } + + // Presentation. + buf.WriteString(`) +SELECT rolname AS "Role name", + array_to_string(ARRAY( + SELECT a FROM (VALUES + (IF(rolsuper, 'Superuser', NULL)), + (IF(NOT rolinherit, 'No inheritance', NULL)), + (IF(rolcreaterole, 'Create role', NULL)), + (IF(rolcreatedb, 'Create DB', NULL)), + (IF(NOT rolcanlogin, 'Cannot login', NULL)), + (IF(rolconnlimit = 0, + 'No connections', + IF(rolconnlimit > 0, + rolconnlimit::STRING || ' connection' || IF(rolconnlimit>1, 's',''), + NULL))), + (IF(rolreplication, 'Replication', NULL)), + (IF(rolbypassrls, 'Bypass RLS', NULL)), + ('Password valid until ' || rolvaliduntil) + ) AS v(a) WHERE v.a IS NOT NULL), + ', ') AS "Attributes", + memberof AS "Member of"`) + + if verbose { + buf.WriteString(`, + COALESCE(description, '') AS "Description"`) + } + + buf.WriteString(` + FROM roles`) + return "List of roles", buf.String() +} + +// describeTableDetails is adapted from the function of the same name in the +// PostgreSQL sources, file src/bin/psql/describe.c. +// Please keep them in sync. +func describeTableDetails() string { + var buf strings.Builder + + // Note: we are pre-computing all the attributes from pg_class + // here that we will need in describeOneTableDetails. + buf.WriteString(` SELECT c.oid, + n.nspname, + c.relname, + c.relkind, + c.relpersistence, + c.relchecks > 0, + c.relhasindex, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE conrelid = c.oid AND contype = 'f') AS relhasfkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE confrelid = c.oid AND contype = 'f') AS relhasifkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_statistic_ext WHERE stxrelid = c.oid) + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname LIKE %[1]s + ORDER BY 2,3`) + + return buf.String() +} + +// describeOneTableDetails is adapted from the function of the same +// name in the PostgreSQL sources, file src/bin/psql/describe.c. +// Please keep them in sync. +func describeOneTableDetails(verbose bool) func([]string) (extraStages []describeStage) { + return func(selectedTable []string) (extraStages []describeStage) { + oid := selectedTable[0] + scName := selectedTable[1] + tName := selectedTable[2] + relkind := selectedTable[3] + relpersistence := selectedTable[4] + relhaschecks := selectedTable[5] + relhasindex := selectedTable[6] + relhasfkey := selectedTable[7] + relhasifkey := selectedTable[8] + relhasstats := selectedTable[9] + + var buf strings.Builder + + var title string + switch relkind { + case "S": // Sequence. + title = fmt.Sprintf(`Sequence "%s.%s"`, scName, tName) + buf.WriteString(` + SELECT pg_catalog.format_type(seqtypid, NULL) AS "Type", + seqstart AS "Start", + seqmin AS "Minimum", + seqmax AS "Maximum", + seqincrement AS "Increment", + CASE WHEN seqcycle THEN 'yes' ELSE 'no' END AS "Cycles?", + seqcache AS "Cache" + FROM pg_catalog.pg_sequence s + WHERE s.reqrelid = %[1]s`) + + // TODO(sql-sessions): The column that owns this sequence + // is omitted here. + + default: + showColDetails := false + switch relkind { + case "r", "v", "m", "f", "c", "p": + showColDetails = true + } + + buf.WriteString(`WITH cols AS ( + SELECT a.attname, + pg_catalog.format_type(a.atttypid, a.atttypmod) AS typname`) + + if showColDetails { + buf.WriteString(`, + (SELECT pg_catalog.pg_get_expr(d.adbin, d.adrelid, true) + FROM pg_catalog.pg_attrdef d + WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef) AS defexpr, + a.attnotnull, + (SELECT c.collname + FROM pg_catalog.pg_collation c, pg_catalog.pg_type t + WHERE c.oid = a.attcollation + AND t.oid = a.atttypid + AND a.attcollation <> t.typcollation) AS attcollation, + a.attidentity, + a.attgenerated`) + } + + if relkind == "i" || relkind == "I" { + // Index. + buf.WriteString(`, + CASE WHEN a.attnum <= ( + SELECT i.indnkeyatts + FROM pg_catalog.pg_index i + WHERE i.indexrelid = %[1]s) THEN 'yes' ELSE 'no' END AS is_key, + pg_catalog.pg_get_indexdef(a.attrelid, a.attnum, TRUE) AS indexdef`) + } + + hasDesc := false + if verbose { + switch relkind { + case "r", "v", "m", "f", "c", "p": + hasDesc = true + buf.WriteString(`, + pg_catalog.col_description(a.attrelid, a.attnum) AS description`) + } + } + + buf.WriteString(` + FROM pg_catalog.pg_attribute a + WHERE a.attrelid = %[1]s AND a.attnum > 0 AND NOT a.attisdropped +ORDER BY a.attnum)`) + + // Select title. + prefix := "" + switch relkind { + case "r": + if relpersistence == "u" { + prefix = "Unlogged table" + } else { + prefix = "Table" + } + case "v": + prefix = "View" + case "i": + prefix = "Index" + case "I": + if relpersistence == "u" { + prefix = "Unlogged partitioned index" + } else { + prefix = "Partitioned index" + } + case "t": + prefix = "TOAST table" + case "c": + prefix = "Composite type" + case "f": + prefix = "Foreign table" + case "p": + if relpersistence == "u" { + prefix = "Unlogged partitioned table" + } else { + prefix = "Partitioned table" + } + default: + prefix = fmt.Sprintf("?%s?", relkind) + } + title = fmt.Sprintf(`%s "%s.%s"`, prefix, scName, tName) + + // Display. + buf.WriteString(` +SELECT attname AS "Column", + typname AS "Type"`) + if showColDetails { + buf.WriteString(`, + COALESCE(attcollation, '') AS "Collation", + IF(attnotnull, 'not null', '') AS "Nullable", + COALESCE( + CASE attidentity + WHEN 'a' THEN 'generated always as identity' + WHEN 'd' THEN 'generated by default as identity' + ELSE CASE attgenerated + WHEN 's' THEN 'generated always as ('||defexpr||') stored' + ELSE defexpr + END + END, '') AS "Default"`) + } + if relkind == "i" || relkind == "I" { + // Index. + buf.WriteString(`, + is_key AS "Key?", + indexdef AS "Definition"`) + } + if hasDesc { + buf.WriteString(`, + COALESCE(description,'') AS "Description"`) + } + + buf.WriteString(` + FROM cols`) + } + + // Assemble the display stages. The first stage is the basic + // information about the table, using the SQL query generated + // above. + // What follows is the footers. + firstStage := describeStage{ + title: title, + sql: buf.String(), + qargs: []interface{}{oid}, + } + extraStages = append(extraStages, firstStage) + + switch relkind { + case "i", "I": + // Footer information about an index. + + buf.Reset() + + buf.WriteString(`WITH idx AS ( +SELECT i.indisunique, i.indisprimary, i.indisclustered, + i.indisvalid, + (NOT i.indimmediate) + AND EXISTS ( + SELECT 1 + FROM pg_catalog.pg_constraint + WHERE conrelid = i.indrelid + AND conindid = i.indexrelid + AND contype IN ('p','u','x') + AND condeferrable + ) AS condeferrable, + (NOT i.indimmediate) + AND EXISTS ( + SELECT 1 + FROM pg_catalog.pg_constraint + WHERE conrelid = i.indrelid + AND conindid = i.indexrelid + AND contype IN ('p','u','x') + AND condeferred + ) AS condeferred, + i.indisreplident, + i.indnullsnotdistinct, + a.amname, c2.relname as indtable, + pg_catalog.pg_get_expr(i.indpred, i.indrelid, true) AS indpred + FROM pg_catalog.pg_index i, + pg_catalog.pg_class c, + pg_catalog.pg_class c2, + pg_catalog.pg_am a + WHERE i.indexrelid = c.oid + AND c.oid = %[1]s + AND c.relam = a.oid + AND i.indrelid = c2.oid) +SELECT IF(indisprimary, 'primary key, ', + IF(indisunique, 'unique'|| + IF(indnullsnotdistinct, ' nulls not distinct', '')||', ', ''))|| + amname||', for table '|| + pg_catalog.quote_ident(%[2]s)||'.'|| + pg_catalog.quote_ident(indtable)|| + IF(length(indpred)>0, ', predicate('||indpred||')', '')|| + IF(indisclustered, ', clustered', '')|| + IF(NOT indisvalid, ', invalid', '')|| + IF(condeferrable, ', deferrable', '')|| + IF(condeferred, ', initially deferred', '')|| + IF(indisreplident, ', replica identity', '') + AS "Properties" + FROM idx`) + + idxStage := describeStage{ + title: "", + sql: buf.String(), + qargs: []interface{}{oid, lexbase.EscapeSQLString(scName)}, + } + extraStages = append(extraStages, idxStage) + } + + switch relkind { + case "r", "m", "f", "p", "I", "t": + // print indexes. + if relhasindex == "t" { + buf.Reset() + + buf.WriteString(`WITH idx AS ( + SELECT c2.relname AS idxname, + i.indisprimary, i.indisunique, i.indisclustered, + i.indisvalid, + pg_catalog.pg_get_indexdef(i.indexrelid, 0, true) as indexdef, + pg_catalog.pg_get_constraintdef(con.oid, true) as condef, + contype, condeferrable, condeferred, + i.indisreplident + FROM pg_catalog.pg_class c, + pg_catalog.pg_class c2, + pg_catalog.pg_index i +LEFT JOIN pg_catalog.pg_constraint con + ON (conrelid = i.indrelid AND conindid = i.indexrelid AND contype IN ('p','u','x')) + WHERE c.oid = %[1]s + AND c.oid = i.indrelid + AND i.indexrelid = c2.oid) +SELECT pg_catalog.quote_ident(idxname) || + IF(contype = 'x', ' ' || condef, + IF(indisprimary, ' PRIMARY KEY,', + IF(indisunique, + IF(contype = 'u', ' UNIQUE CONSTRAINT,', ' UNIQUE,'), ''))|| + ' ' || substring(indexdef FROM position(' USING ' IN indexdef)+7) || + IF(condeferrable, ' DEFERRABLE', '')|| + IF(condeferred, ' INITIALLY DEFERRED', ''))|| + IF(indisclustered, ' CLUSTER', '')|| + IF(NOT indisvalid, ' INVALID', '')|| + IF(indisreplident, ' REPLICA IDENTITY', '') + AS "Indexes" + FROM idx +ORDER BY indisprimary DESC, idxname`) + + idxStage := describeStage{ + title: "", + sql: buf.String(), + qargs: []interface{}{oid}, + } + extraStages = append(extraStages, idxStage) + } + + // print table (and column) check constraints. + + if relhaschecks == "t" { + buf.Reset() + + buf.WriteString(`WITH cons AS ( +SELECT r.conname, + pg_catalog.pg_get_constraintdef(r.oid, true) AS condef + FROM pg_catalog.pg_constraint r + WHERE r.conrelid = %[1]s AND r.contype = 'c' +) + SELECT pg_catalog.quote_ident(conname) || ' ' || condef + AS "Check constraints" + FROM cons +ORDER BY conname`) + + checkStage := describeStage{ + title: "", + sql: buf.String(), + qargs: []interface{}{oid}, + } + extraStages = append(extraStages, checkStage) + } + + // print foreign-key constraints. + if relhasfkey == "t" { + buf.Reset() + buf.WriteString(`WITH cons AS ( +SELECT conname, + pg_catalog.pg_get_constraintdef(r.oid, true) as condef, + conrelid::pg_catalog.regclass AS ontable + FROM pg_catalog.pg_constraint r + WHERE r.conrelid = %[1]s + AND r.contype = 'f' AND (r.conparentid = 0 OR r.conparentid IS NULL)) + SELECT 'TABLE ' || pg_catalog.quote_ident(ontable::STRING) || + ' CONSTRAINT ' || pg_catalog.quote_ident(conname) || ' ' || condef + AS "Foreign-key constraints" + FROM cons +ORDER BY conname`) + + fkeyStage := describeStage{ + title: "", + sql: buf.String(), + qargs: []interface{}{oid}, + } + extraStages = append(extraStages, fkeyStage) + } + + // print incoming foreign-key references. + if relhasifkey == "t" { + buf.Reset() + buf.WriteString(`WITH cons AS ( +SELECT conname, + pg_catalog.pg_get_constraintdef(r.oid, true) as condef, + conrelid::pg_catalog.regclass AS ontable + FROM pg_catalog.pg_constraint r + WHERE r.confrelid = %[1]s + AND r.contype = 'f') + SELECT 'TABLE ' || pg_catalog.quote_ident(ontable::STRING) || + ' CONSTRAINT ' || pg_catalog.quote_ident(conname) || ' ' || condef + AS "Referenced by" + FROM cons +ORDER BY conname`) + + fkeyStage := describeStage{ + title: "", + sql: buf.String(), + qargs: []interface{}{oid}, + } + extraStages = append(extraStages, fkeyStage) + } + + // print any extended statistics + if relhasstats == "t" && verbose { + buf.Reset() + + buf.WriteString(`WITH stat AS ( +SELECT oid, + stxrelid::pg_catalog.regclass AS tb, + stxnamespace::pg_catalog.regnamespace AS nsp, + stxname, + (SELECT pg_catalog.string_agg(pg_catalog.quote_ident(attname),', ') + FROM pg_catalog.unnest(stxkeys) s(attnum) + JOIN pg_catalog.pg_attribute a + ON (stxrelid = a.attrelid + AND a.attnum = s.attnum + AND NOT attisdropped) + ) AS columns, + 'd' = any(stxkind) AS hasndist, + 'f' = any(stxkind) AS hasdeps, + 'm' = any(stxkind) AS hasmcv, + stxstattarget + FROM pg_catalog.pg_statistic_ext stat + WHERE stxrelid = %[1]s) + SELECT pg_catalog.quote_ident(nsp)||'.'||pg_catalog.quote_ident(stxname)|| + IF((hasndist OR hasdeps OR hasmcv) AND NOT (hasndist AND hasdeps AND hasmcv), + '('|| + IF(hasndist, + 'ndistinct' || IF(hasdeps OR hasmcv, ', ', ''), + '')|| + IF(hasdeps, 'dependencies' || IF(hasmcv, ', ', ''), '')|| + IF(hasmcv, 'mcv', '')|| + ')', + '')|| + ' ON '||columns||' FROM ' || pg_catalog.quote_ident(tb::STRING) || + IF(stxstattarget <> -1 AND stxstattarget IS NOT NULL, + '; STATISTICS ' || stxstattarget::STRING, '') + AS "Statistics objects" + FROM stat +ORDER BY stat.oid`) + + statStage := describeStage{ + title: "", + sql: buf.String(), + qargs: []interface{}{oid}, + } + extraStages = append(extraStages, statStage) + } + } + + switch relkind { + case "v", "m": + if verbose { + viewStage := describeStage{ + title: "", + sql: `SELECT pg_catalog.pg_get_viewdef(%[1]s::pg_catalog.oid, true) AS "View definition"`, + qargs: []interface{}{oid}, + } + extraStages = append(extraStages, viewStage) + } + } + return extraStages + } +} diff --git a/pkg/cli/clisqlshell/describe_test.go b/pkg/cli/clisqlshell/describe_test.go new file mode 100644 index 000000000000..d5628348c757 --- /dev/null +++ b/pkg/cli/clisqlshell/describe_test.go @@ -0,0 +1,75 @@ +// Copyright 2022 The Cockroach Authors. +// +// Use of this software is governed by the Business Source License +// included in the file licenses/BSL.txt. +// +// As of the Change Date specified in that file, in accordance with +// the Business Source License, use of this software will be governed +// by the Apache License, Version 2.0, included in the file +// licenses/APL.txt. + +package clisqlshell_test + +import ( + "strings" + "testing" + + "github.com/cockroachdb/cockroach/pkg/cli" + "github.com/cockroachdb/cockroach/pkg/testutils/serverutils" + "github.com/cockroachdb/cockroach/pkg/util/leaktest" + "github.com/cockroachdb/datadriven" +) + +// Example_describe_unknown checks an error path. +func Example_describe_unknown() { + c := cli.NewCLITest(cli.TestCLIParams{}) + defer c.Cleanup() + + c.RunWithArgs([]string{`sql`, `-e`, `\set echo`, `-e`, `\dz`}) + + // Output: + // sql -e \set echo -e \dz + // ERROR: unsupported command: \dz with 0 arguments + // HINT: Use the SQL SHOW statement to inspect your schema. + // ERROR: -e: unsupported command: \dz with 0 arguments + // HINT: Use the SQL SHOW statement to inspect your schema. +} + +func TestDescribe(t *testing.T) { + defer leaktest.AfterTest(t)() + + c := cli.NewCLITest(cli.TestCLIParams{T: t}) + defer c.Cleanup() + + db := serverutils.OpenDBConn( + t, c.TestServer.ServingSQLAddr(), "defaultdb", false /* insecure */, c.TestServer.Stopper()) + + var commonArgs []string + + datadriven.RunTest(t, "testdata/describe", func(t *testing.T, td *datadriven.TestData) string { + switch td.Cmd { + case "sql": + _, err := db.Exec(td.Input) + if err != nil { + t.Fatalf("%s: sql error: %v", td.Pos, err) + } + return "ok" + + case "common": + commonArgs = strings.Split(td.Input, "\n") + return "ok" + + case "cli": + args := strings.Split(td.Input, "\n") + out, err := c.RunWithCaptureArgs(append(commonArgs, args...)) + if err != nil { + t.Fatalf("%s: %v", td.Pos, err) + } + return out + + default: + t.Fatalf("%s: unknown command: %q", td.Pos, td.Cmd) + return "" // unreachable + } + }) +} diff --git a/pkg/cli/clisqlshell/sql.go b/pkg/cli/clisqlshell/sql.go index a56975bbaf83..84a4814d8f3a 100644 --- a/pkg/cli/clisqlshell/sql.go +++ b/pkg/cli/clisqlshell/sql.go @@ -80,13 +80,24 @@ Input/Output \qecho [STRING] write the provided string to the query output stream (see \o). Informational - \l list all databases in the CockroachDB cluster. - \dt show the tables of the current schema in the current database. - \dT show the user defined types of the current database. - \du [USER] list the specified user, or list the users for all databases if no user is specified. - \d [TABLE] show details about columns in the specified table, or alias for '\dt' if no table is specified. - \dd TABLE show details about constraints on the specified table. - \df show the functions that are defined in the current database. + \d[tivms][S+] [PATTERN] list stored objects [only tables/indexes/views/matviews/sequences]. + \dC[S+] [PATTERN] list casts. + \dd[S+] [PATTERN] list object descriptions not displayed elsewhere. + \df[anptw][S+] [PATTERN] list [only agg/normal/procedures/trigger/window] functions. + \dg[S+] [PATTERN] list users and roles. + \di[S+] [PATTERN] list only indexes. + \dm[S+] [PATTERN] list only materialized views. + \dn[S+] [PATTERN] list schemas. + \dp [PATTERN] list table, view, and sequence access privileges. + \ds[S+] [PATTERN] list only sequences. + \dt[S+] [PATTERN] list only tables. + \dT[S+] [PATTERN] list data types. + \du[S+] [PATTERN] same as \dg. + \dv[S+] [PATTERN] list only views. + \l[+] [PATTERN] list databases. + \sf[+] FUNCNAME show a function's definition. + \sv[+] VIEWNAME show a view's definition. + \z [PATTERN] same as \dp. Formatting \x [on|off] toggle records display format. @@ -1230,6 +1241,75 @@ func (c *cliState) setupChangefeedOutput() (undo func(), err error) { } +func (c *cliState) handleDescribe(cmd []string, loopState, errState cliStateEnum) cliStateEnum { + var title, sql string + var qargs []interface{} + var foreach func([]string) []describeStage + title, sql, qargs, foreach, c.exitErr = pgInspect(cmd) + if c.exitErr != nil { + clierror.OutputError(c.iCtx.stderr, c.exitErr, true /*showSeverity*/, false /*verbose*/) + return errState + } + + if title != "" { + fmt.Fprintf(c.iCtx.stdout, "%s:\n", title) + } + var toRun []describeStage + + if foreach == nil { + // A single stage. + toRun = []describeStage{{sql: sql, qargs: qargs}} + } else { + // There's N stages, each produced by the foreach function + // applied on the result of the original SQL. Used mainly by \d. + var rows [][]string + c.exitErr = c.runWithInterruptableCtx(func(ctx context.Context) error { + q := clisqlclient.MakeQuery(fmt.Sprintf(sql, qargs...)) + var err error + _, rows, err = c.sqlExecCtx.RunQuery( + ctx, c.conn, q, + true, /* showMoreChars */ + ) + return err + }) + if c.exitErr != nil { + if !c.singleStatement { + clierror.OutputError(c.iCtx.stderr, c.exitErr, true /*showSeverity*/, false /*verbose*/) + } + return errState + } + + for _, row := range rows { + extraStages := foreach(row) + toRun = append(toRun, extraStages...) + } + } + + for _, st := range toRun { + if st.title != "" { + fmt.Fprintln(c.iCtx.queryOutput, st.title) + } + c.exitErr = c.runWithInterruptableCtx(func(ctx context.Context) error { + q := clisqlclient.MakeQuery(fmt.Sprintf(st.sql, st.qargs...)) + return c.sqlExecCtx.RunQueryAndFormatResults( + ctx, + c.conn, + c.iCtx.queryOutput, // query output. + io.Discard, // we hide timings for describe commands. + c.iCtx.stderr, + q, + ) + }) + if c.exitErr != nil { + if !c.singleStatement { + clierror.OutputError(c.iCtx.stderr, c.exitErr, true /*showSeverity*/, false /*verbose*/) + } + return errState + } + } + return loopState +} + func (c *cliState) doHandleCliCmd(loopState, nextState cliStateEnum) cliStateEnum { if len(c.lastInputLine) == 0 || c.lastInputLine[0] != '\\' { return nextState @@ -1251,6 +1331,17 @@ func (c *cliState) doHandleCliCmd(loopState, nextState cliStateEnum) cliStateEnu line := strings.TrimRight(c.lastInputLine, "; ") cmd := strings.Fields(line) + if cmd[0] == `\z` { + // psql compatibility. + cmd[0] = `\dp` + } + if cmd[0] == `\sf` || cmd[0] == `\sf+` || + cmd[0] == `\sv` || cmd[0] == `\sv+` || + cmd[0] == `\l` || cmd[0] == `\l+` || + (strings.HasPrefix(cmd[0], `\d`) && cmd[0] != `\demo`) { + return c.handleDescribe(cmd, loopState, errState) + } + switch cmd[0] { case `\q`, `\quit`, `\exit`: return cliStop @@ -1346,18 +1437,6 @@ ORDER BY 1` } return c.handleFunctionHelp(cmd[1:], loopState, errState) - case `\l`: - c.concatLines = `SHOW DATABASES` - return cliRunStatement - - case `\dt`: - c.concatLines = `SHOW TABLES` - return cliRunStatement - - case `\df`: - c.concatLines = `SHOW FUNCTIONS` - return cliRunStatement - case `\copy`: c.exitErr = c.runWithInterruptableCtx(func(ctx context.Context) error { // Strip out the starting \ in \copy. @@ -1381,35 +1460,6 @@ ORDER BY 1` } return c.invalidSyntax(errState) - case `\dT`: - c.concatLines = `SHOW TYPES` - return cliRunStatement - - case `\du`: - if len(cmd) == 1 { - c.concatLines = `SHOW USERS` - return cliRunStatement - } else if len(cmd) == 2 { - c.concatLines = fmt.Sprintf(`SELECT * FROM [SHOW USERS] WHERE username = %s`, lexbase.EscapeSQLString(cmd[1])) - return cliRunStatement - } - return c.invalidSyntax(errState) - - case `\d`: - if len(cmd) == 1 { - c.concatLines = `SHOW TABLES` - return cliRunStatement - } else if len(cmd) == 2 { - c.concatLines = `SHOW COLUMNS FROM ` + cmd[1] - return cliRunStatement - } - return c.invalidSyntax(errState) - case `\dd`: - if len(cmd) == 2 { - c.concatLines = `SHOW CONSTRAINTS FROM ` + cmd[1] + ` WITH COMMENT` - return cliRunStatement - } - return c.invalidSyntax(errState) case `\connect`, `\c`: return c.handleConnect(cmd[1:], loopState, errState) @@ -1445,10 +1495,6 @@ ORDER BY 1` return c.handleStatementDiag(cmd[1:], loopState, errState) default: - if strings.HasPrefix(cmd[0], `\d`) { - // Unrecognized command for now, but we want to be helpful. - fmt.Fprint(c.iCtx.stderr, "Suggestion: use the SQL SHOW statement to inspect your schema.\n") - } return c.invalidSyntax(errState) } diff --git a/pkg/cli/clisqlshell/sql_internal_test.go b/pkg/cli/clisqlshell/sql_internal_test.go index a3e5bf9e65c9..46b20d603cdc 100644 --- a/pkg/cli/clisqlshell/sql_internal_test.go +++ b/pkg/cli/clisqlshell/sql_internal_test.go @@ -91,41 +91,11 @@ func TestIsEndOfStatement(t *testing.T) { } } -// Test handleCliCmd cases for client-side commands that are aliases for sql -// statements. -func TestHandleCliCmdSqlAlias(t *testing.T) { - defer leaktest.AfterTest(t)() - defer log.Scope(t).Close(t) - - clientSideCommandTestsTable := []struct { - commandString string - wantSQLStmt string - }{ - {`\l`, `SHOW DATABASES`}, - {`\dt`, `SHOW TABLES`}, - {`\dT`, `SHOW TYPES`}, - {`\du`, `SHOW USERS`}, - {`\du myuser`, `SELECT * FROM [SHOW USERS] WHERE username = 'myuser'`}, - {`\d mytable`, `SHOW COLUMNS FROM mytable`}, - {`\d`, `SHOW TABLES`}, - {`\df`, `SHOW FUNCTIONS`}, - } - - for _, tt := range clientSideCommandTestsTable { - c := setupTestCliState() - c.lastInputLine = tt.commandString - gotState := c.doHandleCliCmd(cliStateEnum(0), cliStateEnum(1)) - - assert.Equal(t, cliRunStatement, gotState) - assert.Equal(t, tt.wantSQLStmt, c.concatLines) - } -} - func TestHandleCliCmdSlashDInvalidSyntax(t *testing.T) { defer leaktest.AfterTest(t)() defer log.Scope(t).Close(t) - clientSideCommandTests := []string{`\d goodarg badarg`, `\dz`} + clientSideCommandTests := []string{`\d goodarg badarg`} for _, tt := range clientSideCommandTests { c := setupTestCliState() @@ -133,7 +103,6 @@ func TestHandleCliCmdSlashDInvalidSyntax(t *testing.T) { gotState := c.doHandleCliCmd(cliStateEnum(0), cliStateEnum(1)) assert.Equal(t, cliStateEnum(0), gotState) - assert.Equal(t, errInvalidSyntax, c.exitErr) } } diff --git a/pkg/cli/clisqlshell/sql_test.go b/pkg/cli/clisqlshell/sql_test.go index eb36d945e3f3..8a5cb3234343 100644 --- a/pkg/cli/clisqlshell/sql_test.go +++ b/pkg/cli/clisqlshell/sql_test.go @@ -37,7 +37,7 @@ func Example_sql() { c.RunWithArgs([]string{`sql`, `-e`, `begin`, `-e`, `select 3 as "3"`, `-e`, `commit`}) c.RunWithArgs([]string{`sql`, `-e`, `select * from t.f`}) c.RunWithArgs([]string{`sql`, `--execute=SELECT database_name, owner FROM [show databases]`}) - c.RunWithArgs([]string{`sql`, `-e`, `\l`, `-e`, `\echo hello`}) + c.RunWithArgs([]string{`sql`, `-e`, `\echo hello`}) c.RunWithArgs([]string{`sql`, `-e`, `select 1 as "1"; select 2 as "2"`}) c.RunWithArgs([]string{`sql`, `-e`, `select 1 as "1"; select 2 as "@" where false`}) // CREATE TABLE AS returns a SELECT tag with a row count, check this. @@ -59,8 +59,6 @@ func Example_sql() { // first batch consisting of 1 row has been returned to the client. c.RunWithArgs([]string{`sql`, `-e`, `select 1/(i-2) from generate_series(1,3) g(i)`}) c.RunWithArgs([]string{`sql`, `-e`, `SELECT '20:01:02+03:04:05'::timetz AS regression_65066`}) - c.RunWithArgs([]string{`sql`, `-e`, `CREATE USER my_user WITH CREATEDB; GRANT admin TO my_user;`}) - c.RunWithArgs([]string{`sql`, `-e`, `\du my_user`}) // Output: // sql -e show application_name @@ -89,12 +87,7 @@ func Example_sql() { // postgres root // system node // t root - // sql -e \l -e \echo hello - // database_name owner primary_region secondary_region regions survival_goal - // defaultdb root NULL NULL {} NULL - // postgres root NULL NULL {} NULL - // system node NULL NULL {} NULL - // t root NULL NULL {} NULL + // sql -e \echo hello // hello // sql -e select 1 as "1"; select 2 as "2" // 1 @@ -125,12 +118,6 @@ func Example_sql() { // sql -e SELECT '20:01:02+03:04:05'::timetz AS regression_65066 // regression_65066 // 20:01:02+03:04:05 - // sql -e CREATE USER my_user WITH CREATEDB; GRANT admin TO my_user; - // CREATE ROLE - // GRANT - // sql -e \du my_user - // username options member_of - // my_user CREATEDB {admin} } func Example_sql_config() { diff --git a/pkg/cli/clisqlshell/testdata/describe b/pkg/cli/clisqlshell/testdata/describe new file mode 100644 index 000000000000..0bb165a51a4b --- /dev/null +++ b/pkg/cli/clisqlshell/testdata/describe @@ -0,0 +1,2615 @@ +common +sql +-e +\set echo +-e +\set display_format csv +-e +---- +ok + +# Note: add comments on views / sequences when this issue is fixed: +# https://github.com/cockroachdb/cockroach/issues/44135 +sql +create database mydb; +comment on database mydb is 'my awesome db comment'; +create table mytable(mycolumn int, check (mycolumn > 123)); +comment on table mytable is 'my awesome tb comment'; +create index myidx on mytable(mycolumn); +comment on index mytable@myidx is 'my awesome idx comment'; +create materialized view mymview as select mycolumn from mytable; +create view myview as select mycolumn from mytable; +create table ftable1(x int unique); +create table ftable2(x int references ftable1(x)); +create sequence myseq; +create type mytyp as enum('hello'); +create user myuser; grant admin to myuser; +create function myfunc(val int) returns int language sql as $$ select val $$; +---- +ok + +subtest list_dbs + +cli +\l +---- +sql -e \set echo -e \set display_format csv -e \l +List of databases: +> SELECT d.datname AS "Name", + pg_catalog.pg_get_userbyid(d.datdba) AS "Owner", + pg_catalog.pg_encoding_to_char(d.encoding) AS "Encoding", + d.datcollate AS "Collate", + d.datctype AS "Ctype", + COALESCE(pg_catalog.array_to_string(d.datacl, e'\n'), '') AS "Access privileges" + FROM pg_catalog.pg_database d +ORDER BY 1 +Name,Owner,Encoding,Collate,Ctype,Access privileges +defaultdb,root,UTF8,en_US.utf8,en_US.utf8, +mydb,root,UTF8,en_US.utf8,en_US.utf8, +postgres,root,UTF8,en_US.utf8,en_US.utf8, +system,unknown (OID=3233629770),UTF8,en_US.utf8,en_US.utf8, + +cli +\l+ +---- +sql -e \set echo -e \set display_format csv -e \l+ +List of databases: +> SELECT d.datname AS "Name", + pg_catalog.pg_get_userbyid(d.datdba) AS "Owner", + pg_catalog.pg_encoding_to_char(d.encoding) AS "Encoding", + d.datcollate AS "Collate", + d.datctype AS "Ctype", + COALESCE(pg_catalog.array_to_string(d.datacl, e'\n'), '') AS "Access privileges", + CASE + WHEN pg_catalog.has_database_privilege(d.datname, 'CONNECT') + THEN IF(d.datconnlimit < 0, 'Unlimited', d.datconnlimit::STRING) + ELSE 'No Access' + END AS "Connections", + COALESCE(pg_catalog.shobj_description(d.oid, 'pg_database'), '') AS "Description" + FROM pg_catalog.pg_database d +ORDER BY 1 +Name,Owner,Encoding,Collate,Ctype,Access privileges,Connections,Description +defaultdb,root,UTF8,en_US.utf8,en_US.utf8,,Unlimited, +mydb,root,UTF8,en_US.utf8,en_US.utf8,,Unlimited,my awesome db comment +postgres,root,UTF8,en_US.utf8,en_US.utf8,,Unlimited, +system,unknown (OID=3233629770),UTF8,en_US.utf8,en_US.utf8,,Unlimited, + +cli +\l my% +---- +sql -e \set echo -e \set display_format csv -e \l my% +List of databases: +> SELECT d.datname AS "Name", + pg_catalog.pg_get_userbyid(d.datdba) AS "Owner", + pg_catalog.pg_encoding_to_char(d.encoding) AS "Encoding", + d.datcollate AS "Collate", + d.datctype AS "Ctype", + COALESCE(pg_catalog.array_to_string(d.datacl, e'\n'), '') AS "Access privileges" + FROM pg_catalog.pg_database d + WHERE d.datname LIKE 'my%' +ORDER BY 1 +Name,Owner,Encoding,Collate,Ctype,Access privileges +mydb,root,UTF8,en_US.utf8,en_US.utf8, + +subtest end + +subtest list_schemas + +cli +\dn +---- +sql -e \set echo -e \set display_format csv -e \dn +List of schemas: +> SELECT n.nspname AS "Name", + pg_catalog.pg_get_userbyid(n.nspowner) AS "Owner" + FROM pg_catalog.pg_namespace n + WHERE TRUE + AND n.nspname !~ '^pg_' + AND n.nspname <> 'crdb_internal' + AND n.nspname <> 'information_schema' +ORDER BY 1 +Name,Owner +public,admin + +cli +\dn p% +---- +sql -e \set echo -e \set display_format csv -e \dn p% +List of schemas: +> SELECT n.nspname AS "Name", + pg_catalog.pg_get_userbyid(n.nspowner) AS "Owner" + FROM pg_catalog.pg_namespace n + WHERE TRUE AND n.nspname LIKE 'p%' +ORDER BY 1 +Name,Owner +pg_catalog,NULL +pg_extension,NULL +public,admin + +cli +\dn+ +---- +sql -e \set echo -e \set display_format csv -e \dn+ +List of schemas: +> SELECT n.nspname AS "Name", + pg_catalog.pg_get_userbyid(n.nspowner) AS "Owner", + COALESCE(pg_catalog.array_to_string(n.nspacl, e'\n'), '') AS "Access privileges", + COALESCE(pg_catalog.obj_description(n.oid, 'pg_namespace'), '') AS "Description" + FROM pg_catalog.pg_namespace n + WHERE TRUE + AND n.nspname !~ '^pg_' + AND n.nspname <> 'crdb_internal' + AND n.nspname <> 'information_schema' +ORDER BY 1 +Name,Owner,Access privileges,Description +public,admin,, + +cli +\dn+ p% +---- +sql -e \set echo -e \set display_format csv -e \dn+ p% +List of schemas: +> SELECT n.nspname AS "Name", + pg_catalog.pg_get_userbyid(n.nspowner) AS "Owner", + COALESCE(pg_catalog.array_to_string(n.nspacl, e'\n'), '') AS "Access privileges", + COALESCE(pg_catalog.obj_description(n.oid, 'pg_namespace'), '') AS "Description" + FROM pg_catalog.pg_namespace n + WHERE TRUE AND n.nspname LIKE 'p%' +ORDER BY 1 +Name,Owner,Access privileges,Description +pg_catalog,NULL,, +pg_extension,NULL,, +public,admin,, + +cli +\dnS +---- +sql -e \set echo -e \set display_format csv -e \dnS +List of schemas: +> SELECT n.nspname AS "Name", + pg_catalog.pg_get_userbyid(n.nspowner) AS "Owner" + FROM pg_catalog.pg_namespace n + WHERE TRUE +ORDER BY 1 +Name,Owner +crdb_internal,NULL +information_schema,NULL +pg_catalog,NULL +pg_extension,NULL +public,admin + +cli +\dnS+ +---- +sql -e \set echo -e \set display_format csv -e \dnS+ +List of schemas: +> SELECT n.nspname AS "Name", + pg_catalog.pg_get_userbyid(n.nspowner) AS "Owner", + COALESCE(pg_catalog.array_to_string(n.nspacl, e'\n'), '') AS "Access privileges", + COALESCE(pg_catalog.obj_description(n.oid, 'pg_namespace'), '') AS "Description" + FROM pg_catalog.pg_namespace n + WHERE TRUE +ORDER BY 1 +Name,Owner,Access privileges,Description +crdb_internal,NULL,, +information_schema,NULL,, +pg_catalog,NULL,, +pg_extension,NULL,, +public,admin,, + +subtest end + +subtest list_objects + +cli +\d +---- +sql -e \set echo -e \set display_format csv -e \d +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + c2.relname AS "Table" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam +LEFT JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid +LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid + WHERE c.relkind IN ('r','p','v','m','i','S','f','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner,Table +public,ftable1,table,root,NULL +public,ftable1_pkey,index,root,ftable1 +public,ftable1_x_key,index,root,ftable1 +public,ftable2,table,root,NULL +public,ftable2_pkey,index,root,ftable2 +public,myidx,index,root,mytable +public,mymview,materialized view,root,NULL +public,mymview_pkey,index,root,mymview +public,myseq,sequence,root,NULL +public,mytable,table,root,NULL +public,mytable_pkey,index,root,mytable +public,myview,view,root,NULL + +cli +\dS +---- +sql -e \set echo -e \set display_format csv -e \dS +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + c2.relname AS "Table" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam +LEFT JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid +LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid + WHERE c.relkind IN ('r','p','t','v','m','i','S','s','f','') + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner,Table +pg_catalog,pg_aggregate,table,admin,NULL +pg_catalog,pg_am,table,admin,NULL +pg_catalog,pg_amop,table,admin,NULL +pg_catalog,pg_amproc,table,admin,NULL +pg_catalog,pg_attrdef,table,admin,NULL +pg_catalog,pg_attrdef_adrelid_idx,index,admin,NULL +pg_catalog,pg_attribute,table,admin,NULL +pg_catalog,pg_attribute_attrelid_idx,index,admin,NULL +pg_catalog,pg_auth_members,table,admin,NULL +pg_catalog,pg_authid,table,admin,NULL +pg_catalog,pg_available_extension_versions,table,admin,NULL +pg_catalog,pg_available_extensions,table,admin,NULL +pg_catalog,pg_cast,table,admin,NULL +pg_catalog,pg_class,table,admin,NULL +pg_catalog,pg_class_oid_idx,index,admin,NULL +pg_catalog,pg_collation,table,admin,NULL +pg_catalog,pg_config,table,admin,NULL +pg_catalog,pg_constraint,table,admin,NULL +pg_catalog,pg_constraint_conrelid_idx,index,admin,NULL +pg_catalog,pg_conversion,table,admin,NULL +pg_catalog,pg_cursors,table,admin,NULL +pg_catalog,pg_database,table,admin,NULL +pg_catalog,pg_db_role_setting,table,admin,NULL +pg_catalog,pg_default_acl,table,admin,NULL +pg_catalog,pg_depend,table,admin,NULL +pg_catalog,pg_description,table,admin,NULL +pg_catalog,pg_enum,table,admin,NULL +pg_catalog,pg_event_trigger,table,admin,NULL +pg_catalog,pg_extension,table,admin,NULL +pg_catalog,pg_file_settings,table,admin,NULL +pg_catalog,pg_foreign_data_wrapper,table,admin,NULL +pg_catalog,pg_foreign_server,table,admin,NULL +pg_catalog,pg_foreign_table,table,admin,NULL +pg_catalog,pg_group,table,admin,NULL +pg_catalog,pg_hba_file_rules,table,admin,NULL +pg_catalog,pg_index,table,admin,NULL +pg_catalog,pg_indexes,table,admin,NULL +pg_catalog,pg_inherits,table,admin,NULL +pg_catalog,pg_init_privs,table,admin,NULL +pg_catalog,pg_language,table,admin,NULL +pg_catalog,pg_largeobject,table,admin,NULL +pg_catalog,pg_largeobject_metadata,table,admin,NULL +pg_catalog,pg_locks,table,admin,NULL +pg_catalog,pg_matviews,table,admin,NULL +pg_catalog,pg_namespace,table,admin,NULL +pg_catalog,pg_namespace_oid_idx,index,admin,NULL +pg_catalog,pg_opclass,table,admin,NULL +pg_catalog,pg_operator,table,admin,NULL +pg_catalog,pg_opfamily,table,admin,NULL +pg_catalog,pg_partitioned_table,table,admin,NULL +pg_catalog,pg_policies,table,admin,NULL +pg_catalog,pg_policy,table,admin,NULL +pg_catalog,pg_prepared_statements,table,admin,NULL +pg_catalog,pg_prepared_xacts,table,admin,NULL +pg_catalog,pg_proc,table,admin,NULL +pg_catalog,pg_proc_oid_idx,index,admin,NULL +pg_catalog,pg_publication,table,admin,NULL +pg_catalog,pg_publication_rel,table,admin,NULL +pg_catalog,pg_publication_tables,table,admin,NULL +pg_catalog,pg_range,table,admin,NULL +pg_catalog,pg_replication_origin,table,admin,NULL +pg_catalog,pg_replication_origin_status,table,admin,NULL +pg_catalog,pg_replication_slots,table,admin,NULL +pg_catalog,pg_rewrite,table,admin,NULL +pg_catalog,pg_roles,table,admin,NULL +pg_catalog,pg_rules,table,admin,NULL +pg_catalog,pg_seclabel,table,admin,NULL +pg_catalog,pg_seclabels,table,admin,NULL +pg_catalog,pg_sequence,table,admin,NULL +pg_catalog,pg_sequences,table,admin,NULL +pg_catalog,pg_settings,table,admin,NULL +pg_catalog,pg_shadow,table,admin,NULL +pg_catalog,pg_shdepend,table,admin,NULL +pg_catalog,pg_shdescription,table,admin,NULL +pg_catalog,pg_shmem_allocations,table,admin,NULL +pg_catalog,pg_shseclabel,table,admin,NULL +pg_catalog,pg_stat_activity,table,admin,NULL +pg_catalog,pg_stat_all_indexes,table,admin,NULL +pg_catalog,pg_stat_all_tables,table,admin,NULL +pg_catalog,pg_stat_archiver,table,admin,NULL +pg_catalog,pg_stat_bgwriter,table,admin,NULL +pg_catalog,pg_stat_database,table,admin,NULL +pg_catalog,pg_stat_database_conflicts,table,admin,NULL +pg_catalog,pg_stat_gssapi,table,admin,NULL +pg_catalog,pg_stat_progress_analyze,table,admin,NULL +pg_catalog,pg_stat_progress_basebackup,table,admin,NULL +pg_catalog,pg_stat_progress_cluster,table,admin,NULL +pg_catalog,pg_stat_progress_create_index,table,admin,NULL +pg_catalog,pg_stat_progress_vacuum,table,admin,NULL +pg_catalog,pg_stat_replication,table,admin,NULL +pg_catalog,pg_stat_slru,table,admin,NULL +pg_catalog,pg_stat_ssl,table,admin,NULL +pg_catalog,pg_stat_subscription,table,admin,NULL +pg_catalog,pg_stat_sys_indexes,table,admin,NULL +pg_catalog,pg_stat_sys_tables,table,admin,NULL +pg_catalog,pg_stat_user_functions,table,admin,NULL +pg_catalog,pg_stat_user_indexes,table,admin,NULL +pg_catalog,pg_stat_user_tables,table,admin,NULL +pg_catalog,pg_stat_wal_receiver,table,admin,NULL +pg_catalog,pg_stat_xact_all_tables,table,admin,NULL +pg_catalog,pg_stat_xact_sys_tables,table,admin,NULL +pg_catalog,pg_stat_xact_user_functions,table,admin,NULL +pg_catalog,pg_stat_xact_user_tables,table,admin,NULL +pg_catalog,pg_statio_all_indexes,table,admin,NULL +pg_catalog,pg_statio_all_sequences,table,admin,NULL +pg_catalog,pg_statio_all_tables,table,admin,NULL +pg_catalog,pg_statio_sys_indexes,table,admin,NULL +pg_catalog,pg_statio_sys_sequences,table,admin,NULL +pg_catalog,pg_statio_sys_tables,table,admin,NULL +pg_catalog,pg_statio_user_indexes,table,admin,NULL +pg_catalog,pg_statio_user_sequences,table,admin,NULL +pg_catalog,pg_statio_user_tables,table,admin,NULL +pg_catalog,pg_statistic,table,admin,NULL +pg_catalog,pg_statistic_ext,table,admin,NULL +pg_catalog,pg_statistic_ext_data,table,admin,NULL +pg_catalog,pg_stats,table,admin,NULL +pg_catalog,pg_stats_ext,table,admin,NULL +pg_catalog,pg_subscription,table,admin,NULL +pg_catalog,pg_subscription_rel,table,admin,NULL +pg_catalog,pg_tables,table,admin,NULL +pg_catalog,pg_tablespace,table,admin,NULL +pg_catalog,pg_timezone_abbrevs,table,admin,NULL +pg_catalog,pg_timezone_names,table,admin,NULL +pg_catalog,pg_timezone_names_name_idx,index,admin,NULL +pg_catalog,pg_transform,table,admin,NULL +pg_catalog,pg_trigger,table,admin,NULL +pg_catalog,pg_ts_config,table,admin,NULL +pg_catalog,pg_ts_config_map,table,admin,NULL +pg_catalog,pg_ts_dict,table,admin,NULL +pg_catalog,pg_ts_parser,table,admin,NULL +pg_catalog,pg_ts_template,table,admin,NULL +pg_catalog,pg_type,table,admin,NULL +pg_catalog,pg_type_oid_idx,index,admin,NULL +pg_catalog,pg_user,table,admin,NULL +pg_catalog,pg_user_mapping,table,admin,NULL +pg_catalog,pg_user_mappings,table,admin,NULL +pg_catalog,pg_views,table,admin,NULL +pg_extension,geography_columns,table,admin,NULL +pg_extension,geometry_columns,table,admin,NULL +pg_extension,spatial_ref_sys,table,admin,NULL +public,ftable1,table,root,NULL +public,ftable1_pkey,index,root,ftable1 +public,ftable1_x_key,index,root,ftable1 +public,ftable2,table,root,NULL +public,ftable2_pkey,index,root,ftable2 +public,myidx,index,root,mytable +public,mymview,materialized view,root,NULL +public,mymview_pkey,index,root,mymview +public,myseq,sequence,root,NULL +public,mytable,table,root,NULL +public,mytable_pkey,index,root,mytable +public,myview,view,root,NULL + +cli +\d+ +---- +sql -e \set echo -e \set display_format csv -e \d+ +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + c2.relname AS "Table", + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence", + am.amname AS "Access Method", + 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 +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam +LEFT JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid +LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid + WHERE c.relkind IN ('r','p','v','m','i','S','f','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner,Table,Persistence,Access Method,Description +public,ftable1,table,root,NULL,permanent,prefix, +public,ftable1_pkey,index,root,ftable1,permanent,prefix, +public,ftable1_x_key,index,root,ftable1,permanent,prefix, +public,ftable2,table,root,NULL,permanent,prefix, +public,ftable2_pkey,index,root,ftable2,permanent,prefix, +public,myidx,index,root,mytable,permanent,prefix,my awesome idx comment +public,mymview,materialized view,root,NULL,permanent,NULL, +public,mymview_pkey,index,root,mymview,permanent,prefix, +public,myseq,sequence,root,NULL,permanent,NULL, +public,mytable,table,root,NULL,permanent,prefix,my awesome tb comment +public,mytable_pkey,index,root,mytable,permanent,prefix, +public,myview,view,root,NULL,permanent,NULL, + +cli +\dS+ +---- +sql -e \set echo -e \set display_format csv -e \dS+ +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + c2.relname AS "Table", + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence", + am.amname AS "Access Method", + 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 +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam +LEFT JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid +LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid + WHERE c.relkind IN ('r','p','t','v','m','i','S','s','f','') + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner,Table,Persistence,Access Method,Description +pg_catalog,pg_aggregate,table,admin,NULL,permanent,prefix,"aggregated built-in functions (incomplete) +https://www.postgresql.org/docs/9.6/catalog-pg-aggregate.html" +pg_catalog,pg_am,table,admin,NULL,permanent,prefix,"index access methods (incomplete) +https://www.postgresql.org/docs/9.5/catalog-pg-am.html" +pg_catalog,pg_amop,table,admin,NULL,permanent,prefix,pg_amop was created for compatibility and is currently unimplemented +pg_catalog,pg_amproc,table,admin,NULL,permanent,prefix,pg_amproc was created for compatibility and is currently unimplemented +pg_catalog,pg_attrdef,table,admin,NULL,permanent,prefix,"column default values +https://www.postgresql.org/docs/9.5/catalog-pg-attrdef.html" +pg_catalog,pg_attrdef_adrelid_idx,index,admin,NULL,permanent,prefix, +pg_catalog,pg_attribute,table,admin,NULL,permanent,prefix,"table columns (incomplete - see also information_schema.columns) +https://www.postgresql.org/docs/12/catalog-pg-attribute.html" +pg_catalog,pg_attribute_attrelid_idx,index,admin,NULL,permanent,prefix, +pg_catalog,pg_auth_members,table,admin,NULL,permanent,prefix,"role membership +https://www.postgresql.org/docs/9.5/catalog-pg-auth-members.html" +pg_catalog,pg_authid,table,admin,NULL,permanent,prefix,"authorization identifiers - differs from postgres as we do not display passwords, +and thus do not require admin privileges for access. +https://www.postgresql.org/docs/9.5/catalog-pg-authid.html" +pg_catalog,pg_available_extension_versions,table,admin,NULL,permanent,prefix,pg_available_extension_versions was created for compatibility and is currently unimplemented +pg_catalog,pg_available_extensions,table,admin,NULL,permanent,prefix,"available extensions +https://www.postgresql.org/docs/9.6/view-pg-available-extensions.html" +pg_catalog,pg_cast,table,admin,NULL,permanent,prefix,"casts (empty - needs filling out) +https://www.postgresql.org/docs/9.6/catalog-pg-cast.html" +pg_catalog,pg_class,table,admin,NULL,permanent,prefix,"tables and relation-like objects (incomplete - see also information_schema.tables/sequences/views) +https://www.postgresql.org/docs/9.5/catalog-pg-class.html" +pg_catalog,pg_class_oid_idx,index,admin,NULL,permanent,prefix, +pg_catalog,pg_collation,table,admin,NULL,permanent,prefix,"available collations (incomplete) +https://www.postgresql.org/docs/9.5/catalog-pg-collation.html" +pg_catalog,pg_config,table,admin,NULL,permanent,prefix,pg_config was created for compatibility and is currently unimplemented +pg_catalog,pg_constraint,table,admin,NULL,permanent,prefix,"table constraints (incomplete - see also information_schema.table_constraints) +https://www.postgresql.org/docs/9.5/catalog-pg-constraint.html" +pg_catalog,pg_constraint_conrelid_idx,index,admin,NULL,permanent,prefix, +pg_catalog,pg_conversion,table,admin,NULL,permanent,prefix,"encoding conversions (empty - unimplemented) +https://www.postgresql.org/docs/9.6/catalog-pg-conversion.html" +pg_catalog,pg_cursors,table,admin,NULL,permanent,prefix,"contains currently active SQL cursors created with DECLARE +https://www.postgresql.org/docs/14/view-pg-cursors.html" +pg_catalog,pg_database,table,admin,NULL,permanent,prefix,"available databases (incomplete) +https://www.postgresql.org/docs/9.5/catalog-pg-database.html" +pg_catalog,pg_db_role_setting,table,admin,NULL,permanent,prefix,"contains the default values that have been configured for session variables +https://www.postgresql.org/docs/13/catalog-pg-db-role-setting.html" +pg_catalog,pg_default_acl,table,admin,NULL,permanent,prefix,"default ACLs; these are the privileges that will be assigned to newly created objects +https://www.postgresql.org/docs/13/catalog-pg-default-acl.html" +pg_catalog,pg_depend,table,admin,NULL,permanent,prefix,"dependency relationships (incomplete) +https://www.postgresql.org/docs/9.5/catalog-pg-depend.html" +pg_catalog,pg_description,table,admin,NULL,permanent,prefix,"object comments +https://www.postgresql.org/docs/9.5/catalog-pg-description.html" +pg_catalog,pg_enum,table,admin,NULL,permanent,prefix,"enum types and labels (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-enum.html" +pg_catalog,pg_event_trigger,table,admin,NULL,permanent,prefix,"event triggers (empty - feature does not exist) +https://www.postgresql.org/docs/9.6/catalog-pg-event-trigger.html" +pg_catalog,pg_extension,table,admin,NULL,permanent,prefix,"installed extensions (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-extension.html" +pg_catalog,pg_file_settings,table,admin,NULL,permanent,prefix,pg_file_settings was created for compatibility and is currently unimplemented +pg_catalog,pg_foreign_data_wrapper,table,admin,NULL,permanent,prefix,"foreign data wrappers (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-foreign-data-wrapper.html" +pg_catalog,pg_foreign_server,table,admin,NULL,permanent,prefix,"foreign servers (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-foreign-server.html" +pg_catalog,pg_foreign_table,table,admin,NULL,permanent,prefix,"foreign tables (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-foreign-table.html" +pg_catalog,pg_group,table,admin,NULL,permanent,prefix,pg_group was created for compatibility and is currently unimplemented +pg_catalog,pg_hba_file_rules,table,admin,NULL,permanent,prefix,pg_hba_file_rules was created for compatibility and is currently unimplemented +pg_catalog,pg_index,table,admin,NULL,permanent,prefix,"indexes (incomplete) +https://www.postgresql.org/docs/9.5/catalog-pg-index.html" +pg_catalog,pg_indexes,table,admin,NULL,permanent,prefix,"index creation statements +https://www.postgresql.org/docs/9.5/view-pg-indexes.html" +pg_catalog,pg_inherits,table,admin,NULL,permanent,prefix,"table inheritance hierarchy (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-inherits.html" +pg_catalog,pg_init_privs,table,admin,NULL,permanent,prefix,pg_init_privs was created for compatibility and is currently unimplemented +pg_catalog,pg_language,table,admin,NULL,permanent,prefix,"available languages (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-language.html" +pg_catalog,pg_largeobject,table,admin,NULL,permanent,prefix,pg_largeobject was created for compatibility and is currently unimplemented +pg_catalog,pg_largeobject_metadata,table,admin,NULL,permanent,prefix,pg_largeobject_metadata was created for compatibility and is currently unimplemented +pg_catalog,pg_locks,table,admin,NULL,permanent,prefix,"locks held by active processes (empty - feature does not exist) +https://www.postgresql.org/docs/9.6/view-pg-locks.html" +pg_catalog,pg_matviews,table,admin,NULL,permanent,prefix,"available materialized views (empty - feature does not exist) +https://www.postgresql.org/docs/9.6/view-pg-matviews.html" +pg_catalog,pg_namespace,table,admin,NULL,permanent,prefix,"available namespaces +https://www.postgresql.org/docs/9.5/catalog-pg-namespace.html" +pg_catalog,pg_namespace_oid_idx,index,admin,NULL,permanent,prefix, +pg_catalog,pg_opclass,table,admin,NULL,permanent,prefix,"opclass (empty - Operator classes not supported yet) +https://www.postgresql.org/docs/12/catalog-pg-opclass.html" +pg_catalog,pg_operator,table,admin,NULL,permanent,prefix,"operators (incomplete) +https://www.postgresql.org/docs/9.5/catalog-pg-operator.html" +pg_catalog,pg_opfamily,table,admin,NULL,permanent,prefix,pg_opfamily was created for compatibility and is currently unimplemented +pg_catalog,pg_partitioned_table,table,admin,NULL,permanent,prefix,pg_partitioned_table was created for compatibility and is currently unimplemented +pg_catalog,pg_policies,table,admin,NULL,permanent,prefix,pg_policies was created for compatibility and is currently unimplemented +pg_catalog,pg_policy,table,admin,NULL,permanent,prefix,pg_policy was created for compatibility and is currently unimplemented +pg_catalog,pg_prepared_statements,table,admin,NULL,permanent,prefix,"prepared statements +https://www.postgresql.org/docs/9.6/view-pg-prepared-statements.html" +pg_catalog,pg_prepared_xacts,table,admin,NULL,permanent,prefix,"prepared transactions (empty - feature does not exist) +https://www.postgresql.org/docs/9.6/view-pg-prepared-xacts.html" +pg_catalog,pg_proc,table,admin,NULL,permanent,prefix,"built-in functions (incomplete) +https://www.postgresql.org/docs/9.5/catalog-pg-proc.html" +pg_catalog,pg_proc_oid_idx,index,admin,NULL,permanent,prefix, +pg_catalog,pg_publication,table,admin,NULL,permanent,prefix,pg_publication was created for compatibility and is currently unimplemented +pg_catalog,pg_publication_rel,table,admin,NULL,permanent,prefix,pg_publication_rel was created for compatibility and is currently unimplemented +pg_catalog,pg_publication_tables,table,admin,NULL,permanent,prefix,pg_publication_tables was created for compatibility and is currently unimplemented +pg_catalog,pg_range,table,admin,NULL,permanent,prefix,"range types (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-range.html" +pg_catalog,pg_replication_origin,table,admin,NULL,permanent,prefix,pg_replication_origin was created for compatibility and is currently unimplemented +pg_catalog,pg_replication_origin_status,table,admin,NULL,permanent,prefix,pg_replication_origin_status was created for compatibility and is currently unimplemented +pg_catalog,pg_replication_slots,table,admin,NULL,permanent,prefix,pg_replication_slots was created for compatibility and is currently unimplemented +pg_catalog,pg_rewrite,table,admin,NULL,permanent,prefix,"rewrite rules (only for referencing on pg_depend for table-view dependencies) +https://www.postgresql.org/docs/9.5/catalog-pg-rewrite.html" +pg_catalog,pg_roles,table,admin,NULL,permanent,prefix,"database roles +https://www.postgresql.org/docs/9.5/view-pg-roles.html" +pg_catalog,pg_rules,table,admin,NULL,permanent,prefix,pg_rules was created for compatibility and is currently unimplemented +pg_catalog,pg_seclabel,table,admin,NULL,permanent,prefix,"security labels (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-seclabel.html" +pg_catalog,pg_seclabels,table,admin,NULL,permanent,prefix,"security labels (empty) +https://www.postgresql.org/docs/9.6/view-pg-seclabels.html" +pg_catalog,pg_sequence,table,admin,NULL,permanent,prefix,"sequences (see also information_schema.sequences) +https://www.postgresql.org/docs/9.5/catalog-pg-sequence.html" +pg_catalog,pg_sequences,table,admin,NULL,permanent,prefix,"pg_sequences is very similar as pg_sequence. +https://www.postgresql.org/docs/13/view-pg-sequences.html +" +pg_catalog,pg_settings,table,admin,NULL,permanent,prefix,"session variables (incomplete) +https://www.postgresql.org/docs/9.5/catalog-pg-settings.html" +pg_catalog,pg_shadow,table,admin,NULL,permanent,prefix,"pg_shadow lists properties for roles that are marked as rolcanlogin in pg_authid +https://www.postgresql.org/docs/13/view-pg-shadow.html" +pg_catalog,pg_shdepend,table,admin,NULL,permanent,prefix,"Shared Dependencies (Roles depending on objects). +https://www.postgresql.org/docs/9.6/catalog-pg-shdepend.html" +pg_catalog,pg_shdescription,table,admin,NULL,permanent,prefix,"shared object comments +https://www.postgresql.org/docs/9.5/catalog-pg-shdescription.html" +pg_catalog,pg_shmem_allocations,table,admin,NULL,permanent,prefix,pg_shmem_allocations was created for compatibility and is currently unimplemented +pg_catalog,pg_shseclabel,table,admin,NULL,permanent,prefix,"shared security labels (empty - feature not supported) +https://www.postgresql.org/docs/9.5/catalog-pg-shseclabel.html" +pg_catalog,pg_stat_activity,table,admin,NULL,permanent,prefix,"backend access statistics (empty - monitoring works differently in CockroachDB) +https://www.postgresql.org/docs/9.6/monitoring-stats.html#PG-STAT-ACTIVITY-VIEW" +pg_catalog,pg_stat_all_indexes,table,admin,NULL,permanent,prefix,pg_stat_all_indexes was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_all_tables,table,admin,NULL,permanent,prefix,pg_stat_all_tables was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_archiver,table,admin,NULL,permanent,prefix,pg_stat_archiver was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_bgwriter,table,admin,NULL,permanent,prefix,pg_stat_bgwriter was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_database,table,admin,NULL,permanent,prefix,pg_stat_database was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_database_conflicts,table,admin,NULL,permanent,prefix,pg_stat_database_conflicts was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_gssapi,table,admin,NULL,permanent,prefix,pg_stat_gssapi was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_progress_analyze,table,admin,NULL,permanent,prefix,pg_stat_progress_analyze was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_progress_basebackup,table,admin,NULL,permanent,prefix,pg_stat_progress_basebackup was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_progress_cluster,table,admin,NULL,permanent,prefix,pg_stat_progress_cluster was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_progress_create_index,table,admin,NULL,permanent,prefix,pg_stat_progress_create_index was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_progress_vacuum,table,admin,NULL,permanent,prefix,pg_stat_progress_vacuum was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_replication,table,admin,NULL,permanent,prefix,pg_stat_replication was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_slru,table,admin,NULL,permanent,prefix,pg_stat_slru was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_ssl,table,admin,NULL,permanent,prefix,pg_stat_ssl was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_subscription,table,admin,NULL,permanent,prefix,pg_stat_subscription was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_sys_indexes,table,admin,NULL,permanent,prefix,pg_stat_sys_indexes was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_sys_tables,table,admin,NULL,permanent,prefix,pg_stat_sys_tables was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_user_functions,table,admin,NULL,permanent,prefix,pg_stat_user_functions was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_user_indexes,table,admin,NULL,permanent,prefix,pg_stat_user_indexes was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_user_tables,table,admin,NULL,permanent,prefix,pg_stat_user_tables was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_wal_receiver,table,admin,NULL,permanent,prefix,pg_stat_wal_receiver was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_xact_all_tables,table,admin,NULL,permanent,prefix,pg_stat_xact_all_tables was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_xact_sys_tables,table,admin,NULL,permanent,prefix,pg_stat_xact_sys_tables was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_xact_user_functions,table,admin,NULL,permanent,prefix,pg_stat_xact_user_functions was created for compatibility and is currently unimplemented +pg_catalog,pg_stat_xact_user_tables,table,admin,NULL,permanent,prefix,pg_stat_xact_user_tables was created for compatibility and is currently unimplemented +pg_catalog,pg_statio_all_indexes,table,admin,NULL,permanent,prefix,pg_statio_all_indexes was created for compatibility and is currently unimplemented +pg_catalog,pg_statio_all_sequences,table,admin,NULL,permanent,prefix,pg_statio_all_sequences was created for compatibility and is currently unimplemented +pg_catalog,pg_statio_all_tables,table,admin,NULL,permanent,prefix,pg_statio_all_tables was created for compatibility and is currently unimplemented +pg_catalog,pg_statio_sys_indexes,table,admin,NULL,permanent,prefix,pg_statio_sys_indexes was created for compatibility and is currently unimplemented +pg_catalog,pg_statio_sys_sequences,table,admin,NULL,permanent,prefix,pg_statio_sys_sequences was created for compatibility and is currently unimplemented +pg_catalog,pg_statio_sys_tables,table,admin,NULL,permanent,prefix,pg_statio_sys_tables was created for compatibility and is currently unimplemented +pg_catalog,pg_statio_user_indexes,table,admin,NULL,permanent,prefix,pg_statio_user_indexes was created for compatibility and is currently unimplemented +pg_catalog,pg_statio_user_sequences,table,admin,NULL,permanent,prefix,pg_statio_user_sequences was created for compatibility and is currently unimplemented +pg_catalog,pg_statio_user_tables,table,admin,NULL,permanent,prefix,pg_statio_user_tables was created for compatibility and is currently unimplemented +pg_catalog,pg_statistic,table,admin,NULL,permanent,prefix,pg_statistic was created for compatibility and is currently unimplemented +pg_catalog,pg_statistic_ext,table,admin,NULL,permanent,prefix,"pg_statistic_ext has the statistics objects created with CREATE STATISTICS +https://www.postgresql.org/docs/13/catalog-pg-statistic-ext.html" +pg_catalog,pg_statistic_ext_data,table,admin,NULL,permanent,prefix,pg_statistic_ext_data was created for compatibility and is currently unimplemented +pg_catalog,pg_stats,table,admin,NULL,permanent,prefix,pg_stats was created for compatibility and is currently unimplemented +pg_catalog,pg_stats_ext,table,admin,NULL,permanent,prefix,pg_stats_ext was created for compatibility and is currently unimplemented +pg_catalog,pg_subscription,table,admin,NULL,permanent,prefix,pg_subscription was created for compatibility and is currently unimplemented +pg_catalog,pg_subscription_rel,table,admin,NULL,permanent,prefix,pg_subscription_rel was created for compatibility and is currently unimplemented +pg_catalog,pg_tables,table,admin,NULL,permanent,prefix,"tables summary (see also information_schema.tables, pg_catalog.pg_class) +https://www.postgresql.org/docs/9.5/view-pg-tables.html" +pg_catalog,pg_tablespace,table,admin,NULL,permanent,prefix,"available tablespaces (incomplete; concept inapplicable to CockroachDB) +https://www.postgresql.org/docs/9.5/catalog-pg-tablespace.html" +pg_catalog,pg_timezone_abbrevs,table,admin,NULL,permanent,prefix,pg_timezone_abbrevs was created for compatibility and is currently unimplemented +pg_catalog,pg_timezone_names,table,admin,NULL,permanent,prefix,pg_timezone_names lists all the timezones that are supported by SET timezone +pg_catalog,pg_timezone_names_name_idx,index,admin,NULL,permanent,prefix, +pg_catalog,pg_transform,table,admin,NULL,permanent,prefix,pg_transform was created for compatibility and is currently unimplemented +pg_catalog,pg_trigger,table,admin,NULL,permanent,prefix,"triggers (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-trigger.html" +pg_catalog,pg_ts_config,table,admin,NULL,permanent,prefix,pg_ts_config was created for compatibility and is currently unimplemented +pg_catalog,pg_ts_config_map,table,admin,NULL,permanent,prefix,pg_ts_config_map was created for compatibility and is currently unimplemented +pg_catalog,pg_ts_dict,table,admin,NULL,permanent,prefix,pg_ts_dict was created for compatibility and is currently unimplemented +pg_catalog,pg_ts_parser,table,admin,NULL,permanent,prefix,pg_ts_parser was created for compatibility and is currently unimplemented +pg_catalog,pg_ts_template,table,admin,NULL,permanent,prefix,pg_ts_template was created for compatibility and is currently unimplemented +pg_catalog,pg_type,table,admin,NULL,permanent,prefix,"scalar types (incomplete) +https://www.postgresql.org/docs/9.5/catalog-pg-type.html" +pg_catalog,pg_type_oid_idx,index,admin,NULL,permanent,prefix, +pg_catalog,pg_user,table,admin,NULL,permanent,prefix,"database users +https://www.postgresql.org/docs/9.5/view-pg-user.html" +pg_catalog,pg_user_mapping,table,admin,NULL,permanent,prefix,"local to remote user mapping (empty - feature does not exist) +https://www.postgresql.org/docs/9.5/catalog-pg-user-mapping.html" +pg_catalog,pg_user_mappings,table,admin,NULL,permanent,prefix,pg_user_mappings was created for compatibility and is currently unimplemented +pg_catalog,pg_views,table,admin,NULL,permanent,prefix,"view definitions (incomplete - see also information_schema.views) +https://www.postgresql.org/docs/9.5/view-pg-views.html" +pg_extension,geography_columns,table,admin,NULL,permanent,prefix,Shows all defined geography columns. Matches PostGIS' geography_columns functionality. +pg_extension,geometry_columns,table,admin,NULL,permanent,prefix,Shows all defined geometry columns. Matches PostGIS' geometry_columns functionality. +pg_extension,spatial_ref_sys,table,admin,NULL,permanent,prefix,Shows all defined Spatial Reference Identifiers (SRIDs). Matches PostGIS' spatial_ref_sys table. +public,ftable1,table,root,NULL,permanent,prefix, +public,ftable1_pkey,index,root,ftable1,permanent,prefix, +public,ftable1_x_key,index,root,ftable1,permanent,prefix, +public,ftable2,table,root,NULL,permanent,prefix, +public,ftable2_pkey,index,root,ftable2,permanent,prefix, +public,myidx,index,root,mytable,permanent,prefix,my awesome idx comment +public,mymview,materialized view,root,NULL,permanent,NULL, +public,mymview_pkey,index,root,mymview,permanent,prefix, +public,myseq,sequence,root,NULL,permanent,NULL, +public,mytable,table,root,NULL,permanent,prefix,my awesome tb comment +public,mytable_pkey,index,root,mytable,permanent,prefix, +public,myview,view,root,NULL,permanent,NULL, + +subtest end + +subtest list_tables + +cli +\dt +---- +sql -e \set echo -e \set display_format csv -e \dt +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam + WHERE c.relkind IN ('r','p','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner +public,ftable1,table,root +public,ftable2,table,root +public,mytable,table,root + +subtest end + +subtest list_indexes + +cli +\di +---- +sql -e \set echo -e \set display_format csv -e \di +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + c2.relname AS "Table" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam +LEFT JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid +LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid + WHERE c.relkind IN ('i','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner,Table +public,ftable1_pkey,index,root,ftable1 +public,ftable1_x_key,index,root,ftable1 +public,ftable2_pkey,index,root,ftable2 +public,myidx,index,root,mytable +public,mymview_pkey,index,root,mymview +public,mytable_pkey,index,root,mytable + +cli +\di+ +---- +sql -e \set echo -e \set display_format csv -e \di+ +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + c2.relname AS "Table", + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence", + am.amname AS "Access Method", + 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 +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam +LEFT JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid +LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid + WHERE c.relkind IN ('i','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner,Table,Persistence,Access Method,Description +public,ftable1_pkey,index,root,ftable1,permanent,prefix, +public,ftable1_x_key,index,root,ftable1,permanent,prefix, +public,ftable2_pkey,index,root,ftable2,permanent,prefix, +public,myidx,index,root,mytable,permanent,prefix,my awesome idx comment +public,mymview_pkey,index,root,mymview,permanent,prefix, +public,mytable_pkey,index,root,mytable,permanent,prefix, + +cli +\di myidx +---- +sql -e \set echo -e \set display_format csv -e \di myidx +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + c2.relname AS "Table" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam +LEFT JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid +LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid + WHERE c.relkind IN ('i','s','') + AND c.relname LIKE 'myidx' + ORDER BY 1,2 +Schema,Name,Type,Owner,Table +public,myidx,index,root,mytable + +cli +\di+ myidx +---- +sql -e \set echo -e \set display_format csv -e \di+ myidx +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + c2.relname AS "Table", + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence", + am.amname AS "Access Method", + 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 +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam +LEFT JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid +LEFT JOIN pg_catalog.pg_class c2 ON i.indrelid = c2.oid + WHERE c.relkind IN ('i','s','') + AND c.relname LIKE 'myidx' + ORDER BY 1,2 +Schema,Name,Type,Owner,Table,Persistence,Access Method,Description +public,myidx,index,root,mytable,permanent,prefix,my awesome idx comment + +subtest end + +subtest list_materialized_views + +cli +\dm +---- +sql -e \set echo -e \set display_format csv -e \dm +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam + WHERE c.relkind IN ('m','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner +public,mymview,materialized view,root + +cli +\dm mymview +---- +sql -e \set echo -e \set display_format csv -e \dm mymview +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam + WHERE c.relkind IN ('m','s','') + AND c.relname LIKE 'mymview' + ORDER BY 1,2 +Schema,Name,Type,Owner +public,mymview,materialized view,root + +cli +\dm+ +---- +sql -e \set echo -e \set display_format csv -e \dm+ +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence", + am.amname AS "Access Method", + 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 +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam + WHERE c.relkind IN ('m','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner,Persistence,Access Method,Description +public,mymview,materialized view,root,permanent,NULL, + +cli +\dm+ mymview +---- +sql -e \set echo -e \set display_format csv -e \dm+ mymview +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence", + am.amname AS "Access Method", + 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 +LEFT JOIN pg_catalog.pg_am am ON am.oid = c.relam + WHERE c.relkind IN ('m','s','') + AND c.relname LIKE 'mymview' + ORDER BY 1,2 +Schema,Name,Type,Owner,Persistence,Access Method,Description +public,mymview,materialized view,root,permanent,NULL, + +subtest end + + +subtest list_views + +cli +\dv +---- +sql -e \set echo -e \set display_format csv -e \dv +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace + WHERE c.relkind IN ('v','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner +public,myview,view,root + +cli +\dv myview +---- +sql -e \set echo -e \set display_format csv -e \dv myview +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace + WHERE c.relkind IN ('v','s','') + AND c.relname LIKE 'myview' + ORDER BY 1,2 +Schema,Name,Type,Owner +public,myview,view,root + +cli +\dv+ +---- +sql -e \set echo -e \set display_format csv -e \dv+ +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence", + 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 + WHERE c.relkind IN ('v','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner,Persistence,Description +public,myview,view,root,permanent, + +cli +\dv+ myview +---- +sql -e \set echo -e \set display_format csv -e \dv+ myview +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence", + 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 + WHERE c.relkind IN ('v','s','') + AND c.relname LIKE 'myview' + ORDER BY 1,2 +Schema,Name,Type,Owner,Persistence,Description +public,myview,view,root,permanent, + +subtest end + +subtest list_sequences + +cli +\ds +---- +sql -e \set echo -e \set display_format csv -e \ds +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace + WHERE c.relkind IN ('S','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner +public,myseq,sequence,root + +cli +\ds+ +---- +sql -e \set echo -e \set display_format csv -e \ds+ +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence", + 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 + WHERE c.relkind IN ('S','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner,Persistence,Description +public,myseq,sequence,root,permanent, + +cli +\ds mys% +---- +sql -e \set echo -e \set display_format csv -e \ds mys% +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace + WHERE c.relkind IN ('S','s','') + AND c.relname LIKE 'mys%' + ORDER BY 1,2 +Schema,Name,Type,Owner +public,myseq,sequence,root + +cli +\ds+ mys% +---- +sql -e \set echo -e \set display_format csv -e \ds+ mys% +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner", + CASE c.relpersistence + WHEN 'p' THEN 'permanent' + WHEN 't' THEN 'temporary' + WHEN 'u' THEN 'unlogged' END AS "Persistence", + 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 + WHERE c.relkind IN ('S','s','') + AND c.relname LIKE 'mys%' + ORDER BY 1,2 +Schema,Name,Type,Owner,Persistence,Description +public,myseq,sequence,root,permanent, + +subtest end + +subtest multiple_types + +cli +\dvs +---- +sql -e \set echo -e \set display_format csv -e \dvs +List of relations: +> 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 't' THEN 'TOAST table' + WHEN 'f' THEN 'foreign table' + WHEN 'p' THEN 'partitioned table' + WHEN 'I' THEN 'partitioned index' + END as "Type", + pg_catalog.pg_get_userbyid(c.relowner) as "Owner" + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n on n.oid = c.relnamespace + WHERE c.relkind IN ('v','S','') + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_table_is_visible(c.oid) + ORDER BY 1,2 +Schema,Name,Type,Owner +public,myseq,sequence,root +public,myview,view,root + +subtest end + +subtest list_table_details + +cli +\d mytable +---- +sql -e \set echo -e \set display_format csv -e \d mytable +> SELECT c.oid, + n.nspname, + c.relname, + c.relkind, + c.relpersistence, + c.relchecks > 0, + c.relhasindex, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE conrelid = c.oid AND contype = 'f') AS relhasfkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE confrelid = c.oid AND contype = 'f') AS relhasifkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_statistic_ext WHERE stxrelid = c.oid) + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname LIKE 'mytable' + ORDER BY 2,3 +Table "public.mytable" +> WITH cols AS ( + SELECT a.attname, + pg_catalog.format_type(a.atttypid, a.atttypmod) AS typname, + (SELECT pg_catalog.pg_get_expr(d.adbin, d.adrelid, true) + FROM pg_catalog.pg_attrdef d + WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef) AS defexpr, + a.attnotnull, + (SELECT c.collname + FROM pg_catalog.pg_collation c, pg_catalog.pg_type t + WHERE c.oid = a.attcollation + AND t.oid = a.atttypid + AND a.attcollation <> t.typcollation) AS attcollation, + a.attidentity, + a.attgenerated + FROM pg_catalog.pg_attribute a + WHERE a.attrelid = 106 AND a.attnum > 0 AND NOT a.attisdropped +ORDER BY a.attnum) +SELECT attname AS "Column", + typname AS "Type", + COALESCE(attcollation, '') AS "Collation", + IF(attnotnull, 'not null', '') AS "Nullable", + COALESCE( + CASE attidentity + WHEN 'a' THEN 'generated always as identity' + WHEN 'd' THEN 'generated by default as identity' + ELSE CASE attgenerated + WHEN 's' THEN 'generated always as ('||defexpr||') stored' + ELSE defexpr + END + END, '') AS "Default" + FROM cols +Column,Type,Collation,Nullable,Default +mycolumn,bigint,,, +rowid,bigint,,not null,unique_rowid() +> WITH idx AS ( + SELECT c2.relname AS idxname, + i.indisprimary, i.indisunique, i.indisclustered, + i.indisvalid, + pg_catalog.pg_get_indexdef(i.indexrelid, 0, true) as indexdef, + pg_catalog.pg_get_constraintdef(con.oid, true) as condef, + contype, condeferrable, condeferred, + i.indisreplident + FROM pg_catalog.pg_class c, + pg_catalog.pg_class c2, + pg_catalog.pg_index i +LEFT JOIN pg_catalog.pg_constraint con + ON (conrelid = i.indrelid AND conindid = i.indexrelid AND contype IN ('p','u','x')) + WHERE c.oid = 106 + AND c.oid = i.indrelid + AND i.indexrelid = c2.oid) +SELECT pg_catalog.quote_ident(idxname) || + IF(contype = 'x', ' ' || condef, + IF(indisprimary, ' PRIMARY KEY,', + IF(indisunique, + IF(contype = 'u', ' UNIQUE CONSTRAINT,', ' UNIQUE,'), ''))|| + ' ' || substring(indexdef FROM position(' USING ' IN indexdef)+7) || + IF(condeferrable, ' DEFERRABLE', '')|| + IF(condeferred, ' INITIALLY DEFERRED', ''))|| + IF(indisclustered, ' CLUSTER', '')|| + IF(NOT indisvalid, ' INVALID', '')|| + IF(indisreplident, ' REPLICA IDENTITY', '') + AS "Indexes" + FROM idx +ORDER BY indisprimary DESC, idxname +Indexes +"mytable_pkey PRIMARY KEY, btree (rowid ASC)" +myidx btree (mycolumn ASC) +> WITH cons AS ( +SELECT r.conname, + pg_catalog.pg_get_constraintdef(r.oid, true) AS condef + FROM pg_catalog.pg_constraint r + WHERE r.conrelid = 106 AND r.contype = 'c' +) + SELECT pg_catalog.quote_ident(conname) || ' ' || condef + AS "Check constraints" + FROM cons +ORDER BY conname +Check constraints +check_mycolumn CHECK ((mycolumn > 123)) + +subtest end + +subtest view_details + +cli +\d+ myview +---- +sql -e \set echo -e \set display_format csv -e \d+ myview +> SELECT c.oid, + n.nspname, + c.relname, + c.relkind, + c.relpersistence, + c.relchecks > 0, + c.relhasindex, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE conrelid = c.oid AND contype = 'f') AS relhasfkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE confrelid = c.oid AND contype = 'f') AS relhasifkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_statistic_ext WHERE stxrelid = c.oid) + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname LIKE 'myview' + ORDER BY 2,3 +View "public.myview" +> WITH cols AS ( + SELECT a.attname, + pg_catalog.format_type(a.atttypid, a.atttypmod) AS typname, + (SELECT pg_catalog.pg_get_expr(d.adbin, d.adrelid, true) + FROM pg_catalog.pg_attrdef d + WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef) AS defexpr, + a.attnotnull, + (SELECT c.collname + FROM pg_catalog.pg_collation c, pg_catalog.pg_type t + WHERE c.oid = a.attcollation + AND t.oid = a.atttypid + AND a.attcollation <> t.typcollation) AS attcollation, + a.attidentity, + a.attgenerated, + pg_catalog.col_description(a.attrelid, a.attnum) AS description + FROM pg_catalog.pg_attribute a + WHERE a.attrelid = 108 AND a.attnum > 0 AND NOT a.attisdropped +ORDER BY a.attnum) +SELECT attname AS "Column", + typname AS "Type", + COALESCE(attcollation, '') AS "Collation", + IF(attnotnull, 'not null', '') AS "Nullable", + COALESCE( + CASE attidentity + WHEN 'a' THEN 'generated always as identity' + WHEN 'd' THEN 'generated by default as identity' + ELSE CASE attgenerated + WHEN 's' THEN 'generated always as ('||defexpr||') stored' + ELSE defexpr + END + END, '') AS "Default", + COALESCE(description,'') AS "Description" + FROM cols +Column,Type,Collation,Nullable,Default,Description +mycolumn,bigint,,,, +> SELECT pg_catalog.pg_get_viewdef(108::pg_catalog.oid, true) AS "View definition" +View definition +SELECT mycolumn FROM defaultdb.public.mytable + +subtest end + +subtest materialized_view_details + +cli +\d+ mymview +---- +sql -e \set echo -e \set display_format csv -e \d+ mymview +> SELECT c.oid, + n.nspname, + c.relname, + c.relkind, + c.relpersistence, + c.relchecks > 0, + c.relhasindex, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE conrelid = c.oid AND contype = 'f') AS relhasfkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE confrelid = c.oid AND contype = 'f') AS relhasifkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_statistic_ext WHERE stxrelid = c.oid) + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname LIKE 'mymview' + ORDER BY 2,3 +?m? "public.mymview" +> WITH cols AS ( + SELECT a.attname, + pg_catalog.format_type(a.atttypid, a.atttypmod) AS typname, + (SELECT pg_catalog.pg_get_expr(d.adbin, d.adrelid, true) + FROM pg_catalog.pg_attrdef d + WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef) AS defexpr, + a.attnotnull, + (SELECT c.collname + FROM pg_catalog.pg_collation c, pg_catalog.pg_type t + WHERE c.oid = a.attcollation + AND t.oid = a.atttypid + AND a.attcollation <> t.typcollation) AS attcollation, + a.attidentity, + a.attgenerated, + pg_catalog.col_description(a.attrelid, a.attnum) AS description + FROM pg_catalog.pg_attribute a + WHERE a.attrelid = 107 AND a.attnum > 0 AND NOT a.attisdropped +ORDER BY a.attnum) +SELECT attname AS "Column", + typname AS "Type", + COALESCE(attcollation, '') AS "Collation", + IF(attnotnull, 'not null', '') AS "Nullable", + COALESCE( + CASE attidentity + WHEN 'a' THEN 'generated always as identity' + WHEN 'd' THEN 'generated by default as identity' + ELSE CASE attgenerated + WHEN 's' THEN 'generated always as ('||defexpr||') stored' + ELSE defexpr + END + END, '') AS "Default", + COALESCE(description,'') AS "Description" + FROM cols +Column,Type,Collation,Nullable,Default,Description +mycolumn,bigint,,,, +rowid,bigint,,not null,unique_rowid(), +> WITH idx AS ( + SELECT c2.relname AS idxname, + i.indisprimary, i.indisunique, i.indisclustered, + i.indisvalid, + pg_catalog.pg_get_indexdef(i.indexrelid, 0, true) as indexdef, + pg_catalog.pg_get_constraintdef(con.oid, true) as condef, + contype, condeferrable, condeferred, + i.indisreplident + FROM pg_catalog.pg_class c, + pg_catalog.pg_class c2, + pg_catalog.pg_index i +LEFT JOIN pg_catalog.pg_constraint con + ON (conrelid = i.indrelid AND conindid = i.indexrelid AND contype IN ('p','u','x')) + WHERE c.oid = 107 + AND c.oid = i.indrelid + AND i.indexrelid = c2.oid) +SELECT pg_catalog.quote_ident(idxname) || + IF(contype = 'x', ' ' || condef, + IF(indisprimary, ' PRIMARY KEY,', + IF(indisunique, + IF(contype = 'u', ' UNIQUE CONSTRAINT,', ' UNIQUE,'), ''))|| + ' ' || substring(indexdef FROM position(' USING ' IN indexdef)+7) || + IF(condeferrable, ' DEFERRABLE', '')|| + IF(condeferred, ' INITIALLY DEFERRED', ''))|| + IF(indisclustered, ' CLUSTER', '')|| + IF(NOT indisvalid, ' INVALID', '')|| + IF(indisreplident, ' REPLICA IDENTITY', '') + AS "Indexes" + FROM idx +ORDER BY indisprimary DESC, idxname +Indexes +"mymview_pkey PRIMARY KEY, btree (rowid ASC)" +> SELECT pg_catalog.pg_get_viewdef(107::pg_catalog.oid, true) AS "View definition" +View definition +SELECT mycolumn FROM defaultdb.public.mytable + +subtest end + +subtest fkey_details + +cli +\d ftable1 +---- +sql -e \set echo -e \set display_format csv -e \d ftable1 +> SELECT c.oid, + n.nspname, + c.relname, + c.relkind, + c.relpersistence, + c.relchecks > 0, + c.relhasindex, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE conrelid = c.oid AND contype = 'f') AS relhasfkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE confrelid = c.oid AND contype = 'f') AS relhasifkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_statistic_ext WHERE stxrelid = c.oid) + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname LIKE 'ftable1' + ORDER BY 2,3 +Table "public.ftable1" +> WITH cols AS ( + SELECT a.attname, + pg_catalog.format_type(a.atttypid, a.atttypmod) AS typname, + (SELECT pg_catalog.pg_get_expr(d.adbin, d.adrelid, true) + FROM pg_catalog.pg_attrdef d + WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef) AS defexpr, + a.attnotnull, + (SELECT c.collname + FROM pg_catalog.pg_collation c, pg_catalog.pg_type t + WHERE c.oid = a.attcollation + AND t.oid = a.atttypid + AND a.attcollation <> t.typcollation) AS attcollation, + a.attidentity, + a.attgenerated + FROM pg_catalog.pg_attribute a + WHERE a.attrelid = 109 AND a.attnum > 0 AND NOT a.attisdropped +ORDER BY a.attnum) +SELECT attname AS "Column", + typname AS "Type", + COALESCE(attcollation, '') AS "Collation", + IF(attnotnull, 'not null', '') AS "Nullable", + COALESCE( + CASE attidentity + WHEN 'a' THEN 'generated always as identity' + WHEN 'd' THEN 'generated by default as identity' + ELSE CASE attgenerated + WHEN 's' THEN 'generated always as ('||defexpr||') stored' + ELSE defexpr + END + END, '') AS "Default" + FROM cols +Column,Type,Collation,Nullable,Default +x,bigint,,, +rowid,bigint,,not null,unique_rowid() +> WITH idx AS ( + SELECT c2.relname AS idxname, + i.indisprimary, i.indisunique, i.indisclustered, + i.indisvalid, + pg_catalog.pg_get_indexdef(i.indexrelid, 0, true) as indexdef, + pg_catalog.pg_get_constraintdef(con.oid, true) as condef, + contype, condeferrable, condeferred, + i.indisreplident + FROM pg_catalog.pg_class c, + pg_catalog.pg_class c2, + pg_catalog.pg_index i +LEFT JOIN pg_catalog.pg_constraint con + ON (conrelid = i.indrelid AND conindid = i.indexrelid AND contype IN ('p','u','x')) + WHERE c.oid = 109 + AND c.oid = i.indrelid + AND i.indexrelid = c2.oid) +SELECT pg_catalog.quote_ident(idxname) || + IF(contype = 'x', ' ' || condef, + IF(indisprimary, ' PRIMARY KEY,', + IF(indisunique, + IF(contype = 'u', ' UNIQUE CONSTRAINT,', ' UNIQUE,'), ''))|| + ' ' || substring(indexdef FROM position(' USING ' IN indexdef)+7) || + IF(condeferrable, ' DEFERRABLE', '')|| + IF(condeferred, ' INITIALLY DEFERRED', ''))|| + IF(indisclustered, ' CLUSTER', '')|| + IF(NOT indisvalid, ' INVALID', '')|| + IF(indisreplident, ' REPLICA IDENTITY', '') + AS "Indexes" + FROM idx +ORDER BY indisprimary DESC, idxname +Indexes +"ftable1_pkey PRIMARY KEY, btree (rowid ASC)" +"ftable1_x_key UNIQUE CONSTRAINT, btree (x ASC)" +> WITH cons AS ( +SELECT conname, + pg_catalog.pg_get_constraintdef(r.oid, true) as condef, + conrelid::pg_catalog.regclass AS ontable + FROM pg_catalog.pg_constraint r + WHERE r.confrelid = 109 + AND r.contype = 'f') + SELECT 'TABLE ' || pg_catalog.quote_ident(ontable::STRING) || + ' CONSTRAINT ' || pg_catalog.quote_ident(conname) || ' ' || condef + AS "Referenced by" + FROM cons +ORDER BY conname +Referenced by +TABLE ftable2 CONSTRAINT ftable2_x_fkey FOREIGN KEY (x) REFERENCES ftable1(x) + +cli +\d ftable2 +---- +sql -e \set echo -e \set display_format csv -e \d ftable2 +> SELECT c.oid, + n.nspname, + c.relname, + c.relkind, + c.relpersistence, + c.relchecks > 0, + c.relhasindex, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE conrelid = c.oid AND contype = 'f') AS relhasfkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_constraint WHERE confrelid = c.oid AND contype = 'f') AS relhasifkey, + EXISTS(SELECT 1 FROM pg_catalog.pg_statistic_ext WHERE stxrelid = c.oid) + FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname LIKE 'ftable2' + ORDER BY 2,3 +Table "public.ftable2" +> WITH cols AS ( + SELECT a.attname, + pg_catalog.format_type(a.atttypid, a.atttypmod) AS typname, + (SELECT pg_catalog.pg_get_expr(d.adbin, d.adrelid, true) + FROM pg_catalog.pg_attrdef d + WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef) AS defexpr, + a.attnotnull, + (SELECT c.collname + FROM pg_catalog.pg_collation c, pg_catalog.pg_type t + WHERE c.oid = a.attcollation + AND t.oid = a.atttypid + AND a.attcollation <> t.typcollation) AS attcollation, + a.attidentity, + a.attgenerated + FROM pg_catalog.pg_attribute a + WHERE a.attrelid = 110 AND a.attnum > 0 AND NOT a.attisdropped +ORDER BY a.attnum) +SELECT attname AS "Column", + typname AS "Type", + COALESCE(attcollation, '') AS "Collation", + IF(attnotnull, 'not null', '') AS "Nullable", + COALESCE( + CASE attidentity + WHEN 'a' THEN 'generated always as identity' + WHEN 'd' THEN 'generated by default as identity' + ELSE CASE attgenerated + WHEN 's' THEN 'generated always as ('||defexpr||') stored' + ELSE defexpr + END + END, '') AS "Default" + FROM cols +Column,Type,Collation,Nullable,Default +x,bigint,,, +rowid,bigint,,not null,unique_rowid() +> WITH idx AS ( + SELECT c2.relname AS idxname, + i.indisprimary, i.indisunique, i.indisclustered, + i.indisvalid, + pg_catalog.pg_get_indexdef(i.indexrelid, 0, true) as indexdef, + pg_catalog.pg_get_constraintdef(con.oid, true) as condef, + contype, condeferrable, condeferred, + i.indisreplident + FROM pg_catalog.pg_class c, + pg_catalog.pg_class c2, + pg_catalog.pg_index i +LEFT JOIN pg_catalog.pg_constraint con + ON (conrelid = i.indrelid AND conindid = i.indexrelid AND contype IN ('p','u','x')) + WHERE c.oid = 110 + AND c.oid = i.indrelid + AND i.indexrelid = c2.oid) +SELECT pg_catalog.quote_ident(idxname) || + IF(contype = 'x', ' ' || condef, + IF(indisprimary, ' PRIMARY KEY,', + IF(indisunique, + IF(contype = 'u', ' UNIQUE CONSTRAINT,', ' UNIQUE,'), ''))|| + ' ' || substring(indexdef FROM position(' USING ' IN indexdef)+7) || + IF(condeferrable, ' DEFERRABLE', '')|| + IF(condeferred, ' INITIALLY DEFERRED', ''))|| + IF(indisclustered, ' CLUSTER', '')|| + IF(NOT indisvalid, ' INVALID', '')|| + IF(indisreplident, ' REPLICA IDENTITY', '') + AS "Indexes" + FROM idx +ORDER BY indisprimary DESC, idxname +Indexes +"ftable2_pkey PRIMARY KEY, btree (rowid ASC)" +> WITH cons AS ( +SELECT conname, + pg_catalog.pg_get_constraintdef(r.oid, true) as condef, + conrelid::pg_catalog.regclass AS ontable + FROM pg_catalog.pg_constraint r + WHERE r.conrelid = 110 + AND r.contype = 'f' AND (r.conparentid = 0 OR r.conparentid IS NULL)) + SELECT 'TABLE ' || pg_catalog.quote_ident(ontable::STRING) || + ' CONSTRAINT ' || pg_catalog.quote_ident(conname) || ' ' || condef + AS "Foreign-key constraints" + FROM cons +ORDER BY conname +Foreign-key constraints +TABLE ftable2 CONSTRAINT ftable2_x_fkey FOREIGN KEY (x) REFERENCES ftable1(x) + +subtest end + +subtest list_types + +cli +\dT +---- +sql -e \set echo -e \set display_format csv -e \dT +List of data types: +> SELECT n.nspname AS "Schema", + pg_catalog.format_type(t.oid, NULL) AS "Name", + COALESCE(pg_catalog.obj_description(t.oid, 'pg_type'),'') AS "Description" + FROM pg_catalog.pg_type t +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace + WHERE (t.typrelid = 0 + OR (SELECT c.relkind = 'c' + FROM pg_catalog.pg_class c + WHERE c.oid = t.typrelid)) + AND (NOT EXISTS( + SELECT 1 + FROM pg_catalog.pg_type el + WHERE el.oid = t.typelem AND el.typarray = t.oid)) + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_type_is_visible(t.oid) +ORDER BY 1, 2 +Schema,Name,Description +public,mytyp, + +cli +\dT %int[] +---- +sql -e \set echo -e \set display_format csv -e \dT %int[] +List of data types: +> SELECT n.nspname AS "Schema", + pg_catalog.format_type(t.oid, NULL) AS "Name", + COALESCE(pg_catalog.obj_description(t.oid, 'pg_type'),'') AS "Description" + FROM pg_catalog.pg_type t +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace + WHERE (t.typrelid = 0 + OR (SELECT c.relkind = 'c' + FROM pg_catalog.pg_class c + WHERE c.oid = t.typrelid)) + AND ('%int[]' LIKE '%[]%' OR NOT EXISTS( + SELECT 1 + FROM pg_catalog.pg_type el + WHERE el.oid = t.typelem AND el.typarray = t.oid)) + AND (t.typname LIKE '%int[]' + OR pg_catalog.format_type(t.oid, NULL) LIKE '%int[]') +ORDER BY 1, 2 +Schema,Name,Description +pg_catalog,bigint[], +pg_catalog,smallint[], + +cli +\dT int% +---- +sql -e \set echo -e \set display_format csv -e \dT int% +List of data types: +> SELECT n.nspname AS "Schema", + pg_catalog.format_type(t.oid, NULL) AS "Name", + COALESCE(pg_catalog.obj_description(t.oid, 'pg_type'),'') AS "Description" + FROM pg_catalog.pg_type t +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace + WHERE (t.typrelid = 0 + OR (SELECT c.relkind = 'c' + FROM pg_catalog.pg_class c + WHERE c.oid = t.typrelid)) + AND ('int%' LIKE '%[]%' OR NOT EXISTS( + SELECT 1 + FROM pg_catalog.pg_type el + WHERE el.oid = t.typelem AND el.typarray = t.oid)) + AND (t.typname LIKE 'int%' + OR pg_catalog.format_type(t.oid, NULL) LIKE 'int%') +ORDER BY 1, 2 +Schema,Name,Description +pg_catalog,bigint, +pg_catalog,int2vector, +pg_catalog,integer, +pg_catalog,interval, +pg_catalog,smallint, + +subtest end + +subtest list_users + +cli +\du +---- +sql -e \set echo -e \set display_format csv -e \du +List of roles: +> WITH roles AS ( +SELECT r.rolname, r.rolsuper, r.rolinherit, + r.rolcreaterole, r.rolcreatedb, r.rolcanlogin, + r.rolconnlimit, r.rolvaliduntil, + ARRAY(SELECT b.rolname + FROM pg_catalog.pg_auth_members m + JOIN pg_catalog.pg_roles b ON (m.roleid = b.oid) + WHERE m.member = r.oid) as memberof, + r.rolreplication, r.rolbypassrls + FROM pg_catalog.pg_roles r + WHERE r.rolname !~ '^pg_') +SELECT rolname AS "Role name", + array_to_string(ARRAY( + SELECT a FROM (VALUES + (IF(rolsuper, 'Superuser', NULL)), + (IF(NOT rolinherit, 'No inheritance', NULL)), + (IF(rolcreaterole, 'Create role', NULL)), + (IF(rolcreatedb, 'Create DB', NULL)), + (IF(NOT rolcanlogin, 'Cannot login', NULL)), + (IF(rolconnlimit = 0, + 'No connections', + IF(rolconnlimit > 0, + rolconnlimit::STRING || ' connection' || IF(rolconnlimit>1, 's',''), + NULL))), + (IF(rolreplication, 'Replication', NULL)), + (IF(rolbypassrls, 'Bypass RLS', NULL)), + ('Password valid until ' || rolvaliduntil) + ) AS v(a) WHERE v.a IS NOT NULL), + ', ') AS "Attributes", + memberof AS "Member of" + FROM roles +Role name,Attributes,Member of +myuser,Superuser,{admin} +root,"Superuser, Create role, Create DB",{admin} +admin,"Superuser, Create role, Create DB",{} + +cli +\du myuser +---- +sql -e \set echo -e \set display_format csv -e \du myuser +List of roles: +> WITH roles AS ( +SELECT r.rolname, r.rolsuper, r.rolinherit, + r.rolcreaterole, r.rolcreatedb, r.rolcanlogin, + r.rolconnlimit, r.rolvaliduntil, + ARRAY(SELECT b.rolname + FROM pg_catalog.pg_auth_members m + JOIN pg_catalog.pg_roles b ON (m.roleid = b.oid) + WHERE m.member = r.oid) as memberof, + r.rolreplication, r.rolbypassrls + FROM pg_catalog.pg_roles r + WHERE r.rolname LIKE 'myuser') +SELECT rolname AS "Role name", + array_to_string(ARRAY( + SELECT a FROM (VALUES + (IF(rolsuper, 'Superuser', NULL)), + (IF(NOT rolinherit, 'No inheritance', NULL)), + (IF(rolcreaterole, 'Create role', NULL)), + (IF(rolcreatedb, 'Create DB', NULL)), + (IF(NOT rolcanlogin, 'Cannot login', NULL)), + (IF(rolconnlimit = 0, + 'No connections', + IF(rolconnlimit > 0, + rolconnlimit::STRING || ' connection' || IF(rolconnlimit>1, 's',''), + NULL))), + (IF(rolreplication, 'Replication', NULL)), + (IF(rolbypassrls, 'Bypass RLS', NULL)), + ('Password valid until ' || rolvaliduntil) + ) AS v(a) WHERE v.a IS NOT NULL), + ', ') AS "Attributes", + memberof AS "Member of" + FROM roles +Role name,Attributes,Member of +myuser,Superuser,{admin} + +subtest end + + +subtest list_descriptions + +cli +\dd +---- +sql -e \set echo -e \set display_format csv -e \dd +Object descriptions: +> SELECT DISTINCT + tt.nspname AS "Schema", + tt.name AS "Name", + tt.object AS "Object", + d.description AS "Description" + FROM ( + SELECT pgc.oid as oid, pgc.conrelid AS tableoid, + n.nspname as nspname, + CAST(pgc.conname AS pg_catalog.text) as name, + CAST('table constraint' AS pg_catalog.text) as object + FROM pg_catalog.pg_constraint pgc + JOIN pg_catalog.pg_class c ON c.oid = pgc.conrelid + LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE TRUE + AND n.nspname !~ '^pg_' + AND n.nspname <> 'crdb_internal' + AND n.nspname <> 'information_schema' AND pg_catalog.pg_table_is_visible(c.oid) +UNION ALL + SELECT pgc.oid as oid, pgc.conrelid AS tableoid, + n.nspname as nspname, + CAST(pgc.conname AS pg_catalog.text) AS name, + CAST('domain constraint' AS pg_catalog.text) AS object + FROM pg_catalog.pg_constraint pgc + JOIN pg_catalog.pg_type t ON t.oid = pgc.contypid + LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace + WHERE TRUE + AND n.nspname !~ '^pg_' + AND n.nspname <> 'crdb_internal' + AND n.nspname <> 'information_schema' AND pg_catalog.pg_type_is_visible(t.oid)) AS tt + JOIN pg_catalog.pg_description d + ON (tt.oid = d.objoid AND tt.tableoid = d.classoid AND d.objsubid = 0) +ORDER BY 1,2,3 +Schema,Name,Object,Description + +cli +\dd mytable +---- +sql -e \set echo -e \set display_format csv -e \dd mytable +Object descriptions: +> SELECT DISTINCT + tt.nspname AS "Schema", + tt.name AS "Name", + tt.object AS "Object", + d.description AS "Description" + FROM ( + SELECT pgc.oid as oid, pgc.conrelid AS tableoid, + n.nspname as nspname, + CAST(pgc.conname AS pg_catalog.text) as name, + CAST('table constraint' AS pg_catalog.text) as object + FROM pg_catalog.pg_constraint pgc + JOIN pg_catalog.pg_class c ON c.oid = pgc.conrelid + LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE TRUE AND pgc.conname LIKE 'mytable' +UNION ALL + SELECT pgc.oid as oid, pgc.conrelid AS tableoid, + n.nspname as nspname, + CAST(pgc.conname AS pg_catalog.text) AS name, + CAST('domain constraint' AS pg_catalog.text) AS object + FROM pg_catalog.pg_constraint pgc + JOIN pg_catalog.pg_type t ON t.oid = pgc.contypid + LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace + WHERE TRUE AND pgc.conname LIKE 'mytable') AS tt + JOIN pg_catalog.pg_description d + ON (tt.oid = d.objoid AND tt.tableoid = d.classoid AND d.objsubid = 0) +ORDER BY 1,2,3 +Schema,Name,Object,Description + +subtest end + +subtest list_functions + +cli +\df +---- +sql -e \set echo -e \set display_format csv -e \df +List of functions: +> SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type" + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_function_is_visible(p.oid) ORDER BY 1, 2, 4 +Schema,Name,Result data type,Argument data types,Type +public,myfunc,int8,int8,func + +cli +\df abs +---- +sql -e \set echo -e \set display_format csv -e \df abs +List of functions: +> SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type" + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE AND p.proname LIKE 'abs' ORDER BY 1, 2, 4 +Schema,Name,Result data type,Argument data types,Type +pg_catalog,abs,float8,float8,func +pg_catalog,abs,int8,int8,func +pg_catalog,abs,numeric,numeric,func + +cli +\df+ abs +---- +sql -e \set echo -e \set display_format csv -e \df+ abs +List of functions: +> SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type", CASE p.provolatile + WHEN 'i' THEN 'immutable' + WHEN 's' THEN 'stable' + WHEN 'v' THEN 'volatile' + ELSE p.provolatile + END AS "Volatility", + pg_catalog.pg_get_userbyid(p.proowner) AS "Owner", + CASE WHEN p.prosecdef THEN 'definer' ELSE 'invoker' END AS "Security", + COALESCE(pg_catalog.array_to_string(p.proacl, e'\n'), '') AS "Access privileges", + p.prosrc AS "Source code", + pg_catalog.obj_description(p.oid, 'pg_proc') AS "Description" + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE AND p.proname LIKE 'abs' ORDER BY 1, 2, 4 +Schema,Name,Result data type,Argument data types,Type,Volatility,Owner,Security,Access privileges,Source code,Description +pg_catalog,abs,float8,float8,func,i,NULL,invoker,,abs,Calculates the absolute value of `val`. +pg_catalog,abs,int8,int8,func,i,NULL,invoker,,abs,Calculates the absolute value of `val`. +pg_catalog,abs,numeric,numeric,func,i,NULL,invoker,,abs,Calculates the absolute value of `val`. + +cli +\dfw %rank% +---- +sql -e \set echo -e \set display_format csv -e \dfw %rank% +List of functions: +> SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type" + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE AND (FALSE OR p.proiswindow) AND p.proname LIKE '%rank%' ORDER BY 1, 2, 4 +Schema,Name,Result data type,Argument data types,Type +pg_catalog,dense_rank,int8,,window +pg_catalog,percent_rank,float8,,window +pg_catalog,rank,int8,,window + +cli +\dfw+ %rank% +---- +sql -e \set echo -e \set display_format csv -e \dfw+ %rank% +List of functions: +> SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type", CASE p.provolatile + WHEN 'i' THEN 'immutable' + WHEN 's' THEN 'stable' + WHEN 'v' THEN 'volatile' + ELSE p.provolatile + END AS "Volatility", + pg_catalog.pg_get_userbyid(p.proowner) AS "Owner", + CASE WHEN p.prosecdef THEN 'definer' ELSE 'invoker' END AS "Security", + COALESCE(pg_catalog.array_to_string(p.proacl, e'\n'), '') AS "Access privileges", + p.prosrc AS "Source code", + pg_catalog.obj_description(p.oid, 'pg_proc') AS "Description" + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE AND (FALSE OR p.proiswindow) AND p.proname LIKE '%rank%' ORDER BY 1, 2, 4 +Schema,Name,Result data type,Argument data types,Type,Volatility,Owner,Security,Access privileges,Source code,Description +pg_catalog,dense_rank,int8,,window,i,NULL,invoker,,dense_rank,Calculates the rank of the current row without gaps; this function counts peer groups. +pg_catalog,percent_rank,float8,,window,i,NULL,invoker,,percent_rank,Calculates the relative rank of the current row: (rank - 1) / (total rows - 1). +pg_catalog,rank,int8,,window,i,NULL,invoker,,rank,Calculates the rank of the current row with gaps; same as row_number of its first peer. + +cli +\dfa xor% +---- +sql -e \set echo -e \set display_format csv -e \dfa xor% +List of functions: +> SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type" + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE AND (FALSE OR p.proisagg) AND p.proname LIKE 'xor%' ORDER BY 1, 2, 4 +Schema,Name,Result data type,Argument data types,Type +pg_catalog,xor_agg,bytea,bytea,agg +pg_catalog,xor_agg,int8,int8,agg + +cli +\dfa+ xor% +---- +sql -e \set echo -e \set display_format csv -e \dfa+ xor% +List of functions: +> SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type", CASE p.provolatile + WHEN 'i' THEN 'immutable' + WHEN 's' THEN 'stable' + WHEN 'v' THEN 'volatile' + ELSE p.provolatile + END AS "Volatility", + pg_catalog.pg_get_userbyid(p.proowner) AS "Owner", + CASE WHEN p.prosecdef THEN 'definer' ELSE 'invoker' END AS "Security", + COALESCE(pg_catalog.array_to_string(p.proacl, e'\n'), '') AS "Access privileges", + p.prosrc AS "Source code", + pg_catalog.obj_description(p.oid, 'pg_proc') AS "Description" + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE AND (FALSE OR p.proisagg) AND p.proname LIKE 'xor%' ORDER BY 1, 2, 4 +Schema,Name,Result data type,Argument data types,Type,Volatility,Owner,Security,Access privileges,Source code,Description +pg_catalog,xor_agg,bytea,bytea,agg,i,NULL,invoker,,xor_agg,Calculates the bitwise XOR of the selected values. +pg_catalog,xor_agg,int8,int8,agg,i,NULL,invoker,,xor_agg,Calculates the bitwise XOR of the selected values. + +cli +\dfn +---- +sql -e \set echo -e \set display_format csv -e \dfn +List of functions: +> SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type" + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE AND NOT p.proisagg AND (p.prokind IS NULL OR p.prokind <> 'p') AND NOT p.proiswindow + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_function_is_visible(p.oid) ORDER BY 1, 2, 4 +Schema,Name,Result data type,Argument data types,Type +public,myfunc,int8,int8,func + +cli +\dfn+ +---- +sql -e \set echo -e \set display_format csv -e \dfn+ +List of functions: +> SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type", CASE p.provolatile + WHEN 'i' THEN 'immutable' + WHEN 's' THEN 'stable' + WHEN 'v' THEN 'volatile' + ELSE p.provolatile + END AS "Volatility", + pg_catalog.pg_get_userbyid(p.proowner) AS "Owner", + CASE WHEN p.prosecdef THEN 'definer' ELSE 'invoker' END AS "Security", + COALESCE(pg_catalog.array_to_string(p.proacl, e'\n'), '') AS "Access privileges", + p.prosrc AS "Source code", + pg_catalog.obj_description(p.oid, 'pg_proc') AS "Description" + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE AND NOT p.proisagg AND (p.prokind IS NULL OR p.prokind <> 'p') AND NOT p.proiswindow + AND n.nspname !~ '^pg_' + AND n.nspname <> 'information_schema' + AND n.nspname <> 'crdb_internal' + AND pg_catalog.pg_function_is_visible(p.oid) ORDER BY 1, 2, 4 +Schema,Name,Result data type,Argument data types,Type,Volatility,Owner,Security,Access privileges,Source code,Description +public,myfunc,int8,int8,func,v,root,invoker,,SELECT val;,NULL + +cli +\dfwa %tile% +---- +sql -e \set echo -e \set display_format csv -e \dfwa %tile% +List of functions: +> SELECT n.nspname AS "Schema", + p.proname AS "Name", + pg_catalog.pg_get_function_result(p.oid) AS "Result data type", + pg_catalog.pg_get_function_arguments(p.oid) AS "Argument data types", + CASE p.prokind + WHEN 'a' THEN 'agg' + WHEN 'w' THEN 'window' + WHEN 'p' THEN 'proc' + ELSE 'func' + END AS "Type" + FROM pg_catalog.pg_proc p +LEFT JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace + WHERE TRUE AND (FALSE OR p.proisagg OR p.proiswindow) AND p.proname LIKE '%tile%' ORDER BY 1, 2, 4 +Schema,Name,Result data type,Argument data types,Type +pg_catalog,ntile,int8,int8,window +pg_catalog,percentile_cont,_interval,_float8,agg +pg_catalog,percentile_cont,_float8,_float8,agg +pg_catalog,percentile_cont,interval,float8,agg +pg_catalog,percentile_cont,float8,float8,agg +pg_catalog,percentile_disc,anyelement,_float8,agg +pg_catalog,percentile_disc,anyelement,float8,agg + +subtest end + +subtest list_casts + +cli +\dC +---- +sql -e \set echo -e \set display_format csv -e \dC +List of casts: +> SELECT pg_catalog.format_type(castsource, NULL) AS "Source type", + pg_catalog.format_type(casttarget, NULL) AS "Target type", + CASE WHEN c.castmethod = 'b' THEN '(binary coercible)' + WHEN c.castmethod = 'i' THEN '(with inout)' + ELSE p.proname + END AS "Function", + CASE WHEN c.castcontext = 'e' THEN 'no' + WHEN c.castcontext = 'a' THEN 'in assignment' + ELSE 'yes' + END AS "Implicit?" + FROM pg_catalog.pg_cast c +LEFT JOIN pg_catalog.pg_proc p ON c.castfunc = p.oid +LEFT JOIN pg_catalog.pg_type ts ON c.castsource = ts.oid +LEFT JOIN pg_catalog.pg_namespace ns ON ns.oid = ts.typnamespace +LEFT JOIN pg_catalog.pg_type tt ON c.casttarget = tt.oid +LEFT JOIN pg_catalog.pg_namespace nt ON nt.oid = tt.typnamespace + WHERE ((true + AND pg_catalog.pg_type_is_visible(ts.oid)) + OR (true + AND pg_catalog.pg_type_is_visible(tt.oid))) +ORDER BY 1, 2 +Source type,Target type,Function,Implicit? +"""char""",character,NULL,in assignment +"""char""",character varying,NULL,in assignment +"""char""",integer,NULL,no +"""char""",text,NULL,yes +bigint,bit,NULL,no +bigint,double precision,NULL,yes +bigint,integer,NULL,in assignment +bigint,numeric,NULL,yes +bigint,oid,NULL,yes +bigint,real,NULL,yes +bigint,regclass,NULL,yes +bigint,regnamespace,NULL,yes +bigint,regproc,NULL,yes +bigint,regprocedure,NULL,yes +bigint,regrole,NULL,yes +bigint,regtype,NULL,yes +bigint,smallint,NULL,in assignment +bit,bigint,NULL,no +bit,bit,NULL,yes +bit,bit varying,NULL,yes +bit,integer,NULL,no +bit varying,bit,NULL,yes +bit varying,bit varying,NULL,yes +boolean,character,NULL,in assignment +boolean,character varying,NULL,in assignment +boolean,integer,NULL,no +boolean,text,NULL,in assignment +box2d,geometry,NULL,yes +bytea,geography,NULL,yes +bytea,geometry,NULL,yes +character,"""char""",NULL,in assignment +character,character,NULL,yes +character,character varying,NULL,yes +character,name,NULL,yes +character,text,NULL,yes +character varying,"""char""",NULL,in assignment +character varying,character,NULL,yes +character varying,character varying,NULL,yes +character varying,name,NULL,yes +character varying,regclass,NULL,yes +character varying,text,NULL,yes +date,timestamp with time zone,NULL,yes +date,timestamp without time zone,NULL,yes +double precision,bigint,NULL,in assignment +double precision,integer,NULL,in assignment +double precision,numeric,NULL,in assignment +double precision,real,NULL,in assignment +double precision,smallint,NULL,in assignment +geography,bytea,NULL,yes +geography,geography,NULL,yes +geography,geometry,NULL,no +geometry,box2d,NULL,yes +geometry,bytea,NULL,yes +geometry,geography,NULL,yes +geometry,geometry,NULL,yes +geometry,jsonb,NULL,no +geometry,text,NULL,yes +inet,character,NULL,in assignment +inet,character varying,NULL,in assignment +inet,text,NULL,in assignment +integer,"""char""",NULL,no +integer,bigint,NULL,yes +integer,bit,NULL,no +integer,boolean,NULL,no +integer,double precision,NULL,yes +integer,numeric,NULL,yes +integer,oid,NULL,yes +integer,real,NULL,yes +integer,regclass,NULL,yes +integer,regnamespace,NULL,yes +integer,regproc,NULL,yes +integer,regprocedure,NULL,yes +integer,regrole,NULL,yes +integer,regtype,NULL,yes +integer,smallint,NULL,in assignment +interval,interval,NULL,yes +interval,time without time zone,NULL,in assignment +jsonb,bigint,NULL,no +jsonb,boolean,NULL,no +jsonb,double precision,NULL,no +jsonb,integer,NULL,no +jsonb,numeric,NULL,no +jsonb,real,NULL,no +jsonb,smallint,NULL,no +name,character,NULL,in assignment +name,character varying,NULL,in assignment +name,text,NULL,yes +numeric,bigint,NULL,in assignment +numeric,double precision,NULL,yes +numeric,integer,NULL,in assignment +numeric,numeric,NULL,yes +numeric,real,NULL,yes +numeric,smallint,NULL,in assignment +oid,bigint,NULL,in assignment +oid,integer,NULL,in assignment +oid,regclass,NULL,yes +oid,regnamespace,NULL,yes +oid,regproc,NULL,yes +oid,regprocedure,NULL,yes +oid,regrole,NULL,yes +oid,regtype,NULL,yes +real,bigint,NULL,in assignment +real,double precision,NULL,yes +real,integer,NULL,in assignment +real,numeric,NULL,in assignment +real,smallint,NULL,in assignment +regclass,bigint,NULL,in assignment +regclass,integer,NULL,in assignment +regclass,oid,NULL,yes +regnamespace,bigint,NULL,in assignment +regnamespace,integer,NULL,in assignment +regnamespace,oid,NULL,yes +regproc,bigint,NULL,in assignment +regproc,integer,NULL,in assignment +regproc,oid,NULL,yes +regproc,regprocedure,NULL,yes +regprocedure,bigint,NULL,in assignment +regprocedure,integer,NULL,in assignment +regprocedure,oid,NULL,yes +regprocedure,regproc,NULL,yes +regrole,bigint,NULL,in assignment +regrole,integer,NULL,in assignment +regrole,oid,NULL,yes +regtype,bigint,NULL,in assignment +regtype,integer,NULL,in assignment +regtype,oid,NULL,yes +smallint,bigint,NULL,yes +smallint,double precision,NULL,yes +smallint,integer,NULL,yes +smallint,numeric,NULL,yes +smallint,oid,NULL,yes +smallint,real,NULL,yes +smallint,regclass,NULL,yes +smallint,regnamespace,NULL,yes +smallint,regproc,NULL,yes +smallint,regprocedure,NULL,yes +smallint,regrole,NULL,yes +smallint,regtype,NULL,yes +text,"""char""",NULL,in assignment +text,character,NULL,yes +text,character varying,NULL,yes +text,geometry,NULL,yes +text,name,NULL,yes +text,regclass,NULL,yes +text,text,NULL,yes +time with time zone,time with time zone,NULL,yes +time with time zone,time without time zone,NULL,in assignment +time without time zone,interval,NULL,yes +time without time zone,time with time zone,NULL,yes +time without time zone,time without time zone,NULL,yes +timestamp with time zone,date,NULL,in assignment +timestamp with time zone,time with time zone,NULL,in assignment +timestamp with time zone,time without time zone,NULL,in assignment +timestamp with time zone,timestamp with time zone,NULL,yes +timestamp with time zone,timestamp without time zone,NULL,in assignment +timestamp without time zone,date,NULL,in assignment +timestamp without time zone,time without time zone,NULL,in assignment +timestamp without time zone,timestamp with time zone,NULL,yes +timestamp without time zone,timestamp without time zone,NULL,yes + +cli +\dC bi% +---- +sql -e \set echo -e \set display_format csv -e \dC bi% +List of casts: +> SELECT pg_catalog.format_type(castsource, NULL) AS "Source type", + pg_catalog.format_type(casttarget, NULL) AS "Target type", + CASE WHEN c.castmethod = 'b' THEN '(binary coercible)' + WHEN c.castmethod = 'i' THEN '(with inout)' + ELSE p.proname + END AS "Function", + CASE WHEN c.castcontext = 'e' THEN 'no' + WHEN c.castcontext = 'a' THEN 'in assignment' + ELSE 'yes' + END AS "Implicit?" + FROM pg_catalog.pg_cast c +LEFT JOIN pg_catalog.pg_proc p ON c.castfunc = p.oid +LEFT JOIN pg_catalog.pg_type ts ON c.castsource = ts.oid +LEFT JOIN pg_catalog.pg_namespace ns ON ns.oid = ts.typnamespace +LEFT JOIN pg_catalog.pg_type tt ON c.casttarget = tt.oid +LEFT JOIN pg_catalog.pg_namespace nt ON nt.oid = tt.typnamespace + WHERE ((true + AND (ts.typname LIKE 'bi%' + OR pg_catalog.format_type(ts.oid, NULL) LIKE 'bi%')) + OR (true + AND (tt.typname LIKE 'bi%' + OR pg_catalog.format_type(tt.oid, NULL) LIKE 'bi%'))) +ORDER BY 1, 2 +Source type,Target type,Function,Implicit? +bigint,bit,NULL,no +bigint,double precision,NULL,yes +bigint,integer,NULL,in assignment +bigint,numeric,NULL,yes +bigint,oid,NULL,yes +bigint,real,NULL,yes +bigint,regclass,NULL,yes +bigint,regnamespace,NULL,yes +bigint,regproc,NULL,yes +bigint,regprocedure,NULL,yes +bigint,regrole,NULL,yes +bigint,regtype,NULL,yes +bigint,smallint,NULL,in assignment +bit,bigint,NULL,no +bit,bit,NULL,yes +bit,bit varying,NULL,yes +bit,integer,NULL,no +bit varying,bit,NULL,yes +bit varying,bit varying,NULL,yes +double precision,bigint,NULL,in assignment +integer,bigint,NULL,yes +integer,bit,NULL,no +jsonb,bigint,NULL,no +numeric,bigint,NULL,in assignment +oid,bigint,NULL,in assignment +real,bigint,NULL,in assignment +regclass,bigint,NULL,in assignment +regnamespace,bigint,NULL,in assignment +regproc,bigint,NULL,in assignment +regprocedure,bigint,NULL,in assignment +regrole,bigint,NULL,in assignment +regtype,bigint,NULL,in assignment +smallint,bigint,NULL,yes + +subtest end diff --git a/pkg/cli/context.go b/pkg/cli/context.go index b97de80a087d..4103bc8cf933 100644 --- a/pkg/cli/context.go +++ b/pkg/cli/context.go @@ -265,7 +265,20 @@ func setCertContextDefaults() { certCtx.generatePKCS8Key = false certCtx.disableUsernameValidation = false certCtx.certPrincipalMap = nil - certCtx.tenantScope = []roachpb.TenantID{roachpb.SystemTenantID} + // Note: we set tenantScope to nil so that by default, client certs + // are not scoped to a specific tenant and can be used to connect to + // any tenant. + // + // Note that the scoping is generally useful for security, and it is + // used in CockroachCloud. However, CockroachCloud does not use our + // CLI code to generate certs and sets its tenant scopes on its own. + // + // Given that our CLI code is provided for convenience and developer + // productivity, and we don't expect certs generated here to be used + // in multi-tenant deployments where tenants are adversarial to each + // other, defaulting to certs that are valid on every tenant is a + // good choice. + certCtx.tenantScope = nil } var sqlExecCtx = clisqlexec.Context{ diff --git a/pkg/cli/flags.go b/pkg/cli/flags.go index fa8dbc23a29a..d30325c381a1 100644 --- a/pkg/cli/flags.go +++ b/pkg/cli/flags.go @@ -580,7 +580,6 @@ func init() { cliflagcfg.StringFlag(f, &certCtx.caKey, cliflags.CAKey) cliflagcfg.IntFlag(f, &certCtx.keySize, cliflags.KeySize) cliflagcfg.BoolFlag(f, &certCtx.overwriteFiles, cliflags.OverwriteFiles) - cliflagcfg.VarFlag(f, &tenantIDSetter{tenantIDs: &certCtx.tenantScope}, cliflags.TenantScope) if strings.HasSuffix(cmd.Name(), "-ca") { // CA-only commands. @@ -596,6 +595,8 @@ func init() { } if cmd == createClientCertCmd { + cliflagcfg.VarFlag(f, &tenantIDSetter{tenantIDs: &certCtx.tenantScope}, cliflags.TenantScope) + // PKCS8 key format is only available for the client cert command. cliflagcfg.BoolFlag(f, &certCtx.generatePKCS8Key, cliflags.GeneratePKCS8Key) cliflagcfg.BoolFlag(f, &certCtx.disableUsernameValidation, cliflags.DisableUsernameValidation) diff --git a/pkg/cmd/roachtest/tests/BUILD.bazel b/pkg/cmd/roachtest/tests/BUILD.bazel index 8bf2bd218e0a..3c3a5ed91f1c 100644 --- a/pkg/cmd/roachtest/tests/BUILD.bazel +++ b/pkg/cmd/roachtest/tests/BUILD.bazel @@ -206,7 +206,6 @@ go_library( "//pkg/roachprod/install", "//pkg/roachprod/logger", "//pkg/roachprod/prometheus", - "//pkg/security/username", "//pkg/server", "//pkg/server/serverpb", "//pkg/sql", diff --git a/pkg/cmd/roachtest/tests/multitenant_utils.go b/pkg/cmd/roachtest/tests/multitenant_utils.go index 686feb9d78a7..35603c449a53 100644 --- a/pkg/cmd/roachtest/tests/multitenant_utils.go +++ b/pkg/cmd/roachtest/tests/multitenant_utils.go @@ -26,7 +26,6 @@ import ( "github.com/cockroachdb/cockroach/pkg/cmd/roachtest/test" "github.com/cockroachdb/cockroach/pkg/roachprod" "github.com/cockroachdb/cockroach/pkg/roachprod/config" - "github.com/cockroachdb/cockroach/pkg/security/username" "github.com/cockroachdb/cockroach/pkg/testutils" "github.com/cockroachdb/cockroach/pkg/testutils/sqlutils" "github.com/stretchr/testify/require" @@ -100,26 +99,10 @@ func createTenantNode( node: node, sqlPort: sqlPort, } - if tn.cockroachBinSupportsTenantScope(ctx, c) { - err := tn.recreateClientCertsWithTenantScope(ctx, c, createOptions.otherTenantIDs) - require.NoError(t, err) - } tn.createTenantCert(ctx, t, c, createOptions.certNodes) return tn } -// cockroachBinSupportsTenantScope is a hack to figure out if the version of -// cockroach on the node supports tenant scoped certificates. We can't use a -// version comparison here because we need to compare alpha build versions which -// are compared lexicographically. This is a problem because our alpha versions -// contain an integer count of commits, which does not sort correctly. Once -// this feature ships in a release, it will be easier to do a version comparison -// on whether this command line flag is supported. -func (tn *tenantNode) cockroachBinSupportsTenantScope(ctx context.Context, c cluster.Cluster) bool { - err := c.RunE(ctx, c.Node(tn.node), "./cockroach cert create-client --help | grep '\\--tenant-scope'") - return err == nil -} - func (tn *tenantNode) createTenantCert( ctx context.Context, t test.Test, c cluster.Cluster, certNodes option.NodeListOption, ) { @@ -145,23 +128,6 @@ func (tn *tenantNode) createTenantCert( c.Run(ctx, c.Node(tn.node), cmd) } -func (tn *tenantNode) recreateClientCertsWithTenantScope( - ctx context.Context, c cluster.Cluster, otherIDs []int, -) error { - tenantArgs := fmt.Sprintf("1,%d", tn.tenantID) - for _, id := range otherIDs { - tenantArgs = fmt.Sprintf("%s,%d", tenantArgs, id) - } - - for _, user := range []username.SQLUsername{username.RootUserName(), username.TestUserName()} { - cmd := fmt.Sprintf( - "./cockroach cert create-client %s --certs-dir=certs --ca-key=certs/ca.key --tenant-scope %s --overwrite", - user.Normalized(), tenantArgs) - c.Run(ctx, c.Node(tn.node), cmd) - } - return c.RefetchCertsFromNode(ctx, tn.node) -} - func (tn *tenantNode) stop(ctx context.Context, t test.Test, c cluster.Cluster) { if tn.errCh == nil { return diff --git a/pkg/roachprod/install/cluster_synced.go b/pkg/roachprod/install/cluster_synced.go index e08fb8c182b4..dd4f7c21190f 100644 --- a/pkg/roachprod/install/cluster_synced.go +++ b/pkg/roachprod/install/cluster_synced.go @@ -1199,8 +1199,8 @@ func (c *SyncedCluster) DistributeCerts(ctx context.Context, l *logger.Logger) e rm -fr certs mkdir -p certs %[1]s cert create-ca --certs-dir=certs --ca-key=certs/ca.key -%[1]s cert create-client root --certs-dir=certs --ca-key=certs/ca.key --tenant-scope 1,2,3,4 -%[1]s cert create-client testuser --certs-dir=certs --ca-key=certs/ca.key --tenant-scope 1,2,3,4 +%[1]s cert create-client root --certs-dir=certs --ca-key=certs/ca.key +%[1]s cert create-client testuser --certs-dir=certs --ca-key=certs/ca.key %[1]s cert create-node %[2]s --certs-dir=certs --ca-key=certs/ca.key # Pre-create a few tenant-client %[1]s cert create-tenant-client 2 %[2]s --certs-dir=certs --ca-key=certs/ca.key @@ -1284,9 +1284,6 @@ func (c *SyncedCluster) createTenantCertBundle( node := c.Nodes[i] var tenantScopeArg string - if c.cockroachBinSupportsTenantScope(l, ctx, node) { - tenantScopeArg = fmt.Sprintf("--tenant-scope %d", tenantID) - } cmd := "set -e;" if c.IsLocal() { @@ -1327,23 +1324,6 @@ tar cvf %[5]s $CERT_DIR }, DefaultSSHRetryOpts) } -// cockroachBinSupportsTenantScope is a hack to figure out if the version of -// cockroach on the node supports tenant scoped certificates. We can't use a -// version comparison here because we need to compare alpha build versions which -// are compared lexicographically. This is a problem because our alpha versions -// contain an integer count of commits, which does not sort correctly. Once -// this feature ships in a release, it will be easier to do a version comparison -// on whether this command line flag is supported. -func (c *SyncedCluster) cockroachBinSupportsTenantScope( - l *logger.Logger, ctx context.Context, node Node, -) bool { - cmd := fmt.Sprintf("%s cert create-client --help | grep '\\--tenant-scope'", cockroachNodeBinary(c, node)) - sess := c.newSession(l, node, cmd) - defer sess.Close() - - return sess.Run(ctx) == nil -} - // getFile retrieves the given file from the first node in the cluster. The // filename is assumed to be relative from the home directory of the node's // user. diff --git a/pkg/security/securitytest/test_certs/regenerate.sh b/pkg/security/securitytest/test_certs/regenerate.sh index 67d7e2fa903e..135764f4ed70 100755 --- a/pkg/security/securitytest/test_certs/regenerate.sh +++ b/pkg/security/securitytest/test_certs/regenerate.sh @@ -7,9 +7,9 @@ rm -f "${dir_n}"/*.{crt,key} ./cockroach cert --certs-dir="${dir_n}" --ca-key="${dir_n}/ca.key" create-node 127.0.0.1 ::1 localhost *.local # Create client certs with tenant scopes. -./cockroach cert --certs-dir="${dir_n}" --ca-key="${dir_n}/ca.key" create-client root --tenant-scope 1,2,10,11,20 -./cockroach cert --certs-dir="${dir_n}" --ca-key="${dir_n}/ca.key" create-client testuser --tenant-scope 1,2,10,11,20 -./cockroach cert --certs-dir="${dir_n}" --ca-key="${dir_n}/ca.key" create-client testuser2 --tenant-scope 1,2,10,11,20 +./cockroach cert --certs-dir="${dir_n}" --ca-key="${dir_n}/ca.key" create-client root +./cockroach cert --certs-dir="${dir_n}" --ca-key="${dir_n}/ca.key" create-client testuser +./cockroach cert --certs-dir="${dir_n}" --ca-key="${dir_n}/ca.key" create-client testuser2 # Tenant certs ./cockroach mt cert --certs-dir="${dir_n}" --ca-key="${dir_n}/ca-client-tenant.key" create-tenant-client-ca diff --git a/pkg/sql/opt/xform/testdata/external/activerecord b/pkg/sql/opt/xform/testdata/external/activerecord index 60f27c1ca974..af051a26e8af 100644 --- a/pkg/sql/opt/xform/testdata/external/activerecord +++ b/pkg/sql/opt/xform/testdata/external/activerecord @@ -118,98 +118,109 @@ sort ├── columns: attname:2!null format_type:75 pg_get_expr:76 attnotnull:13!null atttypid:3!null atttypmod:9!null collname:77 comment:85 [hidden: attnum:6!null] ├── stable ├── key: (6) - ├── fd: (6)-->(2,3,9,13,75-77,85), (2)-->(3,6,9,13,75-77), (3,9)-->(75) + ├── fd: (6)-->(2,3,9,13,75-77,85), (2)-->(3,6,9,13,75-77,85), (3,9)-->(75) ├── ordering: +6 └── project ├── columns: format_type:75 pg_get_expr:76 collname:77 comment:85 attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null ├── stable ├── key: (6) - ├── fd: (6)-->(2,3,9,13,75-77,85), (2)-->(3,6,9,13,75-77), (3,9)-->(75) - ├── right-join (hash) - │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null attisdropped:17!null attcollation:20!null adrelid:27 adnum:28 adbin:29 c.oid:33 c.collname:34 t.oid:42 typcollation:69 + ├── fd: (6)-->(2,3,9,13,75-77,85), (2)-->(3,6,9,13,75-77,85), (3,9)-->(75) + ├── distinct-on + │ ├── columns: attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null adrelid:27 adbin:29 c.collname:34 c.comment:84 + │ ├── grouping columns: attnum:6!null + │ ├── immutable │ ├── key: (6) - │ ├── fd: ()-->(1,17), (6)-->(2,3,9,13,20,27-29,33,34,42,69), (2)-->(3,6,9,13,20), (28)-->(29), (33)-->(34), (42)-->(69) - │ ├── inner-join (cross) - │ │ ├── columns: c.oid:33!null c.collname:34!null t.oid:42!null typcollation:69!null - │ │ ├── key: (33,42) - │ │ ├── fd: (33)-->(34), (42)-->(69) - │ │ ├── scan pg_collation@pg_collation_name_enc_nsp_index [as=c] - │ │ │ ├── columns: c.oid:33!null c.collname:34!null - │ │ │ ├── key: (33) - │ │ │ └── fd: (33)-->(34) - │ │ ├── scan pg_type [as=t] - │ │ │ ├── columns: t.oid:42!null typcollation:69!null - │ │ │ ├── key: (42) - │ │ │ └── fd: (42)-->(69) - │ │ └── filters - │ │ └── c.oid:33 != typcollation:69 [outer=(33,69), constraints=(/33: (/NULL - ]; /69: (/NULL - ])] - │ ├── left-join (lookup pg_attrdef [as=d]) - │ │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null attisdropped:17!null attcollation:20!null adrelid:27 adnum:28 adbin:29 - │ │ ├── key columns: [26] = [26] - │ │ ├── lookup columns are key - │ │ ├── key: (6) - │ │ ├── fd: ()-->(1,17), (6)-->(2,3,9,13,20,27-29), (2)-->(3,6,9,13,20), (28)-->(29) - │ │ ├── left-join (lookup pg_attrdef@pg_attrdef_adrelid_adnum_index [as=d]) - │ │ │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null attisdropped:17!null attcollation:20!null d.oid:26 adrelid:27 adnum:28 - │ │ │ ├── key columns: [1 6] = [27 28] - │ │ │ ├── lookup columns are key + │ ├── fd: (6)-->(2,3,9,13,27,29,34,84), (2)-->(3,6,9,13,27,29,34) + │ ├── right-join (hash) + │ │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null adrelid:27 adbin:29 c.collname:34 type:81 object_id:82 sub_id:83 c.comment:84 column86:86!null + │ │ ├── immutable + │ │ ├── fd: ()-->(1,86), (6)-->(2,3,9,13,27,29,34), (2)-->(3,6,9,13,27,29,34) + │ │ ├── select + │ │ │ ├── columns: type:81!null object_id:82!null sub_id:83!null c.comment:84!null + │ │ │ ├── fd: ()-->(81) + │ │ │ ├── scan comments [as=c] + │ │ │ │ └── columns: type:81!null object_id:82!null sub_id:83!null c.comment:84!null + │ │ │ └── filters + │ │ │ ├── type:81 = 2 [outer=(81), constraints=(/81: [/2 - /2]; tight), fd=()-->(81)] + │ │ │ └── sub_id:83 != 0 [outer=(83), constraints=(/83: (/NULL - /-1] [/1 - ]; tight)] + │ │ ├── project + │ │ │ ├── columns: column86:86!null attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null adrelid:27 adbin:29 c.collname:34 + │ │ │ ├── immutable │ │ │ ├── key: (6) - │ │ │ ├── fd: ()-->(1,17), (6)-->(2,3,9,13,20,26-28), (2)-->(3,6,9,13,20), (26)-->(27,28), (27,28)-->(26) - │ │ │ ├── select - │ │ │ │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null attisdropped:17!null attcollation:20!null + │ │ │ ├── fd: ()-->(1,86), (6)-->(2,3,9,13,27,29,34), (2)-->(3,6,9,13,27,29,34) + │ │ │ ├── right-join (hash) + │ │ │ │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null attisdropped:17!null attcollation:20!null adrelid:27 adnum:28 adbin:29 c.oid:33 c.collname:34 t.oid:42 typcollation:69 │ │ │ │ ├── key: (6) - │ │ │ │ ├── fd: ()-->(1,17), (6)-->(2,3,9,13,20), (2)-->(3,6,9,13,20) - │ │ │ │ ├── scan pg_attribute [as=a] - │ │ │ │ │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null attisdropped:17!null attcollation:20!null - │ │ │ │ │ ├── constraint: /1/6: [/numbers/1 - /numbers] + │ │ │ │ ├── fd: ()-->(1,17), (6)-->(2,3,9,13,20,27-29,33,34,42,69), (2)-->(3,6,9,13,20), (28)-->(29), (33)-->(34), (42)-->(69) + │ │ │ │ ├── inner-join (cross) + │ │ │ │ │ ├── columns: c.oid:33!null c.collname:34!null t.oid:42!null typcollation:69!null + │ │ │ │ │ ├── key: (33,42) + │ │ │ │ │ ├── fd: (33)-->(34), (42)-->(69) + │ │ │ │ │ ├── scan pg_collation@pg_collation_name_enc_nsp_index [as=c] + │ │ │ │ │ │ ├── columns: c.oid:33!null c.collname:34!null + │ │ │ │ │ │ ├── key: (33) + │ │ │ │ │ │ └── fd: (33)-->(34) + │ │ │ │ │ ├── scan pg_type [as=t] + │ │ │ │ │ │ ├── columns: t.oid:42!null typcollation:69!null + │ │ │ │ │ │ ├── key: (42) + │ │ │ │ │ │ └── fd: (42)-->(69) + │ │ │ │ │ └── filters + │ │ │ │ │ └── c.oid:33 != typcollation:69 [outer=(33,69), constraints=(/33: (/NULL - ]; /69: (/NULL - ])] + │ │ │ │ ├── left-join (lookup pg_attrdef [as=d]) + │ │ │ │ │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null attisdropped:17!null attcollation:20!null adrelid:27 adnum:28 adbin:29 + │ │ │ │ │ ├── key columns: [26] = [26] + │ │ │ │ │ ├── lookup columns are key │ │ │ │ │ ├── key: (6) - │ │ │ │ │ └── fd: ()-->(1), (6)-->(2,3,9,13,17,20), (2)-->(3,6,9,13,17,20) + │ │ │ │ │ ├── fd: ()-->(1,17), (6)-->(2,3,9,13,20,27-29), (2)-->(3,6,9,13,20), (28)-->(29) + │ │ │ │ │ ├── left-join (lookup pg_attrdef@pg_attrdef_adrelid_adnum_index [as=d]) + │ │ │ │ │ │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null attisdropped:17!null attcollation:20!null d.oid:26 adrelid:27 adnum:28 + │ │ │ │ │ │ ├── key columns: [1 6] = [27 28] + │ │ │ │ │ │ ├── lookup columns are key + │ │ │ │ │ │ ├── key: (6) + │ │ │ │ │ │ ├── fd: ()-->(1,17), (6)-->(2,3,9,13,20,26-28), (2)-->(3,6,9,13,20), (26)-->(27,28), (27,28)-->(26) + │ │ │ │ │ │ ├── select + │ │ │ │ │ │ │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null attisdropped:17!null attcollation:20!null + │ │ │ │ │ │ │ ├── key: (6) + │ │ │ │ │ │ │ ├── fd: ()-->(1,17), (6)-->(2,3,9,13,20), (2)-->(3,6,9,13,20) + │ │ │ │ │ │ │ ├── scan pg_attribute [as=a] + │ │ │ │ │ │ │ │ ├── columns: attrelid:1!null attname:2!null atttypid:3!null attnum:6!null atttypmod:9!null attnotnull:13!null attisdropped:17!null attcollation:20!null + │ │ │ │ │ │ │ │ ├── constraint: /1/6: [/numbers/1 - /numbers] + │ │ │ │ │ │ │ │ ├── key: (6) + │ │ │ │ │ │ │ │ └── fd: ()-->(1), (6)-->(2,3,9,13,17,20), (2)-->(3,6,9,13,17,20) + │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ └── NOT attisdropped:17 [outer=(17), constraints=(/17: [/false - /false]; tight), fd=()-->(17)] + │ │ │ │ │ │ └── filters + │ │ │ │ │ │ ├── adrelid:27 = numbers [outer=(27), constraints=(/27: [/numbers - /numbers]; tight), fd=()-->(27)] + │ │ │ │ │ │ └── adnum:28 > 0 [outer=(28), constraints=(/28: [/1 - ]; tight)] + │ │ │ │ │ └── filters (true) │ │ │ │ └── filters - │ │ │ │ └── NOT attisdropped:17 [outer=(17), constraints=(/17: [/false - /false]; tight), fd=()-->(17)] - │ │ │ └── filters - │ │ │ ├── adrelid:27 = numbers [outer=(27), constraints=(/27: [/numbers - /numbers]; tight), fd=()-->(27)] - │ │ │ └── adnum:28 > 0 [outer=(28), constraints=(/28: [/1 - ]; tight)] - │ │ └── filters (true) - │ └── filters - │ ├── c.oid:33 = attcollation:20 [outer=(20,33), constraints=(/20: (/NULL - ]; /33: (/NULL - ]), fd=(20)==(33), (33)==(20)] - │ └── t.oid:42 = atttypid:3 [outer=(3,42), constraints=(/3: (/NULL - ]; /42: (/NULL - ]), fd=(3)==(42), (42)==(3)] + │ │ │ │ ├── c.oid:33 = attcollation:20 [outer=(20,33), constraints=(/20: (/NULL - ]; /33: (/NULL - ]), fd=(20)==(33), (33)==(20)] + │ │ │ │ └── t.oid:42 = atttypid:3 [outer=(3,42), constraints=(/3: (/NULL - ]; /42: (/NULL - ]), fd=(3)==(42), (42)==(3)] + │ │ │ └── projections + │ │ │ └── attrelid:1::INT8 [as=column86:86, outer=(1), immutable] + │ │ └── filters + │ │ ├── column86:86 = object_id:82 [outer=(82,86), constraints=(/82: (/NULL - ]; /86: (/NULL - ]), fd=(82)==(86), (86)==(82)] + │ │ ├── sub_id:83 = attnum:6 [outer=(6,83), constraints=(/6: (/NULL - ]; /83: (/NULL - ]), fd=(6)==(83), (83)==(6)] + │ │ └── attrelid:1 < 4294966993 [outer=(1), constraints=(/1: (/NULL - /4294966992]; tight)] + │ └── aggregations + │ ├── const-agg [as=attname:2, outer=(2)] + │ │ └── attname:2 + │ ├── const-agg [as=atttypid:3, outer=(3)] + │ │ └── atttypid:3 + │ ├── const-agg [as=atttypmod:9, outer=(9)] + │ │ └── atttypmod:9 + │ ├── const-agg [as=attnotnull:13, outer=(13)] + │ │ └── attnotnull:13 + │ ├── const-agg [as=adrelid:27, outer=(27)] + │ │ └── adrelid:27 + │ ├── const-agg [as=adbin:29, outer=(29)] + │ │ └── adbin:29 + │ ├── const-agg [as=c.collname:34, outer=(34)] + │ │ └── c.collname:34 + │ └── first-agg [as=c.comment:84, outer=(84)] + │ └── c.comment:84 └── projections ├── format_type(atttypid:3, atttypmod:9) [as=format_type:75, outer=(3,9), stable] ├── pg_get_expr(adbin:29, adrelid:27) [as=pg_get_expr:76, outer=(27,29), stable] ├── c.collname:34 [as=collname:77, outer=(34)] - └── case [as=comment:85, outer=(1,6), immutable, correlated-subquery] - ├── true - ├── when - │ ├── (attnum:6 IS NULL) OR (attrelid:1 IS NULL) - │ └── CAST(NULL AS STRING) - └── subquery - └── project - ├── columns: c.comment:84!null - ├── outer: (1,6) - ├── cardinality: [0 - 1] - ├── immutable - ├── key: () - ├── fd: ()-->(84) - └── limit - ├── columns: type:81!null object_id:82!null sub_id:83!null c.comment:84!null - ├── outer: (1,6) - ├── cardinality: [0 - 1] - ├── immutable - ├── key: () - ├── fd: ()-->(81-84) - ├── select - │ ├── columns: type:81!null object_id:82!null sub_id:83!null c.comment:84!null - │ ├── outer: (1,6) - │ ├── immutable - │ ├── fd: ()-->(81-83) - │ ├── limit hint: 1.00 - │ ├── scan comments [as=c] - │ │ ├── columns: type:81!null object_id:82!null sub_id:83!null c.comment:84!null - │ │ └── limit hint: 300.00 - │ └── filters - │ ├── type:81 = 2 [outer=(81), constraints=(/81: [/2 - /2]; tight), fd=()-->(81)] - │ ├── object_id:82 = attrelid:1::INT8 [outer=(1,82), immutable, constraints=(/82: (/NULL - ]), fd=(1)-->(82)] - │ ├── sub_id:83 = attnum:6 [outer=(6,83), constraints=(/6: (/NULL - ]; /83: (/NULL - ]), fd=(6)==(83), (83)==(6)] - │ ├── attrelid:1 < 4294966993 [outer=(1), constraints=(/1: (/NULL - /4294966992]; tight)] - │ └── attnum:6 != 0 [outer=(6), constraints=(/6: (/NULL - /-1] [/1 - ]; tight)] - └── 1 + └── c.comment:84 [as=comment:85, outer=(84)] diff --git a/pkg/sql/opt/xform/testdata/external/liquibase b/pkg/sql/opt/xform/testdata/external/liquibase index 7585f0a05df3..45219961e5ba 100644 --- a/pkg/sql/opt/xform/testdata/external/liquibase +++ b/pkg/sql/opt/xform/testdata/external/liquibase @@ -165,117 +165,154 @@ project ├── immutable ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37) ├── group-by (hash) - │ ├── columns: c.oid:1!null c.relname:2!null c.relowner:5!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 count_rows:154!null pg_catalog.pg_description.description:179 rownum:182!null + │ ├── columns: c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 count_rows:154!null column172:172 pg_catalog.pg_description.description:179 rownum:182!null │ ├── grouping columns: rownum:182!null + │ ├── immutable │ ├── key: (182) - │ ├── fd: ()-->(31), (1)-->(2,5,10,13,15,17,20,22,23,26,27,37), (2)-->(1,5,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,5,10,13,15,17,20,22,23,26,27,31,37,50,79,106,136,140,154,179) + │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,10,13,15,17,20,22,23,26,27,31,37,50,79,106,136,140,154,172,179) │ ├── right-join (hash) - │ │ ├── columns: c.oid:1!null c.relname:2!null c.relowner:5!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 pg_inherits.inhparent:150 pg_catalog.pg_description.description:179 rownum:182!null - │ │ ├── fd: ()-->(31), (1)-->(2,5,10,13,15,17,20,22,23,26,27,37), (2)-->(1,5,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,5,10,13,15,17,20,22,23,26,27,37,50,79,106,136,140,179) + │ │ ├── columns: c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 pg_inherits.inhparent:150 column172:172 pg_catalog.pg_description.description:179 rownum:182!null + │ │ ├── immutable + │ │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,10,13,15,17,20,22,23,26,27,37,50,79,106,136,140,172,179) │ │ ├── scan pg_inherits │ │ │ └── columns: pg_inherits.inhparent:150!null │ │ ├── distinct-on - │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relowner:5!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 pg_catalog.pg_description.description:179 rownum:182!null + │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 column172:172 pg_catalog.pg_description.description:179 rownum:182!null │ │ │ ├── grouping columns: rownum:182!null + │ │ │ ├── immutable │ │ │ ├── key: (182) - │ │ │ ├── fd: ()-->(31), (1)-->(2,5,10,13,15,17,20,22,23,26,27,37), (2)-->(1,5,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,5,10,13,15,17,20,22,23,26,27,31,37,50,79,106,136,140,179) + │ │ │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,10,13,15,17,20,22,23,26,27,31,37,50,79,106,136,140,172,179) │ │ │ ├── left-join (hash) - │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 n2.oid:78 n2.nspname:79 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 objoid:176 objsubid:178 pg_catalog.pg_description.description:179 rownum:182!null - │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(30), (30)==(3), (36)-->(37), (37)-->(36), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (78)~~>(79), (79)~~>(78), (84)-->(85), (105)-->(106), (134)-->(135,136), (139)-->(140), (140)-->(139), (182)-->(1,2,5,8,10,13,15,17,20,22,23,26,27,36,37,44,45,49-51,78,79,84,85,91,105,106,134-136,139,140) + │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 column172:172 objoid:176 objsubid:178 pg_catalog.pg_description.description:179 rownum:182!null + │ │ │ │ ├── immutable + │ │ │ │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,10,13,15,17,20,22,23,26,27,37,50,79,106,136,140,172) │ │ │ │ ├── ordinality - │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 n2.oid:78 n2.nspname:79 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 rownum:182!null + │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 column172:172 rownum:182!null + │ │ │ │ │ ├── immutable │ │ │ │ │ ├── key: (182) - │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(30), (30)==(3), (36)-->(37), (37)-->(36), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (78)~~>(79), (79)~~>(78), (84)-->(85), (105)-->(106), (134)-->(135,136), (139)-->(140), (140)-->(139), (182)-->(1-3,5,8,10,13,15,17,20,22,23,26,27,30,31,36,37,44,45,49-51,78,79,84,85,91,105,106,134-136,139,140) - │ │ │ │ │ └── left-join (lookup pg_namespace [as=n2]) - │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 n2.oid:78 n2.nspname:79 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ ├── key columns: [51] = [78] - │ │ │ │ │ ├── lookup columns are key - │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(30), (30)==(3), (36)-->(37), (37)-->(36), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (78)~~>(79), (79)~~>(78), (84)-->(85), (105)-->(106), (134)-->(135,136), (139)-->(140), (140)-->(139) - │ │ │ │ │ ├── right-join (hash) - │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(91,105,106), (105)-->(106), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) - │ │ │ │ │ │ ├── inner-join (hash) - │ │ │ │ │ │ │ ├── columns: i.inhrelid:44!null i.inhparent:45!null c2.oid:49!null c2.relname:50!null c2.relnamespace:51!null - │ │ │ │ │ │ │ ├── multiplicity: left-rows(zero-or-one), right-rows(zero-or-more) - │ │ │ │ │ │ │ ├── fd: (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45) - │ │ │ │ │ │ │ ├── scan pg_inherits [as=i] - │ │ │ │ │ │ │ │ └── columns: i.inhrelid:44!null i.inhparent:45!null - │ │ │ │ │ │ │ ├── scan pg_class@pg_class_relname_nsp_index [as=c2] - │ │ │ │ │ │ │ │ ├── columns: c2.oid:49!null c2.relname:50!null c2.relnamespace:51!null - │ │ │ │ │ │ │ │ ├── key: (49) - │ │ │ │ │ │ │ │ └── fd: (49)-->(50,51), (50,51)-->(49) - │ │ │ │ │ │ │ └── filters - │ │ │ │ │ │ │ └── i.inhparent:45 = c2.oid:49 [outer=(45,49), constraints=(/45: (/NULL - ]; /49: (/NULL - ]), fd=(45)==(49), (49)==(45)] - │ │ │ │ │ │ ├── left-join (lookup pg_class [as=ci]) - │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ │ │ ├── key columns: [84] = [105] - │ │ │ │ │ │ │ ├── lookup columns are key - │ │ │ │ │ │ │ ├── key: (1,84) - │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(36,37,91,105,106), (105)-->(106), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) - │ │ │ │ │ │ │ ├── left-join (lookup pg_index [as=ind]) - │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 indexrelid:84 indrelid:85 indisclustered:91 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ │ │ │ ├── key columns: [956] = [84] + │ │ │ │ │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,10,13,15,17,20,22,23,26,27,31,37,50,79,106,136,140,172) + │ │ │ │ │ └── project + │ │ │ │ │ ├── columns: column172:172 c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 + │ │ │ │ │ ├── immutable + │ │ │ │ │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37) + │ │ │ │ │ ├── left-join (lookup pg_namespace [as=n2]) + │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 n2.oid:78 n2.nspname:79 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ ├── key columns: [51] = [78] + │ │ │ │ │ │ ├── lookup columns are key + │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(30), (30)==(3), (36)-->(37), (37)-->(36), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (78)~~>(79), (79)~~>(78), (84)-->(85), (105)-->(106), (134)-->(135,136), (139)-->(140), (140)-->(139) + │ │ │ │ │ │ ├── right-join (hash) + │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(91,105,106), (105)-->(106), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ ├── inner-join (hash) + │ │ │ │ │ │ │ │ ├── columns: i.inhrelid:44!null i.inhparent:45!null c2.oid:49!null c2.relname:50!null c2.relnamespace:51!null + │ │ │ │ │ │ │ │ ├── multiplicity: left-rows(zero-or-one), right-rows(zero-or-more) + │ │ │ │ │ │ │ │ ├── fd: (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45) + │ │ │ │ │ │ │ │ ├── scan pg_inherits [as=i] + │ │ │ │ │ │ │ │ │ └── columns: i.inhrelid:44!null i.inhparent:45!null + │ │ │ │ │ │ │ │ ├── scan pg_class@pg_class_relname_nsp_index [as=c2] + │ │ │ │ │ │ │ │ │ ├── columns: c2.oid:49!null c2.relname:50!null c2.relnamespace:51!null + │ │ │ │ │ │ │ │ │ ├── key: (49) + │ │ │ │ │ │ │ │ │ └── fd: (49)-->(50,51), (50,51)-->(49) + │ │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ │ └── i.inhparent:45 = c2.oid:49 [outer=(45,49), constraints=(/45: (/NULL - ]; /49: (/NULL - ]), fd=(45)==(49), (49)==(45)] + │ │ │ │ │ │ │ ├── left-join (lookup pg_class [as=ci]) + │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ │ │ ├── key columns: [84] = [105] │ │ │ │ │ │ │ │ ├── lookup columns are key - │ │ │ │ │ │ │ │ ├── second join in paired joiner │ │ │ │ │ │ │ │ ├── key: (1,84) - │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(36,37,91), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) - │ │ │ │ │ │ │ │ ├── left-join (lookup pg_index@pg_index_indrelid_index [as=ind]) - │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 indexrelid:956 indrelid:957 continuation:977 - │ │ │ │ │ │ │ │ │ ├── key columns: [1] = [957] - │ │ │ │ │ │ │ │ │ ├── first join in paired joiner; continuation column: continuation:977 - │ │ │ │ │ │ │ │ │ ├── key: (1,956) - │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3), (956)-->(957,977) - │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_tablespace [as=t]) - │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ │ │ │ │ │ ├── key columns: [8] = [36] - │ │ │ │ │ │ │ │ │ │ ├── lookup columns are key - │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) - │ │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_foreign_server [as=fs]) - │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ │ │ │ │ │ │ ├── key columns: [135] = [139] + │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(36,37,91,105,106), (105)-->(106), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ │ ├── left-join (lookup pg_index [as=ind]) + │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 indexrelid:84 indrelid:85 indisclustered:91 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ │ │ │ ├── key columns: [956] = [84] + │ │ │ │ │ │ │ │ │ ├── lookup columns are key + │ │ │ │ │ │ │ │ │ ├── second join in paired joiner + │ │ │ │ │ │ │ │ │ ├── key: (1,84) + │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(36,37,91), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_index@pg_index_indrelid_index [as=ind]) + │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 indexrelid:956 indrelid:957 continuation:977 + │ │ │ │ │ │ │ │ │ │ ├── key columns: [1] = [957] + │ │ │ │ │ │ │ │ │ │ ├── first join in paired joiner; continuation column: continuation:977 + │ │ │ │ │ │ │ │ │ │ ├── key: (1,956) + │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3), (956)-->(957,977) + │ │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_tablespace [as=t]) + │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ │ │ │ │ │ ├── key columns: [8] = [36] │ │ │ │ │ │ │ │ │ │ │ ├── lookup columns are key │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (3)==(30), (30)==(3) - │ │ │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_foreign_table [as=ft]) - │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null ftrelid:134 ftserver:135 ftoptions:136 - │ │ │ │ │ │ │ │ │ │ │ │ ├── key columns: [1] = [134] + │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_foreign_server [as=fs]) + │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ │ │ │ │ │ │ ├── key columns: [135] = [139] │ │ │ │ │ │ │ │ │ │ │ │ ├── lookup columns are key │ │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136), (3)==(30), (30)==(3) - │ │ │ │ │ │ │ │ │ │ │ │ ├── inner-join (hash) - │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null - │ │ │ │ │ │ │ │ │ │ │ │ │ ├── multiplicity: left-rows(zero-or-one), right-rows(zero-or-more) + │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_foreign_table [as=ft]) + │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null ftrelid:134 ftserver:135 ftoptions:136 + │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key columns: [1] = [134] + │ │ │ │ │ │ │ │ │ │ │ │ │ ├── lookup columns are key │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (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)==(30), (30)==(3) - │ │ │ │ │ │ │ │ │ │ │ │ │ ├── select - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 + │ │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ │ │ │ │ │ │ ├── inner-join (hash) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null + │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── multiplicity: left-rows(zero-or-one), right-rows(zero-or-more) │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: (1)-->(2,3,5,8,10,13,15,17,20,22,23,26,27), (2,3)-->(1,5,8,10,13,15,17,20,22,23,26,27) - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── scan pg_class [as=c] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (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)==(30), (30)==(3) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── select │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── fd: (1)-->(2,3,5,8,10,13,15,17,20,22,23,26,27), (2,3)-->(1,5,8,10,13,15,17,20,22,23,26,27) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: (1)-->(2,3,5,8,10,13,15,17,20,22,23,26,27), (2,3)-->(1,5,8,10,13,15,17,20,22,23,26,27) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── scan pg_class [as=c] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── fd: (1)-->(2,3,5,8,10,13,15,17,20,22,23,26,27), (2,3)-->(1,5,8,10,13,15,17,20,22,23,26,27) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── (c.relkind:17 = 'r') OR (c.relkind:17 = 'f') [outer=(17), constraints=(/17: [/'f' - /'f'] [/'r' - /'r']; tight)] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── scan pg_namespace@pg_namespace_nspname_index [as=n] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: n.oid:30!null n.nspname:31!null + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── constraint: /31: [/'public' - /'public'] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── cardinality: [0 - 1] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: () + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── fd: ()-->(30,31) │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── filters - │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── (c.relkind:17 = 'r') OR (c.relkind:17 = 'f') [outer=(17), constraints=(/17: [/'f' - /'f'] [/'r' - /'r']; tight)] - │ │ │ │ │ │ │ │ │ │ │ │ │ ├── scan pg_namespace@pg_namespace_nspname_index [as=n] - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: n.oid:30!null n.nspname:31!null - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── constraint: /31: [/'public' - /'public'] - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── cardinality: [0 - 1] - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: () - │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── fd: ()-->(30,31) - │ │ │ │ │ │ │ │ │ │ │ │ │ └── filters - │ │ │ │ │ │ │ │ │ │ │ │ │ └── n.oid:30 = c.relnamespace:3 [outer=(3,30), constraints=(/3: (/NULL - ]; /30: (/NULL - ]), fd=(3)==(30), (30)==(3)] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── n.oid:30 = c.relnamespace:3 [outer=(3,30), constraints=(/3: (/NULL - ]; /30: (/NULL - ]), fd=(3)==(30), (30)==(3)] + │ │ │ │ │ │ │ │ │ │ │ │ │ └── filters (true) │ │ │ │ │ │ │ │ │ │ │ │ └── filters (true) │ │ │ │ │ │ │ │ │ │ │ └── filters (true) │ │ │ │ │ │ │ │ │ │ └── filters (true) - │ │ │ │ │ │ │ │ │ └── filters (true) - │ │ │ │ │ │ │ │ └── filters - │ │ │ │ │ │ │ │ └── indisclustered:91 [outer=(91), constraints=(/91: [/true - /true]; tight), fd=()-->(91)] - │ │ │ │ │ │ │ └── filters (true) - │ │ │ │ │ │ └── filters - │ │ │ │ │ │ └── i.inhrelid:44 = c.oid:1 [outer=(1,44), constraints=(/1: (/NULL - ]; /44: (/NULL - ]), fd=(1)==(44), (44)==(1)] - │ │ │ │ │ └── filters (true) + │ │ │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ │ │ └── indisclustered:91 [outer=(91), constraints=(/91: [/true - /true]; tight), fd=()-->(91)] + │ │ │ │ │ │ │ │ └── filters (true) + │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ └── i.inhrelid:44 = c.oid:1 [outer=(1,44), constraints=(/1: (/NULL - ]; /44: (/NULL - ]), fd=(1)==(44), (44)==(1)] + │ │ │ │ │ │ └── filters (true) + │ │ │ │ │ └── projections + │ │ │ │ │ └── assignment-cast: STRING [as=column172:172, outer=(5), immutable, correlated-subquery] + │ │ │ │ │ └── coalesce + │ │ │ │ │ ├── subquery + │ │ │ │ │ │ └── project + │ │ │ │ │ │ ├── columns: rolname:158 + │ │ │ │ │ │ ├── outer: (5) + │ │ │ │ │ │ ├── cardinality: [0 - 1] + │ │ │ │ │ │ ├── key: () + │ │ │ │ │ │ ├── fd: ()-->(158) + │ │ │ │ │ │ └── limit + │ │ │ │ │ │ ├── columns: pg_catalog.pg_roles.oid:157!null rolname:158 + │ │ │ │ │ │ ├── outer: (5) + │ │ │ │ │ │ ├── cardinality: [0 - 1] + │ │ │ │ │ │ ├── key: () + │ │ │ │ │ │ ├── fd: ()-->(157,158) + │ │ │ │ │ │ ├── select + │ │ │ │ │ │ │ ├── columns: pg_catalog.pg_roles.oid:157!null rolname:158 + │ │ │ │ │ │ │ ├── outer: (5) + │ │ │ │ │ │ │ ├── fd: ()-->(157) + │ │ │ │ │ │ │ ├── limit hint: 1.00 + │ │ │ │ │ │ │ ├── scan pg_roles + │ │ │ │ │ │ │ │ ├── columns: pg_catalog.pg_roles.oid:157 rolname:158 + │ │ │ │ │ │ │ │ └── limit hint: 1.01 + │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ └── pg_catalog.pg_roles.oid:157 = c.relowner:5 [outer=(5,157), constraints=(/5: (/NULL - ]; /157: (/NULL - ]), fd=(5)==(157), (157)==(5)] + │ │ │ │ │ │ └── 1 + │ │ │ │ │ └── (('unknown (OID=' || c.relowner:5) || ')')::NAME │ │ │ │ ├── select │ │ │ │ │ ├── columns: objoid:176 objsubid:178!null pg_catalog.pg_description.description:179 │ │ │ │ │ ├── fd: ()-->(178) @@ -290,8 +327,6 @@ project │ │ │ │ └── c.oid:1 │ │ │ ├── const-agg [as=c.relname:2, outer=(2)] │ │ │ │ └── c.relname:2 - │ │ │ ├── const-agg [as=c.relowner:5, outer=(5)] - │ │ │ │ └── c.relowner:5 │ │ │ ├── const-agg [as=c.reltuples:10, outer=(10)] │ │ │ │ └── c.reltuples:10 │ │ │ ├── const-agg [as=c.relhasindex:13, outer=(13)] @@ -324,6 +359,8 @@ project │ │ │ │ └── ftoptions:136 │ │ │ ├── const-agg [as=srvname:140, outer=(140)] │ │ │ │ └── srvname:140 + │ │ │ ├── const-agg [as=column172:172, outer=(172)] + │ │ │ │ └── column172:172 │ │ │ └── first-agg [as=pg_catalog.pg_description.description:179, outer=(179)] │ │ │ └── pg_catalog.pg_description.description:179 │ │ └── filters @@ -335,8 +372,6 @@ project │ │ └── c.oid:1 │ ├── const-agg [as=c.relname:2, outer=(2)] │ │ └── c.relname:2 - │ ├── const-agg [as=c.relowner:5, outer=(5)] - │ │ └── c.relowner:5 │ ├── const-agg [as=c.reltuples:10, outer=(10)] │ │ └── c.reltuples:10 │ ├── const-agg [as=c.relhasindex:13, outer=(13)] @@ -369,49 +404,11 @@ project │ │ └── ftoptions:136 │ ├── const-agg [as=srvname:140, outer=(140)] │ │ └── srvname:140 + │ ├── const-agg [as=column172:172, outer=(172)] + │ │ └── column172:172 │ └── const-agg [as=pg_catalog.pg_description.description:179, outer=(179)] │ └── pg_catalog.pg_description.description:179 └── projections - ├── case [as=tableowner:173, outer=(5), immutable, correlated-subquery] - │ ├── true - │ ├── when - │ │ ├── c.relowner:5 IS NULL - │ │ └── CAST(NULL AS STRING) - │ └── subquery - │ └── values - │ ├── columns: column172:172 - │ ├── outer: (5) - │ ├── cardinality: [1 - 1] - │ ├── immutable - │ ├── key: () - │ ├── fd: ()-->(172) - │ └── tuple - │ └── assignment-cast: STRING - │ └── coalesce - │ ├── subquery - │ │ └── project - │ │ ├── columns: rolname:158 - │ │ ├── outer: (5) - │ │ ├── cardinality: [0 - 1] - │ │ ├── key: () - │ │ ├── fd: ()-->(158) - │ │ └── limit - │ │ ├── columns: pg_catalog.pg_roles.oid:157!null rolname:158 - │ │ ├── outer: (5) - │ │ ├── cardinality: [0 - 1] - │ │ ├── key: () - │ │ ├── fd: ()-->(157,158) - │ │ ├── select - │ │ │ ├── columns: pg_catalog.pg_roles.oid:157!null rolname:158 - │ │ │ ├── outer: (5) - │ │ │ ├── fd: ()-->(157) - │ │ │ ├── limit hint: 1.00 - │ │ │ ├── scan pg_roles - │ │ │ │ ├── columns: pg_catalog.pg_roles.oid:157 rolname:158 - │ │ │ │ └── limit hint: 1.01 - │ │ │ └── filters - │ │ │ └── pg_catalog.pg_roles.oid:157 = c.relowner:5 [outer=(5,157), constraints=(/5: (/NULL - ]; /157: (/NULL - ]), fd=(5)==(157), (157)==(5)] - │ │ └── 1 - │ └── (('unknown (OID=' || c.relowner:5) || ')')::NAME - ├── CASE WHEN c.oid:1 IS NULL THEN CAST(NULL AS STRING) ELSE pg_catalog.pg_description.description:179 END [as=description:180, outer=(1,179)] + ├── column172:172 [as=tableowner:173, outer=(172)] + ├── pg_catalog.pg_description.description:179 [as=description:180, outer=(179)] └── count_rows:154 > 0 [as=inhtable:181, outer=(154)] diff --git a/pkg/sql/opt/xform/testdata/external/navicat b/pkg/sql/opt/xform/testdata/external/navicat index 69ef0dcfe7fb..b979ade646d7 100644 --- a/pkg/sql/opt/xform/testdata/external/navicat +++ b/pkg/sql/opt/xform/testdata/external/navicat @@ -169,117 +169,154 @@ sort ├── immutable ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37) ├── group-by (hash) - │ ├── columns: c.oid:1!null c.relname:2!null c.relowner:5!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 count_rows:154!null pg_catalog.pg_description.description:179 rownum:182!null + │ ├── columns: c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 count_rows:154!null column172:172 pg_catalog.pg_description.description:179 rownum:182!null │ ├── grouping columns: rownum:182!null + │ ├── immutable │ ├── key: (182) - │ ├── fd: ()-->(31), (1)-->(2,5,10,13,15,17,20,22,23,26,27,37), (2)-->(1,5,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,5,10,13,15,17,20,22,23,26,27,31,37,50,79,106,136,140,154,179) + │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,10,13,15,17,20,22,23,26,27,31,37,50,79,106,136,140,154,172,179) │ ├── right-join (hash) - │ │ ├── columns: c.oid:1!null c.relname:2!null c.relowner:5!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 pg_inherits.inhparent:150 pg_catalog.pg_description.description:179 rownum:182!null - │ │ ├── fd: ()-->(31), (1)-->(2,5,10,13,15,17,20,22,23,26,27,37), (2)-->(1,5,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,5,10,13,15,17,20,22,23,26,27,37,50,79,106,136,140,179) + │ │ ├── columns: c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 pg_inherits.inhparent:150 column172:172 pg_catalog.pg_description.description:179 rownum:182!null + │ │ ├── immutable + │ │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,10,13,15,17,20,22,23,26,27,37,50,79,106,136,140,172,179) │ │ ├── scan pg_inherits │ │ │ └── columns: pg_inherits.inhparent:150!null │ │ ├── distinct-on - │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relowner:5!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 pg_catalog.pg_description.description:179 rownum:182!null + │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 column172:172 pg_catalog.pg_description.description:179 rownum:182!null │ │ │ ├── grouping columns: rownum:182!null + │ │ │ ├── immutable │ │ │ ├── key: (182) - │ │ │ ├── fd: ()-->(31), (1)-->(2,5,10,13,15,17,20,22,23,26,27,37), (2)-->(1,5,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,5,10,13,15,17,20,22,23,26,27,31,37,50,79,106,136,140,179) + │ │ │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,10,13,15,17,20,22,23,26,27,31,37,50,79,106,136,140,172,179) │ │ │ ├── left-join (hash) - │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 n2.oid:78 n2.nspname:79 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 objoid:176 objsubid:178 pg_catalog.pg_description.description:179 rownum:182!null - │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(30), (30)==(3), (36)-->(37), (37)-->(36), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (78)~~>(79), (79)~~>(78), (84)-->(85), (105)-->(106), (134)-->(135,136), (139)-->(140), (140)-->(139), (182)-->(1,2,5,8,10,13,15,17,20,22,23,26,27,36,37,44,45,49-51,78,79,84,85,91,105,106,134-136,139,140) + │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 column172:172 objoid:176 objsubid:178 pg_catalog.pg_description.description:179 rownum:182!null + │ │ │ │ ├── immutable + │ │ │ │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,10,13,15,17,20,22,23,26,27,37,50,79,106,136,140,172) │ │ │ │ ├── ordinality - │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 n2.oid:78 n2.nspname:79 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 rownum:182!null + │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 column172:172 rownum:182!null + │ │ │ │ │ ├── immutable │ │ │ │ │ ├── key: (182) - │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(30), (30)==(3), (36)-->(37), (37)-->(36), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (78)~~>(79), (79)~~>(78), (84)-->(85), (105)-->(106), (134)-->(135,136), (139)-->(140), (140)-->(139), (182)-->(1-3,5,8,10,13,15,17,20,22,23,26,27,30,31,36,37,44,45,49-51,78,79,84,85,91,105,106,134-136,139,140) - │ │ │ │ │ └── left-join (lookup pg_namespace [as=n2]) - │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 n2.oid:78 n2.nspname:79 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ ├── key columns: [51] = [78] - │ │ │ │ │ ├── lookup columns are key - │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(30), (30)==(3), (36)-->(37), (37)-->(36), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (78)~~>(79), (79)~~>(78), (84)-->(85), (105)-->(106), (134)-->(135,136), (139)-->(140), (140)-->(139) - │ │ │ │ │ ├── right-join (hash) - │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(91,105,106), (105)-->(106), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) - │ │ │ │ │ │ ├── inner-join (hash) - │ │ │ │ │ │ │ ├── columns: i.inhrelid:44!null i.inhparent:45!null c2.oid:49!null c2.relname:50!null c2.relnamespace:51!null - │ │ │ │ │ │ │ ├── multiplicity: left-rows(zero-or-one), right-rows(zero-or-more) - │ │ │ │ │ │ │ ├── fd: (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45) - │ │ │ │ │ │ │ ├── scan pg_inherits [as=i] - │ │ │ │ │ │ │ │ └── columns: i.inhrelid:44!null i.inhparent:45!null - │ │ │ │ │ │ │ ├── scan pg_class@pg_class_relname_nsp_index [as=c2] - │ │ │ │ │ │ │ │ ├── columns: c2.oid:49!null c2.relname:50!null c2.relnamespace:51!null - │ │ │ │ │ │ │ │ ├── key: (49) - │ │ │ │ │ │ │ │ └── fd: (49)-->(50,51), (50,51)-->(49) - │ │ │ │ │ │ │ └── filters - │ │ │ │ │ │ │ └── i.inhparent:45 = c2.oid:49 [outer=(45,49), constraints=(/45: (/NULL - ]; /49: (/NULL - ]), fd=(45)==(49), (49)==(45)] - │ │ │ │ │ │ ├── left-join (lookup pg_class [as=ci]) - │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ │ │ ├── key columns: [84] = [105] - │ │ │ │ │ │ │ ├── lookup columns are key - │ │ │ │ │ │ │ ├── key: (1,84) - │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(36,37,91,105,106), (105)-->(106), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) - │ │ │ │ │ │ │ ├── left-join (lookup pg_index [as=ind]) - │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 indexrelid:84 indrelid:85 indisclustered:91 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ │ │ │ ├── key columns: [956] = [84] + │ │ │ │ │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37), (182)-->(1,2,10,13,15,17,20,22,23,26,27,31,37,50,79,106,136,140,172) + │ │ │ │ │ └── project + │ │ │ │ │ ├── columns: column172:172 c.oid:1!null c.relname:2!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.nspname:31!null spcname:37 c2.relname:50 n2.nspname:79 ci.relname:106 ftoptions:136 srvname:140 + │ │ │ │ │ ├── immutable + │ │ │ │ │ ├── fd: ()-->(31), (1)-->(2,10,13,15,17,20,22,23,26,27,37), (2)-->(1,10,13,15,17,20,22,23,26,27,37) + │ │ │ │ │ ├── left-join (lookup pg_namespace [as=n2]) + │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 n2.oid:78 n2.nspname:79 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ ├── key columns: [51] = [78] + │ │ │ │ │ │ ├── lookup columns are key + │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (3)==(30), (30)==(3), (36)-->(37), (37)-->(36), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (78)~~>(79), (79)~~>(78), (84)-->(85), (105)-->(106), (134)-->(135,136), (139)-->(140), (140)-->(139) + │ │ │ │ │ │ ├── right-join (hash) + │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 i.inhrelid:44 i.inhparent:45 c2.oid:49 c2.relname:50 c2.relnamespace:51 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(91,105,106), (105)-->(106), (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ ├── inner-join (hash) + │ │ │ │ │ │ │ │ ├── columns: i.inhrelid:44!null i.inhparent:45!null c2.oid:49!null c2.relname:50!null c2.relnamespace:51!null + │ │ │ │ │ │ │ │ ├── multiplicity: left-rows(zero-or-one), right-rows(zero-or-more) + │ │ │ │ │ │ │ │ ├── fd: (49)-->(50,51), (50,51)-->(49), (45)==(49), (49)==(45) + │ │ │ │ │ │ │ │ ├── scan pg_inherits [as=i] + │ │ │ │ │ │ │ │ │ └── columns: i.inhrelid:44!null i.inhparent:45!null + │ │ │ │ │ │ │ │ ├── scan pg_class@pg_class_relname_nsp_index [as=c2] + │ │ │ │ │ │ │ │ │ ├── columns: c2.oid:49!null c2.relname:50!null c2.relnamespace:51!null + │ │ │ │ │ │ │ │ │ ├── key: (49) + │ │ │ │ │ │ │ │ │ └── fd: (49)-->(50,51), (50,51)-->(49) + │ │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ │ └── i.inhparent:45 = c2.oid:49 [outer=(45,49), constraints=(/45: (/NULL - ]; /49: (/NULL - ]), fd=(45)==(49), (49)==(45)] + │ │ │ │ │ │ │ ├── left-join (lookup pg_class [as=ci]) + │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 indexrelid:84 indrelid:85 indisclustered:91 ci.oid:105 ci.relname:106 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ │ │ ├── key columns: [84] = [105] │ │ │ │ │ │ │ │ ├── lookup columns are key - │ │ │ │ │ │ │ │ ├── second join in paired joiner │ │ │ │ │ │ │ │ ├── key: (1,84) - │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(36,37,91), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) - │ │ │ │ │ │ │ │ ├── left-join (lookup pg_index@pg_index_indrelid_index [as=ind]) - │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 indexrelid:956 indrelid:957 continuation:977 - │ │ │ │ │ │ │ │ │ ├── key columns: [1] = [957] - │ │ │ │ │ │ │ │ │ ├── first join in paired joiner; continuation column: continuation:977 - │ │ │ │ │ │ │ │ │ ├── key: (1,956) - │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3), (956)-->(957,977) - │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_tablespace [as=t]) - │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ │ │ │ │ │ ├── key columns: [8] = [36] - │ │ │ │ │ │ │ │ │ │ ├── lookup columns are key - │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) - │ │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_foreign_server [as=fs]) - │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 - │ │ │ │ │ │ │ │ │ │ │ ├── key columns: [135] = [139] + │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(36,37,91,105,106), (105)-->(106), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ │ ├── left-join (lookup pg_index [as=ind]) + │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 indexrelid:84 indrelid:85 indisclustered:91 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ │ │ │ ├── key columns: [956] = [84] + │ │ │ │ │ │ │ │ │ ├── lookup columns are key + │ │ │ │ │ │ │ │ │ ├── second join in paired joiner + │ │ │ │ │ │ │ │ │ ├── key: (1,84) + │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (84)-->(85), (1,84)-->(36,37,91), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_index@pg_index_indrelid_index [as=ind]) + │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 indexrelid:956 indrelid:957 continuation:977 + │ │ │ │ │ │ │ │ │ │ ├── key columns: [1] = [957] + │ │ │ │ │ │ │ │ │ │ ├── first join in paired joiner; continuation column: continuation:977 + │ │ │ │ │ │ │ │ │ │ ├── key: (1,956) + │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3), (956)-->(957,977) + │ │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_tablespace [as=t]) + │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null t.oid:36 spcname:37 ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ │ │ │ │ │ ├── key columns: [8] = [36] │ │ │ │ │ │ │ │ │ │ │ ├── lookup columns are key │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (3)==(30), (30)==(3) - │ │ │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_foreign_table [as=ft]) - │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null ftrelid:134 ftserver:135 ftoptions:136 - │ │ │ │ │ │ │ │ │ │ │ │ ├── key columns: [1] = [134] + │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,36,37,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (36)-->(37), (37)-->(36), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_foreign_server [as=fs]) + │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null ftrelid:134 ftserver:135 ftoptions:136 fs.oid:139 srvname:140 + │ │ │ │ │ │ │ │ │ │ │ │ ├── key columns: [135] = [139] │ │ │ │ │ │ │ │ │ │ │ │ ├── lookup columns are key │ │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136), (3)==(30), (30)==(3) - │ │ │ │ │ │ │ │ │ │ │ │ ├── inner-join (hash) - │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null - │ │ │ │ │ │ │ │ │ │ │ │ │ ├── multiplicity: left-rows(zero-or-one), right-rows(zero-or-more) + │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136,139,140), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136,139,140), (139)~~>(140), (140)~~>(139), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ │ │ │ │ │ ├── left-join (lookup pg_foreign_table [as=ft]) + │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null ftrelid:134 ftserver:135 ftoptions:136 + │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key columns: [1] = [134] + │ │ │ │ │ │ │ │ │ │ │ │ │ ├── lookup columns are key │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (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)==(30), (30)==(3) - │ │ │ │ │ │ │ │ │ │ │ │ │ ├── select - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 + │ │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (1)-->(2,5,8,10,13,15,17,20,22,23,26,27,134-136), (2)-->(1,5,8,10,13,15,17,20,22,23,26,27), (134)-->(135,136), (3)==(30), (30)==(3) + │ │ │ │ │ │ │ │ │ │ │ │ │ ├── inner-join (hash) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 n.oid:30!null n.nspname:31!null + │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── multiplicity: left-rows(zero-or-one), right-rows(zero-or-more) │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: (1)-->(2,3,5,8,10,13,15,17,20,22,23,26,27), (2,3)-->(1,5,8,10,13,15,17,20,22,23,26,27) - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── scan pg_class [as=c] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: ()-->(3,30,31), (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)==(30), (30)==(3) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── select │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) - │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── fd: (1)-->(2,3,5,8,10,13,15,17,20,22,23,26,27), (2,3)-->(1,5,8,10,13,15,17,20,22,23,26,27) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── fd: (1)-->(2,3,5,8,10,13,15,17,20,22,23,26,27), (2,3)-->(1,5,8,10,13,15,17,20,22,23,26,27) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── scan pg_class [as=c] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: c.oid:1!null c.relname:2!null c.relnamespace:3!null c.relowner:5!null c.reltablespace:8!null c.reltuples:10!null c.relhasindex:13!null c.relpersistence:15!null c.relkind:17!null c.relhasoids:20!null c.relhasrules:22!null c.relhastriggers:23!null c.relacl:26 c.reloptions:27 + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: (1) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── fd: (1)-->(2,3,5,8,10,13,15,17,20,22,23,26,27), (2,3)-->(1,5,8,10,13,15,17,20,22,23,26,27) + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── (c.relkind:17 = 'r') OR (c.relkind:17 = 'f') [outer=(17), constraints=(/17: [/'f' - /'f'] [/'r' - /'r']; tight)] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── scan pg_namespace@pg_namespace_nspname_index [as=n] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: n.oid:30!null n.nspname:31!null + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── constraint: /31: [/'public' - /'public'] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── cardinality: [0 - 1] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: () + │ │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── fd: ()-->(30,31) │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── filters - │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── (c.relkind:17 = 'r') OR (c.relkind:17 = 'f') [outer=(17), constraints=(/17: [/'f' - /'f'] [/'r' - /'r']; tight)] - │ │ │ │ │ │ │ │ │ │ │ │ │ ├── scan pg_namespace@pg_namespace_nspname_index [as=n] - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── columns: n.oid:30!null n.nspname:31!null - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── constraint: /31: [/'public' - /'public'] - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── cardinality: [0 - 1] - │ │ │ │ │ │ │ │ │ │ │ │ │ │ ├── key: () - │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── fd: ()-->(30,31) - │ │ │ │ │ │ │ │ │ │ │ │ │ └── filters - │ │ │ │ │ │ │ │ │ │ │ │ │ └── n.oid:30 = c.relnamespace:3 [outer=(3,30), constraints=(/3: (/NULL - ]; /30: (/NULL - ]), fd=(3)==(30), (30)==(3)] + │ │ │ │ │ │ │ │ │ │ │ │ │ │ └── n.oid:30 = c.relnamespace:3 [outer=(3,30), constraints=(/3: (/NULL - ]; /30: (/NULL - ]), fd=(3)==(30), (30)==(3)] + │ │ │ │ │ │ │ │ │ │ │ │ │ └── filters (true) │ │ │ │ │ │ │ │ │ │ │ │ └── filters (true) │ │ │ │ │ │ │ │ │ │ │ └── filters (true) │ │ │ │ │ │ │ │ │ │ └── filters (true) - │ │ │ │ │ │ │ │ │ └── filters (true) - │ │ │ │ │ │ │ │ └── filters - │ │ │ │ │ │ │ │ └── indisclustered:91 [outer=(91), constraints=(/91: [/true - /true]; tight), fd=()-->(91)] - │ │ │ │ │ │ │ └── filters (true) - │ │ │ │ │ │ └── filters - │ │ │ │ │ │ └── i.inhrelid:44 = c.oid:1 [outer=(1,44), constraints=(/1: (/NULL - ]; /44: (/NULL - ]), fd=(1)==(44), (44)==(1)] - │ │ │ │ │ └── filters (true) + │ │ │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ │ │ └── indisclustered:91 [outer=(91), constraints=(/91: [/true - /true]; tight), fd=()-->(91)] + │ │ │ │ │ │ │ │ └── filters (true) + │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ └── i.inhrelid:44 = c.oid:1 [outer=(1,44), constraints=(/1: (/NULL - ]; /44: (/NULL - ]), fd=(1)==(44), (44)==(1)] + │ │ │ │ │ │ └── filters (true) + │ │ │ │ │ └── projections + │ │ │ │ │ └── assignment-cast: STRING [as=column172:172, outer=(5), immutable, correlated-subquery] + │ │ │ │ │ └── coalesce + │ │ │ │ │ ├── subquery + │ │ │ │ │ │ └── project + │ │ │ │ │ │ ├── columns: rolname:158 + │ │ │ │ │ │ ├── outer: (5) + │ │ │ │ │ │ ├── cardinality: [0 - 1] + │ │ │ │ │ │ ├── key: () + │ │ │ │ │ │ ├── fd: ()-->(158) + │ │ │ │ │ │ └── limit + │ │ │ │ │ │ ├── columns: pg_catalog.pg_roles.oid:157!null rolname:158 + │ │ │ │ │ │ ├── outer: (5) + │ │ │ │ │ │ ├── cardinality: [0 - 1] + │ │ │ │ │ │ ├── key: () + │ │ │ │ │ │ ├── fd: ()-->(157,158) + │ │ │ │ │ │ ├── select + │ │ │ │ │ │ │ ├── columns: pg_catalog.pg_roles.oid:157!null rolname:158 + │ │ │ │ │ │ │ ├── outer: (5) + │ │ │ │ │ │ │ ├── fd: ()-->(157) + │ │ │ │ │ │ │ ├── limit hint: 1.00 + │ │ │ │ │ │ │ ├── scan pg_roles + │ │ │ │ │ │ │ │ ├── columns: pg_catalog.pg_roles.oid:157 rolname:158 + │ │ │ │ │ │ │ │ └── limit hint: 1.01 + │ │ │ │ │ │ │ └── filters + │ │ │ │ │ │ │ └── pg_catalog.pg_roles.oid:157 = c.relowner:5 [outer=(5,157), constraints=(/5: (/NULL - ]; /157: (/NULL - ]), fd=(5)==(157), (157)==(5)] + │ │ │ │ │ │ └── 1 + │ │ │ │ │ └── (('unknown (OID=' || c.relowner:5) || ')')::NAME │ │ │ │ ├── select │ │ │ │ │ ├── columns: objoid:176 objsubid:178!null pg_catalog.pg_description.description:179 │ │ │ │ │ ├── fd: ()-->(178) @@ -294,8 +331,6 @@ sort │ │ │ │ └── c.oid:1 │ │ │ ├── const-agg [as=c.relname:2, outer=(2)] │ │ │ │ └── c.relname:2 - │ │ │ ├── const-agg [as=c.relowner:5, outer=(5)] - │ │ │ │ └── c.relowner:5 │ │ │ ├── const-agg [as=c.reltuples:10, outer=(10)] │ │ │ │ └── c.reltuples:10 │ │ │ ├── const-agg [as=c.relhasindex:13, outer=(13)] @@ -328,6 +363,8 @@ sort │ │ │ │ └── ftoptions:136 │ │ │ ├── const-agg [as=srvname:140, outer=(140)] │ │ │ │ └── srvname:140 + │ │ │ ├── const-agg [as=column172:172, outer=(172)] + │ │ │ │ └── column172:172 │ │ │ └── first-agg [as=pg_catalog.pg_description.description:179, outer=(179)] │ │ │ └── pg_catalog.pg_description.description:179 │ │ └── filters @@ -339,8 +376,6 @@ sort │ │ └── c.oid:1 │ ├── const-agg [as=c.relname:2, outer=(2)] │ │ └── c.relname:2 - │ ├── const-agg [as=c.relowner:5, outer=(5)] - │ │ └── c.relowner:5 │ ├── const-agg [as=c.reltuples:10, outer=(10)] │ │ └── c.reltuples:10 │ ├── const-agg [as=c.relhasindex:13, outer=(13)] @@ -373,49 +408,11 @@ sort │ │ └── ftoptions:136 │ ├── const-agg [as=srvname:140, outer=(140)] │ │ └── srvname:140 + │ ├── const-agg [as=column172:172, outer=(172)] + │ │ └── column172:172 │ └── const-agg [as=pg_catalog.pg_description.description:179, outer=(179)] │ └── pg_catalog.pg_description.description:179 └── projections - ├── case [as=tableowner:173, outer=(5), immutable, correlated-subquery] - │ ├── true - │ ├── when - │ │ ├── c.relowner:5 IS NULL - │ │ └── CAST(NULL AS STRING) - │ └── subquery - │ └── values - │ ├── columns: column172:172 - │ ├── outer: (5) - │ ├── cardinality: [1 - 1] - │ ├── immutable - │ ├── key: () - │ ├── fd: ()-->(172) - │ └── tuple - │ └── assignment-cast: STRING - │ └── coalesce - │ ├── subquery - │ │ └── project - │ │ ├── columns: rolname:158 - │ │ ├── outer: (5) - │ │ ├── cardinality: [0 - 1] - │ │ ├── key: () - │ │ ├── fd: ()-->(158) - │ │ └── limit - │ │ ├── columns: pg_catalog.pg_roles.oid:157!null rolname:158 - │ │ ├── outer: (5) - │ │ ├── cardinality: [0 - 1] - │ │ ├── key: () - │ │ ├── fd: ()-->(157,158) - │ │ ├── select - │ │ │ ├── columns: pg_catalog.pg_roles.oid:157!null rolname:158 - │ │ │ ├── outer: (5) - │ │ │ ├── fd: ()-->(157) - │ │ │ ├── limit hint: 1.00 - │ │ │ ├── scan pg_roles - │ │ │ │ ├── columns: pg_catalog.pg_roles.oid:157 rolname:158 - │ │ │ │ └── limit hint: 1.01 - │ │ │ └── filters - │ │ │ └── pg_catalog.pg_roles.oid:157 = c.relowner:5 [outer=(5,157), constraints=(/5: (/NULL - ]; /157: (/NULL - ]), fd=(5)==(157), (157)==(5)] - │ │ └── 1 - │ └── (('unknown (OID=' || c.relowner:5) || ')')::NAME - ├── CASE WHEN c.oid:1 IS NULL THEN CAST(NULL AS STRING) ELSE pg_catalog.pg_description.description:179 END [as=description:180, outer=(1,179)] + ├── column172:172 [as=tableowner:173, outer=(172)] + ├── pg_catalog.pg_description.description:179 [as=description:180, outer=(179)] └── count_rows:154 > 0 [as=inhtable:181, outer=(154)] diff --git a/pkg/sql/opt/xform/testdata/external/pgjdbc b/pkg/sql/opt/xform/testdata/external/pgjdbc index 3ada70d2e8a2..e9e40a3843ef 100644 --- a/pkg/sql/opt/xform/testdata/external/pgjdbc +++ b/pkg/sql/opt/xform/testdata/external/pgjdbc @@ -37,19 +37,19 @@ project ├── columns: type_cat:71 type_schem:35!null type_name:3!null class_name:71 data_type:72 remarks:122 base_type:123 ├── fd: ()-->(71) ├── ensure-distinct-on - │ ├── columns: t.oid:2!null t.typname:3!null t.typtype:8 nspname:35!null case:70 description:79 rownum:124!null + │ ├── columns: t.typname:3!null t.typtype:8 nspname:35!null case:70 description:79 rownum:124!null │ ├── grouping columns: rownum:124!null │ ├── error: "more than one row returned by a subquery used as an expression" │ ├── key: (124) - │ ├── fd: (124)-->(2,3,8,35,70,79) + │ ├── fd: (124)-->(3,8,35,70,79) │ ├── left-join (hash) - │ │ ├── columns: t.oid:2!null t.typname:3!null t.typtype:8 t.typbasetype:26 nspname:35!null pg_catalog.pg_type.oid:39 case:70 description:79 rownum:124!null - │ │ ├── fd: (124)-->(2,3,8,26,35,79) + │ │ ├── columns: t.typname:3!null t.typtype:8 t.typbasetype:26 nspname:35!null pg_catalog.pg_type.oid:39 case:70 description:79 rownum:124!null + │ │ ├── fd: (124)-->(3,8,26,35,79) │ │ ├── distinct-on - │ │ │ ├── columns: t.oid:2!null t.typname:3!null t.typtype:8 t.typbasetype:26 nspname:35!null description:79 rownum:124!null + │ │ │ ├── columns: t.typname:3!null t.typtype:8 t.typbasetype:26 nspname:35!null description:79 rownum:124!null │ │ │ ├── grouping columns: rownum:124!null │ │ │ ├── key: (124) - │ │ │ ├── fd: (124)-->(2,3,8,26,35,79) + │ │ │ ├── fd: (124)-->(3,8,26,35,79) │ │ │ ├── left-join (hash) │ │ │ │ ├── columns: t.oid:2!null t.typname:3!null t.typnamespace:4!null t.typtype:8 t.typbasetype:26 n.oid:34!null nspname:35!null objoid:76 classoid:77 objsubid:78 description:79 c.oid:81 relname:82 relnamespace:83 n.oid:118 nspname:119 rownum:124!null │ │ │ │ ├── fd: (4)==(34), (34)==(4), (124)-->(2-4,8,26,34,35), (77)==(81), (81)==(77), (83)==(118), (118)==(83) @@ -98,8 +98,6 @@ project │ │ │ │ └── filters │ │ │ │ └── objoid:76 = t.oid:2 [outer=(2,76), constraints=(/2: (/NULL - ]; /76: (/NULL - ]), fd=(2)==(76), (76)==(2)] │ │ │ └── aggregations - │ │ │ ├── const-agg [as=t.oid:2, outer=(2)] - │ │ │ │ └── t.oid:2 │ │ │ ├── const-agg [as=t.typname:3, outer=(3)] │ │ │ │ └── t.typname:3 │ │ │ ├── const-agg [as=t.typtype:8, outer=(8)] @@ -119,8 +117,6 @@ project │ │ └── filters │ │ └── pg_catalog.pg_type.oid:39 = t.typbasetype:26 [outer=(26,39), constraints=(/26: (/NULL - ]; /39: (/NULL - ]), fd=(26)==(39), (39)==(26)] │ └── aggregations - │ ├── const-agg [as=t.oid:2, outer=(2)] - │ │ └── t.oid:2 │ ├── const-agg [as=t.typname:3, outer=(3)] │ │ └── t.typname:3 │ ├── const-agg [as=t.typtype:8, outer=(8)] @@ -134,7 +130,7 @@ project └── projections ├── NULL [as=type_cat:71] ├── CASE WHEN t.typtype:8 = 'c' THEN 'STRUCT' ELSE 'DISTINCT' END [as=data_type:72, outer=(8)] - ├── CASE WHEN t.oid:2 IS NULL THEN CAST(NULL AS STRING) ELSE description:79 END [as=remarks:122, outer=(2,79)] + ├── description:79 [as=remarks:122, outer=(79)] └── CASE WHEN t.typtype:8 = 'd' THEN case:70 ELSE CAST(NULL AS STRING) END [as=base_type:123, outer=(8,70)] diff --git a/pkg/sql/sem/builtins/builtins_test.go b/pkg/sql/sem/builtins/builtins_test.go index 59af222206b8..b8d2d1155dbb 100644 --- a/pkg/sql/sem/builtins/builtins_test.go +++ b/pkg/sql/sem/builtins/builtins_test.go @@ -680,3 +680,83 @@ func TestTruncateTimestamp(t *testing.T) { }) } } + +func TestPGBuiltinsCalledOnNull(t *testing.T) { + defer leaktest.AfterTest(t)() + ctx := context.Background() + + params := base.TestServerArgs{} + s, db, _ := serverutils.StartServer(t, params) + defer s.Stopper().Stop(ctx) + + tdb := sqlutils.MakeSQLRunner(db) + + testCases := []struct { + sql string + }{ + { // Case 1 + sql: "SELECT pg_get_functiondef(NULL);", + }, + { // Case 2 + sql: "SELECT pg_get_function_arguments(NULL);", + }, + { // Case 3 + sql: "SELECT pg_get_function_result(NULL);", + }, + { // Case 4 + sql: "SELECT pg_get_function_identity_arguments(NULL);", + }, + { // Case 5 + sql: "SELECT pg_get_indexdef(NULL);", + }, + { // Case 6 + sql: "SELECT pg_get_userbyid(NULL);", + }, + { // Case 7 + sql: "SELECT pg_sequence_parameters(NULL);", + }, + { // Case 8 + sql: "SELECT col_description(NULL, NULL);", + }, + { // Case 9 + sql: "SELECT col_description(NULL, 0);", + }, + { // Case 10 + sql: "SELECT col_description(0, NULL);", + }, + { // Case 11 + sql: "SELECT obj_description(NULL);", + }, + { // Case 12 + sql: "SELECT obj_description(NULL, NULL);", + }, + { // Case 13 + sql: "SELECT obj_description(NULL, 'foo');", + }, + { // Case 14 + sql: "SELECT obj_description(0, NULL);", + }, + { // Case 15 + sql: "SELECT shobj_description(NULL, NULL);", + }, + { // Case 16 + sql: "SELECT shobj_description(NULL, 'foo');", + }, + { // Case 17 + sql: "SELECT shobj_description(0, NULL);", + }, + { // Case 18 + sql: "SELECT pg_function_is_visible(NULL);", + }, + { // Case 19 + sql: "SELECT pg_table_is_visible(NULL);", + }, + { // Case 20 + sql: "SELECT pg_type_is_visible(NULL);", + }, + } + for i, tc := range testCases { + res := tdb.QueryStr(t, tc.sql) + require.Equalf(t, [][]string{{"NULL"}}, res, "failed test case %d", i+1) + } +} diff --git a/pkg/sql/sem/builtins/pg_builtins.go b/pkg/sql/sem/builtins/pg_builtins.go index 4a10ed242d43..b01c09522535 100644 --- a/pkg/sql/sem/builtins/pg_builtins.go +++ b/pkg/sql/sem/builtins/pg_builtins.go @@ -608,7 +608,8 @@ var pgBuiltins = map[string]builtinDefinition{ LIMIT 1`, oidext.CockroachPredefinedOIDMax), Info: "For user-defined functions, returns the definition of the specified function. " + "For builtin functions, returns the name of the function.", - Volatility: volatility.Stable, + Volatility: volatility.Stable, + CalledOnNullInput: true, }, ), @@ -621,7 +622,8 @@ var pgBuiltins = map[string]builtinDefinition{ Body: getFunctionArgStringQuery, Info: "Returns the argument list (with defaults) necessary to identify a function, " + "in the form it would need to appear in within CREATE FUNCTION.", - Volatility: volatility.Stable, + Volatility: volatility.Stable, + CalledOnNullInput: true, }, ), @@ -640,8 +642,9 @@ var pgBuiltins = map[string]builtinDefinition{ JOIN pg_catalog.pg_type t ON prorettype=t.oid WHERE p.oid=$1 LIMIT 1`, - Info: "Returns the types of the result of the specified function.", - Volatility: volatility.Stable, + Info: "Returns the types of the result of the specified function.", + Volatility: volatility.Stable, + CalledOnNullInput: true, }, ), @@ -658,7 +661,8 @@ var pgBuiltins = map[string]builtinDefinition{ Body: getFunctionArgStringQuery, Info: "Returns the argument list (without defaults) necessary to identify a function, " + "in the form it would need to appear in within ALTER FUNCTION, for instance.", - Volatility: volatility.Stable, + Volatility: volatility.Stable, + CalledOnNullInput: true, }, ), @@ -667,12 +671,13 @@ var pgBuiltins = map[string]builtinDefinition{ "pg_get_indexdef": makeBuiltin( tree.FunctionProperties{Category: builtinconstants.CategorySystemInfo, DistsqlBlocklist: true}, tree.Overload{ - IsUDF: true, - Types: tree.ParamTypes{{Name: "index_oid", Typ: types.Oid}}, - ReturnType: tree.FixedReturnType(types.String), - Body: `SELECT indexdef FROM pg_catalog.pg_indexes WHERE crdb_oid = $1`, - Info: "Gets the CREATE INDEX command for index", - Volatility: volatility.Stable, + IsUDF: true, + Types: tree.ParamTypes{{Name: "index_oid", Typ: types.Oid}}, + ReturnType: tree.FixedReturnType(types.String), + Body: `SELECT indexdef FROM pg_catalog.pg_indexes WHERE crdb_oid = $1`, + Info: "Gets the CREATE INDEX command for index", + Volatility: volatility.Stable, + CalledOnNullInput: true, }, tree.Overload{ IsUDF: true, @@ -846,11 +851,12 @@ var pgBuiltins = map[string]builtinDefinition{ Types: tree.ParamTypes{ {Name: "role_oid", Typ: types.Oid}, }, - ReturnType: tree.FixedReturnType(types.String), - IsUDF: true, - Body: `SELECT COALESCE((SELECT rolname FROM pg_catalog.pg_roles WHERE oid=$1 LIMIT 1), 'unknown (OID=' || $1 || ')')`, - Info: notUsableInfo, - Volatility: volatility.Stable, + ReturnType: tree.FixedReturnType(types.String), + IsUDF: true, + Body: `SELECT COALESCE((SELECT rolname FROM pg_catalog.pg_roles WHERE oid=$1 LIMIT 1), 'unknown (OID=' || $1 || ')')`, + Info: notUsableInfo, + Volatility: volatility.Stable, + CalledOnNullInput: true, }, ), @@ -870,8 +876,9 @@ var pgBuiltins = map[string]builtinDefinition{ Body: `SELECT COALESCE ((SELECT (seqstart, seqmin, seqmax, seqincrement, seqcycle, seqcache, seqtypid) FROM pg_catalog.pg_sequence WHERE seqrelid=$1 LIMIT 1), CASE WHEN crdb_internal.force_error('42P01', 'relation with OID ' || $1 || ' does not exist') > 0 THEN NULL ELSE NULL END)`, - Info: notUsableInfo, - Volatility: volatility.Stable, + Info: notUsableInfo, + Volatility: volatility.Stable, + CalledOnNullInput: true, }, ), @@ -948,7 +955,8 @@ var pgBuiltins = map[string]builtinDefinition{ catconstants.MinVirtualID), Info: "Returns the comment for a table column, which is specified by the OID of its table and its column number. " + "(obj_description cannot be used for table columns, since columns do not have OIDs of their own.)", - Volatility: volatility.Stable, + Volatility: volatility.Stable, + CalledOnNullInput: true, }, ), @@ -965,7 +973,8 @@ var pgBuiltins = map[string]builtinDefinition{ Info: "Returns the comment for a database object specified by its OID alone. " + "This is deprecated since there is no guarantee that OIDs are unique across different system catalogs; " + "therefore, the wrong comment might be returned.", - Volatility: volatility.Stable, + Volatility: volatility.Stable, + CalledOnNullInput: true, }, tree.Overload{ IsUDF: true, @@ -984,7 +993,8 @@ var pgBuiltins = map[string]builtinDefinition{ LIMIT 1`, Info: "Returns the comment for a database object specified by its OID and the name of the containing system catalog. " + "For example, obj_description(123456, 'pg_class') would retrieve the comment for the table with OID 123456.", - Volatility: volatility.Stable, + Volatility: volatility.Stable, + CalledOnNullInput: true, }, ), @@ -1017,7 +1027,8 @@ var pgBuiltins = map[string]builtinDefinition{ LIMIT 1`, Info: "Returns the comment for a shared database object specified by its OID and the name of the containing system catalog. " + "This is just like obj_description except that it is used for retrieving comments on shared objects (e.g. databases). ", - Volatility: volatility.Stable, + Volatility: volatility.Stable, + CalledOnNullInput: true, }, ), @@ -1072,8 +1083,9 @@ var pgBuiltins = map[string]builtinDefinition{ INNER LOOKUP JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid WHERE p.oid=$1 LIMIT 1`, - Info: "Returns whether the function with the given OID belongs to one of the schemas on the search path.", - Volatility: volatility.Stable, + CalledOnNullInput: true, + Info: "Returns whether the function with the given OID belongs to one of the schemas on the search path.", + Volatility: volatility.Stable, }, ), // pg_table_is_visible returns true if the input oid corresponds to a table @@ -1089,8 +1101,9 @@ var pgBuiltins = map[string]builtinDefinition{ INNER LOOKUP JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE c.oid=$1 LIMIT 1`, - Info: "Returns whether the table with the given OID belongs to one of the schemas on the search path.", - Volatility: volatility.Stable, + CalledOnNullInput: true, + Info: "Returns whether the table with the given OID belongs to one of the schemas on the search path.", + Volatility: volatility.Stable, }, ), @@ -1110,8 +1123,9 @@ var pgBuiltins = map[string]builtinDefinition{ INNER LOOKUP JOIN pg_catalog.pg_namespace n ON t.typnamespace = n.oid WHERE t.oid=$1 LIMIT 1`, - Info: "Returns whether the type with the given OID belongs to one of the schemas on the search path.", - Volatility: volatility.Stable, + CalledOnNullInput: true, + Info: "Returns whether the type with the given OID belongs to one of the schemas on the search path.", + Volatility: volatility.Stable, }, ),