Skip to content

Commit

Permalink
sql: implement pg_is_other_temp_schema
Browse files Browse the repository at this point in the history
Needed for cockroachdb#69010.

This commit implements the `pg_is_other_temp_schema` builtin function.
`pg_is_other_temp_schema` returns true if the given OID is the OID of another
session's temporary schema. This can be useful, for example, to exclude other
sessions' temporary tables from a catalog display.

Release note (sql change): The pg_is_other_temp_schema builtin function is now
supported, which returns whether the given OID is the OID of another session's
temporary schema.

Release justification: None, waiting for v22.1.
  • Loading branch information
nvanbenschoten committed Sep 14, 2021
1 parent 3f43062 commit f9a8de9
Show file tree
Hide file tree
Showing 4 changed files with 88 additions and 0 deletions.
2 changes: 2 additions & 0 deletions docs/generated/sql/functions.md
Original file line number Diff line number Diff line change
Expand Up @@ -3138,6 +3138,8 @@ SELECT * FROM crdb_internal.check_consistency(true, ‘\x02’, ‘\x04’)</p>
</span></td></tr>
<tr><td><a name="pg_get_serial_sequence"></a><code>pg_get_serial_sequence(table_name: <a href="string.html">string</a>, column_name: <a href="string.html">string</a>) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Returns the name of the sequence used by the given column_name in the table table_name.</p>
</span></td></tr>
<tr><td><a name="pg_is_other_temp_schema"></a><code>pg_is_other_temp_schema(oid: oid) &rarr; <a href="bool.html">bool</a></code></td><td><span class="funcdesc"><p>Returns true if the given OID is the OID of another session’s temporary schema. (This can be useful, for example, to exclude other sessions’ temporary tables from a catalog display.)</p>
</span></td></tr>
<tr><td><a name="pg_my_temp_schema"></a><code>pg_my_temp_schema() &rarr; oid</code></td><td><span class="funcdesc"><p>Returns the OID of the current session’s temporary schema, or zero if it has none (because it has not created any temporary tables).</p>
</span></td></tr>
<tr><td><a name="pg_relation_is_updatable"></a><code>pg_relation_is_updatable(reloid: oid, include_triggers: <a href="bool.html">bool</a>) &rarr; int4</code></td><td><span class="funcdesc"><p>Returns the update events the relation supports.</p>
Expand Down
16 changes: 16 additions & 0 deletions pkg/bench/rttanalysis/orm_queries_bench_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -197,6 +197,22 @@ WHERE
CREATE TEMP TABLE t(a int primary key, b int)`,
Stmt: `SELECT pg_my_temp_schema() FROM generate_series(1, 10)`,
},

{
Name: "pg_is_other_temp_schema",
Setup: `SET experimental_enable_temp_tables = true;
CREATE TEMP TABLE t(a int primary key, b int)`,
Stmt: `SELECT nspname, pg_is_other_temp_schema(oid) FROM
(SELECT * FROM pg_namespace WHERE nspname = 'public') n`,
},

{
Name: "pg_is_other_temp_schema multiple times",
Setup: `SET experimental_enable_temp_tables = true;
CREATE TEMP TABLE t(a int primary key, b int)`,
Stmt: `SELECT nspname, pg_is_other_temp_schema(oid) FROM
(SELECT * FROM pg_namespace LIMIT 5) n`,
},
}

RunRoundTripBenchmark(b, tests)
Expand Down
36 changes: 36 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/pg_builtins
Original file line number Diff line number Diff line change
Expand Up @@ -379,6 +379,42 @@ true
statement ok
SET DATABASE = test;

# pg_is_other_temp_schema
#
# Returns true if the provided OID meets the following conditions:
# - is a reference to a schema
# - that is temporary
# - and is owned by a different session

query B
SELECT pg_is_other_temp_schema((SELECT oid FROM pg_type LIMIT 1))
----
false

query B
SELECT pg_is_other_temp_schema((SELECT oid FROM pg_namespace WHERE nspname = 'pg_catalog'))
----
false

query TB
SELECT user, pg_is_other_temp_schema((SELECT oid FROM pg_namespace WHERE nspname LIKE 'pg_temp_%'))
----
root false

# Switch users as a means of switching sessions. GRANT to ensure visibility.

statement ok
GRANT root TO testuser

user testuser

query TB
SELECT user, pg_is_other_temp_schema((SELECT oid FROM pg_namespace WHERE nspname LIKE 'pg_temp_%'))
----
testuser true

user root

# information_schema._pg_truetypid and information_schema._pg_truetypmod
#
# We can't exhaustively test these until we support domain types.
Expand Down
34 changes: 34 additions & 0 deletions pkg/sql/sem/builtins/pg_builtins.go
Original file line number Diff line number Diff line change
Expand Up @@ -863,6 +863,40 @@ var pgBuiltins = map[string]builtinDefinition{
},
),

// pg_is_other_temp_schema returns true if the given OID is the OID of another
// session's temporary schema.
// https://www.postgresql.org/docs/11/functions-info.html
"pg_is_other_temp_schema": makeBuiltin(defProps(),
tree.Overload{
Types: tree.ArgTypes{{"oid", types.Oid}},
ReturnType: tree.FixedReturnType(types.Bool),
Fn: func(ctx *tree.EvalContext, args tree.Datums) (tree.Datum, error) {
schemaArg := tree.UnwrapDatum(ctx, args[0])
schema, err := getNameForArg(ctx, schemaArg, "pg_namespace", "nspname")
if err != nil {
return nil, err
}
if schema == "" {
// OID does not exist.
return tree.DBoolFalse, nil
}
if !strings.HasPrefix(schema, catconstants.PgTempSchemaName) {
// OID is not a reference to a temporary schema.
//
// This string matching is what Postgres does too. See isAnyTempNamespace.
return tree.DBoolFalse, nil
}
if schema == ctx.SessionData().SearchPath.GetTemporarySchemaName() {
// OID is a reference to this session's temporary schema.
return tree.DBoolFalse, nil
}
return tree.DBoolTrue, nil
},
Info: "Returns true if the given OID is the OID of another session's temporary schema. (This can be useful, for example, to exclude other sessions' temporary tables from a catalog display.)",
Volatility: tree.VolatilityStable,
},
),

// TODO(bram): Make sure the reported type is correct for tuples. See #25523.
"pg_typeof": makeBuiltin(tree.FunctionProperties{NullableArgs: true},
tree.Overload{
Expand Down

0 comments on commit f9a8de9

Please sign in to comment.