From 484b671f92f232fe1d17682d036a73888eb0f2c2 Mon Sep 17 00:00:00 2001 From: Nathan VanBenschoten Date: Wed, 8 Sep 2021 01:44:54 -0400 Subject: [PATCH 1/2] sql: implement information_schema._pg_truetypid and information_schema._pg_truetypmod Needed for #69010. This commit adds implementations for the `information_schema._pg_truetypid` and `information_schema._pg_truetypmod` builtin functions. These functions return the "true" type ID and modifier, disregarding indirection introduced by domain types. The builtins are implemented as user-defined functions in Postgres here: https://github.com/postgres/postgres/blob/master/src/backend/catalog/information_schema.sql Release justification: None, waiting for v22.1. Release note (sql change): The `information_schema._pg_truetypid` and `information_schema._pg_truetypmod` builtin functions are now supported, which improve compatibility with PostgreSQL. --- .../logictest/testdata/logic_test/pg_builtins | 33 +++++++++ pkg/sql/sem/builtins/pg_builtins.go | 71 +++++++++++++++++++ 2 files changed, 104 insertions(+) diff --git a/pkg/sql/logictest/testdata/logic_test/pg_builtins b/pkg/sql/logictest/testdata/logic_test/pg_builtins index 4412bd792978..eb158196a48d 100644 --- a/pkg/sql/logictest/testdata/logic_test/pg_builtins +++ b/pkg/sql/logictest/testdata/logic_test/pg_builtins @@ -340,3 +340,36 @@ SELECT pg_catalog.set_config('woo', 'woo', false) query error configuration setting.*not supported SELECT set_config('vacuum_cost_delay', '0', false) + +# information_schema._pg_truetypid and information_schema._pg_truetypmod +# +# We can't exhaustively test these until we support domain types. + +statement ok +CREATE TABLE types ( + a TEXT PRIMARY KEY, + b FLOAT, + c BPCHAR, + d VARCHAR(64), + e BIT, + f VARBIT(16), + g DECIMAL(12, 2) +); + +query TOI +SELECT typname, + information_schema._pg_truetypid(a.*, t.*), + information_schema._pg_truetypmod(a.*, t.*) +FROM pg_attribute a +JOIN pg_type t +ON a.atttypid = t.oid +WHERE attrelid = 'types'::regclass +ORDER BY t.oid +---- +text 25 -1 +float8 701 -1 +bpchar 1042 5 +varchar 1043 68 +bit 1560 1 +varbit 1562 16 +numeric 1700 786438 diff --git a/pkg/sql/sem/builtins/pg_builtins.go b/pkg/sql/sem/builtins/pg_builtins.go index 8fe9403a77c2..2fd1daacc31e 100644 --- a/pkg/sql/sem/builtins/pg_builtins.go +++ b/pkg/sql/sem/builtins/pg_builtins.go @@ -1913,6 +1913,28 @@ SELECT description Info: "Return size in bytes of the column provided as an argument", Volatility: tree.VolatilityImmutable, }), + + // NOTE: these two builtins could be defined as user-defined functions, like + // they are in Postgres: + // https://github.com/postgres/postgres/blob/master/src/backend/catalog/information_schema.sql + // + // CREATE FUNCTION _pg_truetypid(pg_attribute, pg_type) RETURNS oid + // LANGUAGE sql + // IMMUTABLE + // PARALLEL SAFE + // RETURNS NULL ON NULL INPUT + // RETURN CASE WHEN $2.typtype = 'd' THEN $2.typbasetype ELSE $1.atttypid END; + // + "information_schema._pg_truetypid": pgTrueTypImpl("atttypid", "typbasetype", types.Oid), + // + // CREATE FUNCTION _pg_truetypmod(pg_attribute, pg_type) RETURNS int4 + // LANGUAGE sql + // IMMUTABLE + // PARALLEL SAFE + // RETURNS NULL ON NULL INPUT + // RETURN CASE WHEN $2.typtype = 'd' THEN $2.typtypmod ELSE $1.atttypmod END; + // + "information_schema._pg_truetypmod": pgTrueTypImpl("atttypmod", "typtypmod", types.Int4), } func getSessionVar(ctx *tree.EvalContext, settingName string, missingOk bool) (tree.Datum, error) { @@ -2031,3 +2053,52 @@ func tableHasPrivilegeSpecifier(tableArg tree.Datum) (tree.HasPrivilegeSpecifier } return specifier, nil } + +func pgTrueTypImpl(attrField, typField string, retType *types.T) builtinDefinition { + return makeBuiltin(defProps(), + tree.Overload{ + Types: tree.ArgTypes{ + {"pg_attribute", types.AnyTuple}, + {"pg_type", types.AnyTuple}, + }, + ReturnType: tree.FixedReturnType(retType), + Fn: func(ctx *tree.EvalContext, args tree.Datums) (tree.Datum, error) { + // In Postgres, this builtin is statically typed to accept a + // pg_attribute record and a pg_type record. This isn't currently + // possible in CockroachDB, so instead, we accept any tuple and then + // perform a bit of dynamic typing to pull out the desired fields from + // the records. + fieldIdx := func(t *tree.DTuple, field string) int { + for i, label := range t.ResolvedType().TupleLabels() { + if label == field { + return i + } + } + return -1 + } + + pgAttr, pgType := args[0].(*tree.DTuple), args[1].(*tree.DTuple) + pgAttrFieldIdx := fieldIdx(pgAttr, attrField) + pgTypeTypeIdx := fieldIdx(pgType, "typtype") + pgTypeFieldIdx := fieldIdx(pgType, typField) + if pgAttrFieldIdx == -1 || pgTypeTypeIdx == -1 || pgTypeFieldIdx == -1 { + return nil, pgerror.Newf(pgcode.UndefinedFunction, + "No function matches the given name and argument types.") + } + + pgAttrField := pgAttr.D[pgAttrFieldIdx] + pgTypeType := pgType.D[pgTypeTypeIdx].(*tree.DString) + pgTypeField := pgType.D[pgTypeFieldIdx] + + // If this is a domain type, return the field from pg_type, otherwise, + // return the field from pg_attribute. + if *pgTypeType == "d" { + return pgTypeField, nil + } + return pgAttrField, nil + }, + Info: notUsableInfo, + Volatility: tree.VolatilityImmutable, + }, + ) +} From 3d9b5cdacd0f4312938f466607c54ab3d53d2f7b Mon Sep 17 00:00:00 2001 From: Nathan VanBenschoten Date: Wed, 8 Sep 2021 02:02:37 -0400 Subject: [PATCH 2/2] sql: implement information_schema._pg_char_max_length Needed for #69010. This commit adds implementations for the `information_schema._pg_char_max_length` builtin function. This functions returns the maximum character length of a type with the provided ID and modifier. The builtin is implemented as a user-defined function in Postgres here: https://github.com/postgres/postgres/blob/master/src/backend/catalog/information_schema.sql Release justification: None, waiting for v22.1. Release note (sql change): The `information_schema._pg_char_max_length` builtin function is now supported, which improves compatibility with PostgreSQL. --- .../logictest/testdata/logic_test/pg_builtins | 37 +++++++++++++++ pkg/sql/sem/builtins/pg_builtins.go | 45 ++++++++++++++++++- 2 files changed, 81 insertions(+), 1 deletion(-) diff --git a/pkg/sql/logictest/testdata/logic_test/pg_builtins b/pkg/sql/logictest/testdata/logic_test/pg_builtins index eb158196a48d..9ff44ea12360 100644 --- a/pkg/sql/logictest/testdata/logic_test/pg_builtins +++ b/pkg/sql/logictest/testdata/logic_test/pg_builtins @@ -373,3 +373,40 @@ varchar 1043 68 bit 1560 1 varbit 1562 16 numeric 1700 786438 + +# information_schema._pg_char_max_length + +query TI +SELECT typname, information_schema._pg_char_max_length(a.atttypid, a.atttypmod) +FROM pg_attribute a +JOIN pg_type t +ON a.atttypid = t.oid +WHERE attrelid = 'types'::regclass +ORDER BY t.oid +---- +text NULL +float8 NULL +bpchar 1 +varchar 64 +bit 1 +varbit 16 +numeric NULL + +query TI +SELECT typname, information_schema._pg_char_max_length( + information_schema._pg_truetypid(a.*, t.*), + information_schema._pg_truetypmod(a.*, t.*) +) +FROM pg_attribute a +JOIN pg_type t +ON a.atttypid = t.oid +WHERE attrelid = 'types'::regclass +ORDER BY t.oid +---- +text NULL +float8 NULL +bpchar 1 +varchar 64 +bit 1 +varbit 16 +numeric NULL diff --git a/pkg/sql/sem/builtins/pg_builtins.go b/pkg/sql/sem/builtins/pg_builtins.go index 2fd1daacc31e..1e040b538ab6 100644 --- a/pkg/sql/sem/builtins/pg_builtins.go +++ b/pkg/sql/sem/builtins/pg_builtins.go @@ -900,7 +900,7 @@ var pgBuiltins = map[string]builtinDefinition{ return tree.DNull, nil } maybeTypmod := args[1] - oid := oid.Oid(int(oidArg.(*tree.DOid).DInt)) + oid := oid.Oid(oidArg.(*tree.DOid).DInt) typ, ok := types.OidToType[oid] if !ok { // If the type wasn't statically known, try looking it up as a user @@ -1935,6 +1935,49 @@ SELECT description // RETURN CASE WHEN $2.typtype = 'd' THEN $2.typtypmod ELSE $1.atttypmod END; // "information_schema._pg_truetypmod": pgTrueTypImpl("atttypmod", "typtypmod", types.Int4), + + // NOTE: this could be defined as a user-defined function, like + // it is in Postgres: + // https://github.com/postgres/postgres/blob/master/src/backend/catalog/information_schema.sql + // + // CREATE FUNCTION _pg_char_max_length(typid oid, typmod int4) RETURNS integer + // LANGUAGE sql + // IMMUTABLE + // PARALLEL SAFE + // RETURNS NULL ON NULL INPUT + // RETURN + // CASE WHEN $2 = -1 /* default typmod */ + // THEN null + // WHEN $1 IN (1042, 1043) /* char, varchar */ + // THEN $2 - 4 + // WHEN $1 IN (1560, 1562) /* bit, varbit */ + // THEN $2 + // ELSE null + // END; + // + "information_schema._pg_char_max_length": makeBuiltin(defProps(), + tree.Overload{ + Types: tree.ArgTypes{ + {"typid", types.Oid}, + {"typmod", types.Int4}, + }, + ReturnType: tree.FixedReturnType(types.Int), + Fn: func(ctx *tree.EvalContext, args tree.Datums) (tree.Datum, error) { + typid := oid.Oid(args[0].(*tree.DOid).DInt) + typmod := *args[1].(*tree.DInt) + if typmod == -1 { + return tree.DNull, nil + } else if typid == oid.T_bpchar || typid == oid.T_varchar { + return tree.NewDInt(typmod - 4), nil + } else if typid == oid.T_bit || typid == oid.T_varbit { + return tree.NewDInt(typmod), nil + } + return tree.DNull, nil + }, + Info: notUsableInfo, + Volatility: tree.VolatilityImmutable, + }, + ), } func getSessionVar(ctx *tree.EvalContext, settingName string, missingOk bool) (tree.Datum, error) {