Skip to content

Commit

Permalink
Merge #69913
Browse files Browse the repository at this point in the history
69913: sql: implement information_schema.{_pg_truetypid, _pg_truetypmod, _pg_char_max_length} r=nvanbenschoten a=nvanbenschoten

Needed for #69010.

This PR adds implementations for the following three builtin functions
`information_schema._pg_truetypid`
`information_schema._pg_truetypmod`
`information_schema._pg_char_max_length`

The first two functions return the "true" type ID and modifier, disregarding indirection introduced by domain types. The third returns the maximum character length of a type with the provided ID and modifier.

The builtins are implemented as user-defined functions in Postgres here: https://github.com/postgres/postgres/blob/master/src/backend/catalog/information_schema.sql

Combined with #69909 and #69911, this PR unlocks these two gnarly introspection queries in PostgREST:
- https://github.com/PostgREST/postgrest/blob/b05898d17f8e33c8c82fc1d05a30eb3044999668/src/PostgREST/DbStructure.hs#L538
- https://github.com/PostgREST/postgrest/blob/b05898d17f8e33c8c82fc1d05a30eb3044999668/src/PostgREST/DbStructure.hs#L709

Release justification: None, waiting for v22.1.

Co-authored-by: Nathan VanBenschoten <[email protected]>
  • Loading branch information
craig[bot] and nvanbenschoten committed Sep 14, 2021
2 parents 19b1766 + 3d9b5cd commit bf75279
Show file tree
Hide file tree
Showing 2 changed files with 185 additions and 1 deletion.
70 changes: 70 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/pg_builtins
Original file line number Diff line number Diff line change
Expand Up @@ -340,3 +340,73 @@ 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

# 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
116 changes: 115 additions & 1 deletion pkg/sql/sem/builtins/pg_builtins.go
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down Expand Up @@ -1913,6 +1913,71 @@ 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),

// 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) {
Expand Down Expand Up @@ -2031,3 +2096,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,
},
)
}

0 comments on commit bf75279

Please sign in to comment.