Skip to content

Commit

Permalink
sql: populate information_schema.parameters
Browse files Browse the repository at this point in the history
Release note (sql change): The information_schema.parameters table is
now populated with information about function parameters.
  • Loading branch information
rafiss committed Jul 20, 2023
1 parent da50804 commit 6e1de01
Show file tree
Hide file tree
Showing 7 changed files with 110 additions and 58 deletions.
4 changes: 2 additions & 2 deletions pkg/cli/clisqlshell/testdata/describe
Original file line number Diff line number Diff line change
Expand Up @@ -585,13 +585,13 @@ 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)
pg_catalog,pg_language,table,admin,NULL,permanent,prefix,"available languages
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)
pg_catalog,pg_matviews,table,admin,NULL,permanent,prefix,"available materialized views
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"
Expand Down
46 changes: 37 additions & 9 deletions pkg/sql/information_schema.go
Original file line number Diff line number Diff line change
Expand Up @@ -857,14 +857,44 @@ https://www.postgresql.org/docs/9.5/infoschema-key-column-usage.html`,

// Postgres: https://www.postgresql.org/docs/9.6/static/infoschema-parameters.html
// MySQL: https://dev.mysql.com/doc/refman/5.7/en/parameters-table.html
var informationSchemaParametersTable = virtualSchemaTable{
comment: `built-in function parameters (empty - introspection not yet supported)
var informationSchemaParametersTable = virtualSchemaView{
comment: `function parameters
https://www.postgresql.org/docs/9.5/infoschema-parameters.html`,
schema: vtable.InformationSchemaParameters,
populate: func(ctx context.Context, p *planner, dbContext catalog.DatabaseDescriptor, addRow func(...tree.Datum) error) error {
return nil
resultColumns: colinfo.ResultColumns{
{Name: "specific_catalog", Typ: types.String},
{Name: "specific_schema", Typ: types.String},
{Name: "specific_name", Typ: types.String},
{Name: "ordinal_position", Typ: types.Int},
{Name: "parameter_mode", Typ: types.String},
{Name: "is_result", Typ: types.String},
{Name: "as_locator", Typ: types.String},
{Name: "parameter_name", Typ: types.String},
{Name: "data_type", Typ: types.String},
{Name: "character_maximum_length", Typ: types.Int},
{Name: "character_octet_length", Typ: types.Int},
{Name: "character_set_catalog", Typ: types.String},
{Name: "character_set_schema", Typ: types.String},
{Name: "character_set_name", Typ: types.String},
{Name: "collation_catalog", Typ: types.String},
{Name: "collation_schema", Typ: types.String},
{Name: "collation_name", Typ: types.String},
{Name: "numeric_precision", Typ: types.Int},
{Name: "numeric_precision_radix", Typ: types.Int},
{Name: "numeric_scale", Typ: types.Int},
{Name: "datetime_precision", Typ: types.Int},
{Name: "interval_type", Typ: types.String},
{Name: "interval_precision", Typ: types.Int},
{Name: "udt_catalog", Typ: types.String},
{Name: "udt_schema", Typ: types.String},
{Name: "udt_name", Typ: types.String},
{Name: "scope_catalog", Typ: types.String},
{Name: "scope_schema", Typ: types.String},
{Name: "scope_name", Typ: types.String},
{Name: "maximum_cardinality", Typ: types.Int},
{Name: "dtd_identifier", Typ: types.String},
{Name: "parameter_default", Typ: types.String},
},
unimplemented: true,
}

var (
Expand Down Expand Up @@ -966,10 +996,8 @@ https://www.postgresql.org/docs/9.5/infoschema-role-table-grants.html`,

// MySQL: https://dev.mysql.com/doc/mysql-infoschema-excerpt/5.7/en/routines-table.html
var informationSchemaRoutineTable = virtualSchemaView{
comment: "The view routines contains all functions and procedures in the " +
"current database. Only those functions and procedures are shown that the " +
"current user has access to (by way of being the owner or having some " +
"privilege).\nhttps://www.postgresql.org/docs/15/infoschema-routines.html",
comment: `built-in functions and user-defined functions
https://www.postgresql.org/docs/15/infoschema-routines.html`,
schema: vtable.InformationSchemaRoutines,
resultColumns: colinfo.ResultColumns{
{Name: "specific_catalog", Typ: types.String},
Expand Down
2 changes: 1 addition & 1 deletion pkg/sql/logictest/testdata/logic_test/crdb_internal
Original file line number Diff line number Diff line change
Expand Up @@ -202,7 +202,7 @@ pg_index false
pg_indexes false
pg_inherits true
pg_init_privs true
pg_language true
pg_language false
pg_largeobject true
pg_largeobject_metadata true
pg_locks true
Expand Down
12 changes: 6 additions & 6 deletions pkg/sql/logictest/testdata/logic_test/crdb_internal_catalog

Large diffs are not rendered by default.

8 changes: 5 additions & 3 deletions pkg/sql/logictest/testdata/logic_test/information_schema
Original file line number Diff line number Diff line change
Expand Up @@ -55,7 +55,7 @@ information_schema information_schema_catalog_name table admin NULL N
information_schema key_column_usage table admin NULL NULL
information_schema keywords table admin NULL NULL
information_schema optimizer_trace table admin NULL NULL
information_schema parameters table admin NULL NULL
information_schema parameters view admin NULL NULL
information_schema partitions table admin NULL NULL
information_schema plugins table admin NULL NULL
information_schema processlist table admin NULL NULL
Expand Down Expand Up @@ -270,7 +270,7 @@ information_schema information_schema_catalog_name table admin NULL N
information_schema key_column_usage table admin NULL NULL
information_schema keywords table admin NULL NULL
information_schema optimizer_trace table admin NULL NULL
information_schema parameters table admin NULL NULL
information_schema parameters view admin NULL NULL
information_schema partitions table admin NULL NULL
information_schema plugins table admin NULL NULL
information_schema processlist table admin NULL NULL
Expand Down Expand Up @@ -4811,9 +4811,11 @@ dtd_identifier STRING true NULL ·
parameter_default STRING true NULL · {} false

query TTTITTTTTIITTTTTTIIIITITTTTTTITT colnames
SELECT * FROM information_schema.parameters
SELECT * FROM information_schema.parameters WHERE specific_name LIKE 'get_byte%' ORDER BY specific_name, ordinal_position
----
specific_catalog specific_schema specific_name ordinal_position parameter_mode is_result as_locator parameter_name data_type character_maximum_length character_octet_length character_set_catalog character_set_schema character_set_name collation_catalog collation_schema collation_name numeric_precision numeric_precision_radix numeric_scale datetime_precision interval_type interval_precision udt_catalog udt_schema udt_name scope_catalog scope_schema scope_name maximum_cardinality dtd_identifier parameter_default
test pg_catalog get_byte_854 1 IN NO NO NULL bytea NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL test pg_catalog bytea NULL NULL NULL NULL 1 NULL
test pg_catalog get_byte_854 2 IN NO NO NULL bigint NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL test pg_catalog int8 NULL NULL NULL NULL 2 NULL

query TTTTTTTT colnames,rowsort
SELECT * FROM system.information_schema.column_privileges WHERE table_name = 'eventlog'
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -8,9 +8,6 @@
"DatatypeMismatches": 0
},
"diffs": {
"routines": {
"scope_schema": null
},
"schemata": {
"default_character_set_catalog": null,
"default_character_set_schema": null,
Expand Down
93 changes: 59 additions & 34 deletions pkg/sql/vtable/information_schema.go
Original file line number Diff line number Diff line change
Expand Up @@ -235,40 +235,65 @@ CREATE TABLE information_schema.key_column_usage (

// InformationSchemaParameters describes the schema of the
// information_schema.parameters table.
const InformationSchemaParameters = `CREATE TABLE information_schema.parameters (
SPECIFIC_CATALOG STRING,
SPECIFIC_SCHEMA STRING,
SPECIFIC_NAME STRING,
ORDINAL_POSITION INT,
PARAMETER_MODE STRING,
IS_RESULT STRING,
AS_LOCATOR STRING,
PARAMETER_NAME STRING,
DATA_TYPE STRING,
CHARACTER_MAXIMUM_LENGTH INT,
CHARACTER_OCTET_LENGTH INT,
CHARACTER_SET_CATALOG STRING,
CHARACTER_SET_SCHEMA STRING,
CHARACTER_SET_NAME STRING,
COLLATION_CATALOG STRING,
COLLATION_SCHEMA STRING,
COLLATION_NAME STRING,
NUMERIC_PRECISION INT,
NUMERIC_PRECISION_RADIX INT,
NUMERIC_SCALE INT,
DATETIME_PRECISION INT,
INTERVAL_TYPE STRING,
INTERVAL_PRECISION INT,
UDT_CATALOG STRING,
UDT_SCHEMA STRING,
UDT_NAME STRING,
SCOPE_CATALOG STRING,
SCOPE_SCHEMA STRING,
SCOPE_NAME STRING,
MAXIMUM_CARDINALITY INT,
DTD_IDENTIFIER STRING,
PARAMETER_DEFAULT STRING
)`
const InformationSchemaParameters = `
CREATE VIEW information_schema.parameters AS
SELECT CAST(current_database() AS TEXT) AS specific_catalog,
CAST(n_nspname AS TEXT) AS specific_schema,
CAST(nameconcatoid(proname, p_oid) AS TEXT) AS specific_name,
CAST((ss.x).n AS INT) AS ordinal_position,
CAST(
CASE WHEN proargmodes IS NULL THEN 'IN'
WHEN proargmodes[(ss.x).n] = 'i' THEN 'IN'
WHEN proargmodes[(ss.x).n] = 'o' THEN 'OUT'
WHEN proargmodes[(ss.x).n] = 'b' THEN 'INOUT'
WHEN proargmodes[(ss.x).n] = 'v' THEN 'IN'
WHEN proargmodes[(ss.x).n] = 't' THEN 'OUT'
END AS TEXT) AS parameter_mode,
CAST('NO' AS TEXT) AS is_result,
CAST('NO' AS TEXT) AS as_locator,
CAST(NULLIF(proargnames[(ss.x).n], '') AS TEXT) AS parameter_name,
CAST(
CASE WHEN t.typelem <> 0 AND t.typlen = -1 THEN 'ARRAY'
WHEN nt.nspname = 'pg_catalog' THEN format_type(t.oid, null)
ELSE 'USER-DEFINED' END AS TEXT)
AS data_type,
CAST(null AS INT) AS character_maximum_length,
CAST(null AS INT) AS character_octet_length,
CAST(null AS TEXT) AS character_set_catalog,
CAST(null AS TEXT) AS character_set_schema,
CAST(null AS TEXT) AS character_set_name,
CAST(null AS TEXT) AS collation_catalog,
CAST(null AS TEXT) AS collation_schema,
CAST(null AS TEXT) AS collation_name,
CAST(null AS INT) AS numeric_precision,
CAST(null AS INT) AS numeric_precision_radix,
CAST(null AS INT) AS numeric_scale,
CAST(null AS INT) AS datetime_precision,
CAST(null AS TEXT) AS interval_type,
CAST(null AS INT) AS interval_precision,
CAST(current_database() AS TEXT) AS udt_catalog,
CAST(nt.nspname AS TEXT) AS udt_schema,
CAST(t.typname AS TEXT) AS udt_name,
CAST(null AS TEXT) AS scope_catalog,
CAST(null AS TEXT) AS scope_schema,
CAST(null AS TEXT) AS scope_name,
CAST(null AS INT) AS maximum_cardinality,
CAST((ss.x).n AS TEXT) AS dtd_identifier,
CAST(
CASE WHEN pg_has_role(proowner, 'USAGE')
THEN pg_get_function_arg_default(p_oid, (ss.x).n)
ELSE NULL END
AS TEXT) AS parameter_default
FROM pg_type t, pg_namespace nt,
(SELECT n.nspname AS n_nspname, p.proname, p.oid AS p_oid, p.proowner,
p.proargnames, p.proargmodes,
information_schema._pg_expandarray(coalesce(p.proallargtypes, p.proargtypes::oid[])) AS x
FROM pg_namespace n, pg_proc p
WHERE n.oid = p.pronamespace
AND (pg_has_role(p.proowner, 'USAGE') OR
has_function_privilege(p.oid, 'EXECUTE'))) AS ss
WHERE t.oid = (ss.x).x AND t.typnamespace = nt.oid;`

// InformationSchemaReferentialConstraints describes the schema of the
// information_schema.referential_constraints table.
Expand Down

0 comments on commit 6e1de01

Please sign in to comment.