Skip to content

Commit

Permalink
feat(vet): Add default query parameters for explain queries (#2543)
Browse files Browse the repository at this point in the history
* feat(vet): add default query parameters for vet explain with MySQL
* feat(vet): Add default parameter values for PostgreSQL

Before this change, all parameters to a query would be set to NULL when explaining the query. For both PostgreSQL and MySQL, this caused the explain output to either error or return unhelpful results.

For MySQL, these NULL parameters would cause "Impossible WHERE clause" errors. For PostgreSQL, the EXPLAIN output would return plans without indexes.

The default parameters aren't complete and won't cover all cases. We're working on a fallback mechanism that would allow you to specify the explain parameters values directly. Stay tuned!

---------

Co-authored-by: Andrew Benton <[email protected]>
  • Loading branch information
kyleconroy and andrewmbenton authored Jul 31, 2023
1 parent 3b48228 commit a58e3a5
Show file tree
Hide file tree
Showing 8 changed files with 1,093 additions and 4 deletions.
6 changes: 4 additions & 2 deletions docs/howto/vet.md
Original file line number Diff line number Diff line change
Expand Up @@ -89,6 +89,8 @@ rules:
### Rules using `EXPLAIN ...` output

*Added in v1.20.0*

The CEL expression environment has two variables containing `EXPLAIN ...` output,
`postgresql.explain` and `mysql.explain`. `sqlc` only populates the variable associated with
your configured database engine, and only when you have a
Expand All @@ -100,15 +102,15 @@ For the `postgresql` engine, `sqlc` runs
EXPLAIN (ANALYZE false, VERBOSE, COSTS, SETTINGS, BUFFERS, FORMAT JSON) ...
```

where `"..."` is your query string, and parses the output into a `PostgreSQLExplain` proto message.
where `"..."` is your query string, and parses the output into a [`PostgreSQLExplain`](https://buf.build/sqlc/sqlc/docs/v1.20.0:vet#vet.PostgreSQLExplain) proto message.

For the `mysql` engine, `sqlc` runs

```sql
EXPLAIN FORMAT=JSON ...
```

where `"..."` is your query string, and parses the output into a `MySQLExplain` proto message.
where `"..."` is your query string, and parses the output into a [`MySQLExplain`](https://buf.build/sqlc/sqlc/docs/v1.20.0:vet#vet.MySQLExplain) proto message.

These proto message definitions are too long to include here, but you can find them in the `protos`
directory within the `sqlc` source tree.
Expand Down
136 changes: 134 additions & 2 deletions internal/cmd/vet.go
Original file line number Diff line number Diff line change
Expand Up @@ -170,16 +170,145 @@ func (p *pgxConn) Prepare(ctx context.Context, name, query string) error {
return err
}

// Return a default value for a PostgreSQL column based on its type. Returns nil
// if the type is unknown.
func pgDefaultValue(col *plugin.Column) any {
if col == nil {
return nil
}
if col.Type == nil {
return nil
}
typname := strings.TrimPrefix(col.Type.Name, "pg_catalog.")
switch typname {
case "any", "void":
if col.IsArray {
return []any{}
} else {
return nil
}
case "anyarray":
return []any{}
case "bool", "boolean":
if col.IsArray {
return []bool{}
} else {
return false
}
case "double", "double precision", "real":
if col.IsArray {
return []float32{}
} else {
return 0.1
}
case "json", "jsonb":
if col.IsArray {
return []string{}
} else {
return "{}"
}
case "citext", "string", "text", "varchar":
if col.IsArray {
return []string{}
} else {
return ""
}
case "bigint", "bigserial", "integer", "int", "int2", "int4", "int8", "serial":
if col.IsArray {
return []int{}
} else {
return 1
}
case "date", "time", "timestamp", "timestamptz":
if col.IsArray {
return []time.Time{}
} else {
return time.Time{}
}
case "uuid":
if col.IsArray {
return []string{}
} else {
return "00000000-0000-0000-0000-000000000000"
}
case "numeric", "decimal":
if col.IsArray {
return []string{}
} else {
return "0.1"
}
case "inet":
if col.IsArray {
return []string{}
} else {
return "192.168.0.1/24"
}
case "cidr":
if col.IsArray {
return []string{}
} else {
return "192.168.1/24"
}
default:
return nil
}
}

// Return a default value for a MySQL column based on its type. Returns nil
// if the type is unknown.
func mysqlDefaultValue(col *plugin.Column) any {
if col == nil {
return nil
}
if col.Type == nil {
return nil
}
switch col.Type.Name {
case "any":
return nil
case "bool":
return false
case "int", "bigint", "mediumint", "smallint", "tinyint", "bit":
return 1
case "decimal": // "numeric", "dec", "fixed"
// No perfect choice here to avoid "Impossible WHERE" but I think
// 0.1 is decent. It works for all cases where `scale` > 0 which
// should be the majority. For more information refer to
// https://dev.mysql.com/doc/refman/8.1/en/fixed-point-types.html.
return 0.1
case "float", "double":
return 0.1
case "date":
return "0000-00-00"
case "datetime", "timestamp":
return "0000-00-00 00:00:00"
case "time":
return "00:00:00"
case "year":
return "0000"
case "char", "varchar", "binary", "varbinary", "tinyblob", "blob",
"mediumblob", "longblob", "tinytext", "text", "mediumtext", "longtext":
return ""
case "json":
return "{}"
default:
return nil
}
}

func (p *pgxConn) Explain(ctx context.Context, query string, args ...*plugin.Parameter) (*vetEngineOutput, error) {
eQuery := "EXPLAIN (ANALYZE false, VERBOSE, COSTS, SETTINGS, BUFFERS, FORMAT JSON) " + query
eArgs := make([]any, len(args))
for i, a := range args {
eArgs[i] = pgDefaultValue(a.Column)
}
row := p.c.QueryRow(ctx, eQuery, eArgs...)
var result []json.RawMessage
if err := row.Scan(&result); err != nil {
return nil, err
}
if debug.Debug.DumpExplain {
fmt.Println(eQuery)
fmt.Println(eQuery, "with args", eArgs)
fmt.Println(string(result[0]))
}
var explain vet.PostgreSQLExplain
Expand Down Expand Up @@ -210,13 +339,16 @@ type mysqlExplainer struct {
func (me *mysqlExplainer) Explain(ctx context.Context, query string, args ...*plugin.Parameter) (*vetEngineOutput, error) {
eQuery := "EXPLAIN FORMAT=JSON " + query
eArgs := make([]any, len(args))
for i, a := range args {
eArgs[i] = mysqlDefaultValue(a.Column)
}
row := me.QueryRowContext(ctx, eQuery, eArgs...)
var result json.RawMessage
if err := row.Scan(&result); err != nil {
return nil, err
}
if debug.Debug.DumpExplain {
fmt.Println(eQuery)
fmt.Println(eQuery, "with args", eArgs)
fmt.Println(string(result))
}
var explain vet.MySQLExplain
Expand Down
31 changes: 31 additions & 0 deletions internal/endtoend/testdata/vet_explain/mysql/db/db.go

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

137 changes: 137 additions & 0 deletions internal/endtoend/testdata/vet_explain/mysql/db/models.go

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

Loading

0 comments on commit a58e3a5

Please sign in to comment.