Skip to content

Commit

Permalink
Browse files Browse the repository at this point in the history
115468: sql: make CALL statements explainable r=DrewKimball a=DrewKimball

This patch makes it possible to run CALL statements with EXPLAIN. Currently, most explain variants only display the name and arguments of the procedure. The `OPT` explain variants additionally show the SQL/PLpgSQL body statements of the procedure. This commit also changes the name displayed for a procedure in the output of `EXPLAIN (OPT)` from `udf` to `procedure`.

Fixes cockroachdb#114674

Release note (sql change): It is now possible to run CALL statements with EXPLAIN. The `EXPLAIN (OPT)` variant will show the body of the procedure, while other variants will only show the procedure name and arguments.

Co-authored-by: Drew Kimball <[email protected]>
  • Loading branch information
craig[bot] and DrewKimball committed Dec 9, 2023
2 parents 22d9482 + a7a8158 commit e747f6e
Show file tree
Hide file tree
Showing 20 changed files with 486 additions and 26 deletions.
1 change: 1 addition & 0 deletions docs/generated/sql/bnf/explainable_stmt.bnf
Original file line number Diff line number Diff line change
Expand Up @@ -2,3 +2,4 @@ explainable_stmt ::=
preparable_stmt
| comment_stmt
| execute_stmt
| call_stmt
1 change: 1 addition & 0 deletions docs/generated/sql/bnf/stmt_block.bnf
Original file line number Diff line number Diff line change
Expand Up @@ -671,6 +671,7 @@ explainable_stmt ::=
preparable_stmt
| comment_stmt
| execute_stmt
| call_stmt

explain_option_list ::=
( explain_option_name ) ( ( ',' explain_option_name ) )*
Expand Down
174 changes: 174 additions & 0 deletions pkg/ccl/logictestccl/testdata/logic_test/explain_call_plpgsql
Original file line number Diff line number Diff line change
@@ -0,0 +1,174 @@
# LogicTest: local

statement ok
CREATE PROCEDURE foo(x INT) LANGUAGE PLpgSQL AS $$
BEGIN
RAISE NOTICE 'foo: %', x;
END
$$

query T
EXPLAIN CALL foo(0);
----
distribution: local
vectorized: true
·
• call
procedure: foo(0)

query T
EXPLAIN (VERBOSE) CALL foo(1);
----
distribution: local
vectorized: true
·
• call
columns: ()
estimated row count: 10 (missing stats)
procedure: foo(1)

query T
EXPLAIN (OPT) CALL foo(3);
----
call
└── procedure: foo
├── args
│ └── 3
├── params: x
└── body
└── values
└── (_stmt_raise_1(x),)

query T
EXPLAIN (OPT, VERBOSE) CALL foo(3);
----
call
├── volatile
├── stats: [rows=10]
├── cost: 0.02
├── distribution: test
└── procedure: foo
├── args
│ └── 3
├── params: x:1
└── body
└── values
├── columns: "_stmt_raise_1":5
├── outer: (1)
├── cardinality: [1 - 1]
├── volatile
├── stats: [rows=1]
├── key: ()
├── fd: ()-->(5)
└── (_stmt_raise_1(x:1),)

query T
EXPLAIN (OPT, TYPES) CALL foo(3);
----
call
├── volatile
├── stats: [rows=10]
├── cost: 0.02
├── distribution: test
└── procedure: foo [type=void]
├── args
│ └── const: 3 [type=int]
├── params: x:1(int)
└── body
└── values
├── columns: "_stmt_raise_1":5(void)
├── outer: (1)
├── cardinality: [1 - 1]
├── volatile
├── stats: [rows=1]
├── key: ()
├── fd: ()-->(5)
└── tuple [type=tuple{void}]
└── udf: _stmt_raise_1 [type=void]
├── args
│ └── variable: x:1 [type=int]
├── params: x:2(int)
└── body
├── values
│ ├── columns: stmt_raise_2:3(int)
│ ├── outer: (2)
│ ├── cardinality: [1 - 1]
│ ├── volatile
│ ├── stats: [rows=1]
│ ├── key: ()
│ ├── fd: ()-->(3)
│ └── tuple [type=tuple{int}]
│ └── function: crdb_internal.plpgsql_raise [type=int]
│ ├── const: 'NOTICE' [type=string]
│ ├── concat [type=string]
│ │ ├── concat [type=string]
│ │ │ ├── const: 'foo: ' [type=string]
│ │ │ └── coalesce [type=string]
│ │ │ ├── cast: STRING [type=string]
│ │ │ │ └── variable: x:2 [type=int]
│ │ │ └── const: '<NULL>' [type=string]
│ │ └── const: '' [type=string]
│ ├── const: '' [type=string]
│ ├── const: '' [type=string]
│ └── const: '00000' [type=string]
└── values
├── columns: stmt_return_3:4(void)
├── cardinality: [1 - 1]
├── stats: [rows=1]
├── key: ()
├── fd: ()-->(4)
└── tuple [type=tuple{void}]
└── null [type=void]

query T
EXPLAIN (DISTSQL) CALL foo(3);
----
distribution: local
vectorized: true
·
• call
procedure: foo(3)
·
Diagram: https://cockroachdb.github.io/distsqlplan/decode.html#eJyMj0FL-0AQxe__TxHeqYXt3wRveyvWQyDWansQJMi6mdbFbSbubKhS8t0liUURD53DwLx5M7-ZI-TNQ-P6YVXM82UyWeTrzfqumCZX86JImvbZO_t_yzy5nEKh5oqWZk8C_YgMpUIT2JIIh146Doa8eodOFVzdtLGXSwXLgaCPiC56goZna3xijfdJepFCoaJonB_cnQK38XtWotkRdPYDli-g006dz7snabgWOouU_iLNsq5UoGpH45PCbbC0CmwH71jeDosGoSKJYzcbi7w-tSQGMvvx_FJh6_nw5CpopF8x-yOdAv2A2Un_2PqFD8PazUfTn7U1XkjhxrzSgiKFvaudRGehY2ip6_59BgAA__9oSZu_

query T
EXPLAIN ANALYZE CALL foo(3);
----
planning time: 10µs
execution time: 100µs
distribution: <hidden>
vectorized: <hidden>
maximum memory usage: <hidden>
network usage: <hidden>
regions: <hidden>
isolation level: serializable
priority: normal
quality of service: regular
·
• call
nodes: <hidden>
regions: <hidden>
actual row count: 0
procedure: foo(3)

query T
EXPLAIN ANALYZE (DISTSQL) CALL foo(3);
----
planning time: 10µs
execution time: 100µs
distribution: <hidden>
vectorized: <hidden>
maximum memory usage: <hidden>
network usage: <hidden>
regions: <hidden>
isolation level: serializable
priority: normal
quality of service: regular
·
• call
nodes: <hidden>
regions: <hidden>
actual row count: 0
procedure: foo(3)
·
Diagram: https://cockroachdb.github.io/distsqlplan/decode.html#eJyMUMtq40AQvO9XiDrtwnhXYm9zW9YXg_MgyS2IMB617SEjtTLdwg5Gn5UfyJcFSTY4IYH0YaCqu6tq-gB5irD4_2-5zNpuFYP_vWb--fcXDBqu6NLVJLD3KFAatIk9iXAaqMM4sKj2sLlBaNpOB7o08JwI9gANGgkWkb2LmXcxZvmfHAYVqQtx1KU9-U4DN5mGmmyWv74IDFZO_ZYk407bTm02bCXenRNlbzCho62o2xBscZZzMYfNe_P9qDckLTdC70J-5ZR_cJoVfWlA1Yam-wh3ydN1Yj_OTvBqFBqJikSnbjGBRXNqiSZy9RS_NFhH3j2EChb5sWafPKfCsOA2Mnzsdsu7UfbuuR1irV0UMrhwjzQnpVSHJogGD6upo77_8RYAAP__9m6rjw==
2 changes: 1 addition & 1 deletion pkg/ccl/logictestccl/tests/local/BUILD.bazel
Original file line number Diff line number Diff line change
Expand Up @@ -9,7 +9,7 @@ go_test(
"//pkg/ccl/logictestccl:testdata", # keep
],
exec_properties = {"Pool": "large"},
shard_count = 30,
shard_count = 31,
tags = [
"ccl_test",
"cpu:1",
Expand Down
7 changes: 7 additions & 0 deletions pkg/ccl/logictestccl/tests/local/generated_test.go

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

55 changes: 43 additions & 12 deletions pkg/sql/explain_bundle.go
Original file line number Diff line number Diff line change
Expand Up @@ -539,10 +539,28 @@ func (b *stmtBundleBuilder) addEnv(ctx context.Context) {
if mem.Metadata().HasUserDefinedFunctions() {
// Get all relevant user-defined functions.
blankLine()
if err := c.PrintRelevantCreateUdf(&buf, strings.ToLower(b.stmt), b.flags.RedactValues, &b.errorStrings); err != nil {
err = c.PrintRelevantCreateRoutine(
&buf, strings.ToLower(b.stmt), b.flags.RedactValues, &b.errorStrings, false, /* procedure */
)
if err != nil {
b.printError(fmt.Sprintf("-- error getting schema for udfs: %v", err), &buf)
}
}
if call, ok := mem.RootExpr().(*memo.CallExpr); ok {
// Currently, a stored procedure can only be called from a CALL statement,
// which can only be the root expression.
if proc, ok := call.Proc.(*memo.UDFCallExpr); ok {
blankLine()
err = c.PrintRelevantCreateRoutine(
&buf, strings.ToLower(proc.Def.Name), b.flags.RedactValues, &b.errorStrings, true, /* procedure */
)
if err != nil {
b.printError(fmt.Sprintf("-- error getting schema for procedure: %v", err), &buf)
}
} else {
b.printError("-- unexpected input expression for CALL statement", &buf)
}
}
for i := range tables {
blankLine()
if err := c.PrintCreateTable(&buf, &tables[i], b.flags.RedactValues); err != nil {
Expand Down Expand Up @@ -899,30 +917,43 @@ func (c *stmtEnvCollector) PrintCreateEnum(w io.Writer, redactValues bool) error
return nil
}

func (c *stmtEnvCollector) PrintRelevantCreateUdf(
w io.Writer, stmt string, redactValues bool, errorStrings *[]string,
func (c *stmtEnvCollector) PrintRelevantCreateRoutine(
w io.Writer, stmt string, redactValues bool, errorStrings *[]string, procedure bool,
) error {
// The select function_name returns a DOidWrapper,
// we need to cast it to string for queryRows function to process.
// TODO(#104976): consider getting the udf sql body statements from the memo metadata.
functionNameQuery := "SELECT function_name::STRING as function_name_str FROM [SHOW FUNCTIONS]"
udfNames, err := c.queryRows(functionNameQuery)
var routineTypeName, routineNameQuery string
if procedure {
routineTypeName = "PROCEDURE"
routineNameQuery = "SELECT procedure_name::STRING as procedure_name_str FROM [SHOW PROCEDURES]"
} else {
routineTypeName = "FUNCTION"
routineNameQuery = "SELECT function_name::STRING as function_name_str FROM [SHOW FUNCTIONS]"
}
routineNames, err := c.queryRows(routineNameQuery)
if err != nil {
return err
}
for _, name := range udfNames {
for _, name := range routineNames {
if strings.Contains(stmt, name) {
createFunctionQuery := fmt.Sprintf(
"SELECT create_statement FROM [ SHOW CREATE FUNCTION \"%s\" ]", name,
createRoutineQuery := fmt.Sprintf(
"SELECT create_statement FROM [ SHOW CREATE %s \"%s\" ]", routineTypeName, name,
)
if redactValues {
createFunctionQuery = fmt.Sprintf(
"SELECT crdb_internal.redact(crdb_internal.redactable_sql_constants(create_statement)) FROM [ SHOW CREATE FUNCTION \"%s\" ]", name,
createRoutineQuery = fmt.Sprintf(
"SELECT crdb_internal.redact(crdb_internal.redactable_sql_constants(create_statement)) FROM [ SHOW CREATE %s \"%s\" ]",
routineTypeName, name,
)
}
createStatement, err := c.query(createFunctionQuery)
createStatement, err := c.query(createRoutineQuery)
if err != nil {
errString := fmt.Sprintf("-- error getting user defined function %s: %s", name, err)
var errString string
if procedure {
errString = fmt.Sprintf("-- error getting stored procedure %s: %s", name, err)
} else {
errString = fmt.Sprintf("-- error getting user defined function %s: %s", name, err)
}
fmt.Fprint(w, errString+"\n")
*errorStrings = append(*errorStrings, errString)
continue
Expand Down
37 changes: 29 additions & 8 deletions pkg/sql/explain_bundle_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -331,19 +331,40 @@ CREATE TABLE users(id UUID DEFAULT gen_random_uuid() PRIMARY KEY, promo_id INT R
})

t.Run("udfs", func(t *testing.T) {
r.Exec(t, "CREATE FUNCTION add(a INT, b INT) RETURNS INT IMMUTABLE LEAKPROOF LANGUAGE SQL AS 'SELECT a + b';")
r.Exec(t, "CREATE FUNCTION subtract(a INT, b INT) RETURNS INT IMMUTABLE LEAKPROOF LANGUAGE SQL AS 'SELECT a - b';")
rows := r.QueryStr(t, "EXPLAIN ANALYZE (DEBUG) SELECT add(3, 4);")
r.Exec(t, "CREATE FUNCTION add_func(a INT, b INT) RETURNS INT IMMUTABLE LEAKPROOF LANGUAGE SQL AS 'SELECT a + b';")
r.Exec(t, "CREATE FUNCTION subtract_func(a INT, b INT) RETURNS INT IMMUTABLE LEAKPROOF LANGUAGE SQL AS 'SELECT a - b';")
rows := r.QueryStr(t, "EXPLAIN ANALYZE (DEBUG) SELECT add_func(3, 4);")
checkBundle(
t, fmt.Sprint(rows), "add", func(name, contents string) error {
t, fmt.Sprint(rows), "add_func", func(name, contents string) error {
if name == "schema.sql" {
reg := regexp.MustCompile("add")
reg := regexp.MustCompile("add_func")
if reg.FindString(contents) == "" {
return errors.Errorf("could not find definition for 'add' function in schema.sql")
return errors.Errorf("could not find definition for 'add_func' function in schema.sql")
}
reg = regexp.MustCompile("subtract")
reg = regexp.MustCompile("subtract_func")
if reg.FindString(contents) != "" {
return errors.Errorf("Found irrelevant user defined function 'substract' in schema.sql")
return errors.Errorf("Found irrelevant user defined function 'subtract_func' in schema.sql")
}
}
return nil
}, false /* expectErrors */, base, plans,
"distsql.html vec-v.txt vec.txt")
})

t.Run("procedures", func(t *testing.T) {
r.Exec(t, "CREATE PROCEDURE add_proc(a INT, b INT) LANGUAGE SQL AS 'SELECT a + b';")
r.Exec(t, "CREATE PROCEDURE subtract_proc(a INT, b INT) LANGUAGE SQL AS 'SELECT a - b';")
rows := r.QueryStr(t, "EXPLAIN ANALYZE (DEBUG) CALL add_proc(3, 4);")
checkBundle(
t, fmt.Sprint(rows), "add_proc", func(name, contents string) error {
if name == "schema.sql" {
reg := regexp.MustCompile("add_proc")
if reg.FindString(contents) == "" {
return errors.Errorf("could not find definition for 'add_proc' procedure in schema.sql")
}
reg = regexp.MustCompile("subtract_proc")
if reg.FindString(contents) != "" {
return errors.Errorf("Found irrelevant procedure 'subtract_proc' in schema.sql")
}
}
return nil
Expand Down
15 changes: 15 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/prepare
Original file line number Diff line number Diff line change
Expand Up @@ -1694,4 +1694,19 @@ SELECT colors FROM test_114867
----
{red}

subtest prepare_call

# CALL statements cannot be prepared.
statement ok
CREATE PROCEDURE foo(x INT) LANGUAGE SQL AS $$
SELECT 1;
SELECT 2;
$$;

statement error pgcode 42601 syntax error
PREPARE bar AS CALL foo(0);

statement error pgcode 42601 syntax error
PREPARE bar AS CALL foo($1);

subtest end
Loading

0 comments on commit e747f6e

Please sign in to comment.