Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

sql: add json{,b}_populate_record{,set} #70115

Merged
merged 1 commit into from
Sep 20, 2021
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
8 changes: 8 additions & 0 deletions docs/generated/sql/functions.md
Original file line number Diff line number Diff line change
Expand Up @@ -1121,6 +1121,10 @@ the locality flag on node startup. Returns an error if no region is set.</p>
</span></td></tr>
<tr><td><a name="json_object_keys"></a><code>json_object_keys(input: jsonb) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Returns sorted set of keys in the outermost JSON object.</p>
</span></td></tr>
<tr><td><a name="json_populate_record"></a><code>json_populate_record(base: anyelement, from_json: jsonb) &rarr; anyelement</code></td><td><span class="funcdesc"><p>Expands the object in from_json to a row whose columns match the record type defined by base.</p>
</span></td></tr>
<tr><td><a name="json_populate_recordset"></a><code>json_populate_recordset(base: anyelement, from_json: jsonb) &rarr; anyelement</code></td><td><span class="funcdesc"><p>Expands the outermost array of objects in from_json to a set of rows whose columns match the record type defined by base</p>
</span></td></tr>
<tr><td><a name="jsonb_array_elements"></a><code>jsonb_array_elements(input: jsonb) &rarr; jsonb</code></td><td><span class="funcdesc"><p>Expands a JSON array to a set of JSON values.</p>
</span></td></tr>
<tr><td><a name="jsonb_array_elements_text"></a><code>jsonb_array_elements_text(input: jsonb) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Expands a JSON array to a set of text values.</p>
Expand All @@ -1131,6 +1135,10 @@ the locality flag on node startup. Returns an error if no region is set.</p>
</span></td></tr>
<tr><td><a name="jsonb_object_keys"></a><code>jsonb_object_keys(input: jsonb) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Returns sorted set of keys in the outermost JSON object.</p>
</span></td></tr>
<tr><td><a name="jsonb_populate_record"></a><code>jsonb_populate_record(base: anyelement, from_json: jsonb) &rarr; anyelement</code></td><td><span class="funcdesc"><p>Expands the object in from_json to a row whose columns match the record type defined by base.</p>
</span></td></tr>
<tr><td><a name="jsonb_populate_recordset"></a><code>jsonb_populate_recordset(base: anyelement, from_json: jsonb) &rarr; anyelement</code></td><td><span class="funcdesc"><p>Expands the outermost array of objects in from_json to a set of rows whose columns match the record type defined by base</p>
</span></td></tr>
<tr><td><a name="pg_get_keywords"></a><code>pg_get_keywords() &rarr; tuple{string AS word, string AS catcode, string AS catdesc}</code></td><td><span class="funcdesc"><p>Produces a virtual table containing the keywords known to the SQL parser.</p>
</span></td></tr>
<tr><td><a name="regexp_split_to_table"></a><code>regexp_split_to_table(string: <a href="string.html">string</a>, pattern: <a href="string.html">string</a>) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Split string using a POSIX regular expression as the delimiter.</p>
Expand Down
79 changes: 79 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/json
Original file line number Diff line number Diff line change
Expand Up @@ -852,3 +852,82 @@ query T
SELECT '{}'::JSONB[]
----
{}

# json_populate_record
query FIII colnames
SELECT *, c FROM json_populate_record(((1.01, 2, 3) AS d, c, a), '{"a": 3, "c": 10, "d": 11.001}')
----
d c a c
11.001 10 3 10

query BTT colnames
SELECT * FROM json_populate_record(((true, ARRAY[1], ARRAY['f']) AS a, b, c), '{"a": true, "b": [1,2], "c": ["a", "b"]}')
----
a b c
true {1,2} {a,b}

query BT colnames
SELECT * FROM json_populate_record(((true, ((1, 'bar', ARRAY['a']) AS x, y, z)) AS a, b), '{"a": true, "b": {"x": "3", "y": "foo", "z": ["a", "b"]}}')
----
a b
true (3,foo,"{a,b}")

query BI colnames
SELECT * FROM json_populate_record(((true, 3) AS a, b), '{"a": null, "b": null}')
----
a b
NULL NULL

query T colnames
SELECT json_populate_record(((1.01, 2, 3) AS d, c, a), '{"a": 3, "c": 10, "d": 11.001}')
mgartner marked this conversation as resolved.
Show resolved Hide resolved
----
json_populate_record
(11.001,10,3)

query T colnames
SELECT json_populate_record(((1.01, 2) AS a, b), '{"a": "1.2345", "b": "33"}')
----
json_populate_record
(1.2345,33)

query F colnames
SELECT (json_populate_record(((1.01, 2, 3) AS d, c, a), '{"a": 3, "c": 10, "d": 11.001}')).d
----
d
11.001

query error could not parse \"foo\" as type int
SELECT json_populate_record(((3,) AS a), '{"a": "foo"}')

query error anonymous records cannot be used with json_populate_record
SELECT * FROM json_populate_record((1,2,3,4), '{"a": 3, "c": 10, "d": 11.001}')

query error anonymous records cannot be used with json_populate_record
SELECT * FROM json_populate_record(NULL, '{"a": 3, "c": 10, "d": 11.001}')

query I
SELECT * FROM json_populate_record(((3,) AS a), NULL)
----
3

query FIII colnames
SELECT *, c FROM json_populate_recordset(((1.01, 2, 3) AS d, c, a), '[{"a": 3, "c": 10, "d": 11.001}, {}]')
----
d c a c
11.001 10 3 10
1.01 2 3 2

query FITI colnames
SELECT *, c FROM json_populate_recordset(((NULL::NUMERIC, 2::INT, 3::TEXT) AS d, c, a), '[{"a": 3, "c": 10, "d": 11.001}, {}]')
----
d c a c
11.001 10 3 10
NULL 2 3 2

query FIT
SELECT * FROM json_populate_recordset(((NULL::NUMERIC, 2::INT, 3::TEXT) AS d, c, a), NULL)
----

query FIT
SELECT * FROM json_populate_recordset(((NULL::NUMERIC, 2::INT, 3::TEXT) AS d, c, a), '[]')
----
19 changes: 19 additions & 0 deletions pkg/sql/sem/builtins/all_builtins.go
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@
package builtins

import (
"fmt"
"sort"

"github.com/cockroachdb/cockroach/pkg/sql/sem/tree"
Expand Down Expand Up @@ -54,6 +55,24 @@ func init() {
} else if def.props.Class == tree.WindowClass {
AllWindowBuiltinNames = append(AllWindowBuiltinNames, name)
}
for _, overload := range def.overloads {
fnCount := 0
if overload.Fn != nil {
fnCount++
}
if overload.Generator != nil {
overload.Fn = unsuitableUseOfGeneratorFn
fnCount++
}
if overload.GeneratorWithExprs != nil {
overload.Fn = unsuitableUseOfGeneratorFn
fnCount++
}
if fnCount > 1 {
panic(fmt.Sprintf("builtin %s: at most 1 of Fn, Generator, and GeneratorWithExprs must be set on overloads; (found %d)",
name, fnCount))
}
}
}

// Generate missing categories.
Expand Down
6 changes: 2 additions & 4 deletions pkg/sql/sem/builtins/builtins.go
Original file line number Diff line number Diff line change
Expand Up @@ -3704,10 +3704,8 @@ value if you rely on the HLC for accuracy.`,
// The behavior of both the JSON and JSONB data types in CockroachDB is
// similar to the behavior of the JSONB data type in Postgres.

"json_to_recordset": makeBuiltin(tree.FunctionProperties{UnsupportedWithIssue: 33285, Category: categoryJSON}),
"jsonb_to_recordset": makeBuiltin(tree.FunctionProperties{UnsupportedWithIssue: 33285, Category: categoryJSON}),
"json_populate_recordset": makeBuiltin(tree.FunctionProperties{UnsupportedWithIssue: 33285, Category: categoryJSON}),
"jsonb_populate_recordset": makeBuiltin(tree.FunctionProperties{UnsupportedWithIssue: 33285, Category: categoryJSON}),
"json_to_recordset": makeBuiltin(tree.FunctionProperties{UnsupportedWithIssue: 33285, Category: categoryJSON}),
"jsonb_to_recordset": makeBuiltin(tree.FunctionProperties{UnsupportedWithIssue: 33285, Category: categoryJSON}),

"jsonb_path_exists": makeBuiltin(tree.FunctionProperties{UnsupportedWithIssue: 22513, Category: categoryJSON}),
"jsonb_path_exists_opr": makeBuiltin(tree.FunctionProperties{UnsupportedWithIssue: 22513, Category: categoryJSON}),
Expand Down
207 changes: 202 additions & 5 deletions pkg/sql/sem/builtins/generator_builtins.go
Original file line number Diff line number Diff line change
Expand Up @@ -303,6 +303,16 @@ var generators = map[string]builtinDefinition{
"jsonb_each": makeBuiltin(genPropsWithLabels(jsonEachGeneratorLabels), jsonEachImpl),
"json_each_text": makeBuiltin(genPropsWithLabels(jsonEachGeneratorLabels), jsonEachTextImpl),
"jsonb_each_text": makeBuiltin(genPropsWithLabels(jsonEachGeneratorLabels), jsonEachTextImpl),
"json_populate_record": makeBuiltin(jsonPopulateProps, makeJSONPopulateImpl(makeJSONPopulateRecordGenerator,
"Expands the object in from_json to a row whose columns match the record type defined by base.",
)),
"jsonb_populate_record": makeBuiltin(jsonPopulateProps, makeJSONPopulateImpl(makeJSONPopulateRecordGenerator,
"Expands the object in from_json to a row whose columns match the record type defined by base.",
)),
"json_populate_recordset": makeBuiltin(jsonPopulateProps, makeJSONPopulateImpl(makeJSONPopulateRecordSetGenerator,
"Expands the outermost array of objects in from_json to a set of rows whose columns match the record type defined by base")),
"jsonb_populate_recordset": makeBuiltin(jsonPopulateProps, makeJSONPopulateImpl(makeJSONPopulateRecordSetGenerator,
"Expands the outermost array of objects in from_json to a set of rows whose columns match the record type defined by base")),

"crdb_internal.check_consistency": makeBuiltin(
tree.FunctionProperties{
Expand Down Expand Up @@ -404,8 +414,8 @@ func makeGeneratorOverload(
return makeGeneratorOverloadWithReturnType(in, tree.FixedReturnType(ret), g, info, volatility)
}

func newUnsuitableUseOfGeneratorError() error {
return errors.AssertionFailedf("generator functions cannot be evaluated as scalars")
var unsuitableUseOfGeneratorFn = func(_ *tree.EvalContext, _ tree.Datums) (tree.Datum, error) {
return nil, errors.AssertionFailedf("generator functions cannot be evaluated as scalars")
}

func makeGeneratorOverloadWithReturnType(
Expand All @@ -419,9 +429,6 @@ func makeGeneratorOverloadWithReturnType(
Types: in,
ReturnType: retType,
Generator: g,
Fn: func(ctx *tree.EvalContext, args tree.Datums) (tree.Datum, error) {
return nil, newUnsuitableUseOfGeneratorError()
},
Info: info,
Volatility: volatility,
}
Expand Down Expand Up @@ -1231,6 +1238,196 @@ func (g *jsonEachGenerator) Values() (tree.Datums, error) {
return tree.Datums{g.key, g.value}, nil
}

var jsonPopulateProps = tree.FunctionProperties{
Class: tree.GeneratorClass,
Category: categoryGenerator,
// The typical way to call json_populate_record is to send NULL::atype as the
// first argument, so we have to accept nullable args.
NullableArgs: true,
}

func makeJSONPopulateImpl(gen tree.GeneratorWithExprsFactory, info string) tree.Overload {
return tree.Overload{
// The json{,b}_populate_record{,set} builtins all have a 2 argument
// structure. The first argument is an arbitrary tuple type, which is used
// to set the columns of the output when the builtin is used as a FROM
// source, or used as-is when it's used as an ordinary projection.
// The second argument is a JSON object or array of objects. The builtin
// transforms the JSON in the second argument into the tuple in the first
// argument, field by field, casting fields in key "k" to the type in the
// tuple slot "k". Any tuple fields that were missing in the JSON will be
// left as they are in the input argument.
// The first argument can be of the form NULL::<tupletype>, in which case
// the default values of each field will be NULL.
// The second argument can also be null, in which case the first argument
// is returned as-is.
Types: tree.ArgTypes{{"base", types.Any}, {"from_json", types.Jsonb}},
ReturnType: func(args []tree.TypedExpr) *types.T {
if len(args) != 2 {
return tree.UnknownReturnType
}
return args[0].ResolvedType()
},
GeneratorWithExprs: gen,
Info: info,
Volatility: tree.VolatilityStable,
}
}

func makeJSONPopulateRecordGenerator(
evalCtx *tree.EvalContext, args tree.Exprs,
) (tree.ValueGenerator, error) {
tuple, j, err := jsonPopulateRecordEvalArgs(evalCtx, args)
if err != nil {
return nil, err
}

if j != nil {
if j.Type() != json.ObjectJSONType {
return nil, pgerror.Newf(pgcode.InvalidParameterValue, "argument of json_populate_record must be an object")
}
} else {
j = json.NewObjectBuilder(0).Build()
}
return &jsonPopulateRecordGenerator{
evalCtx: evalCtx,
input: tuple,
target: j,
}, nil
}

// jsonPopulateRecordEvalArgs evaluates the first 2 expression arguments to
// one of the jsonPopulateRecord variants, and returns the correctly-typed
// tuple of default values, and the JSON input or nil if it was SQL NULL.
func jsonPopulateRecordEvalArgs(
evalCtx *tree.EvalContext, args tree.Exprs,
) (tuple *tree.DTuple, jsonInputOrNil json.JSON, err error) {
evalled := make(tree.Datums, len(args))
for i := range args {
var err error
evalled[i], err = args[i].(tree.TypedExpr).Eval(evalCtx)
if err != nil {
return nil, nil, err
}
}
tupleType := args[0].(tree.TypedExpr).ResolvedType()
var defaultElems tree.Datums
if evalled[0] == tree.DNull {
defaultElems = make(tree.Datums, len(tupleType.TupleLabels()))
for i := range defaultElems {
defaultElems[i] = tree.DNull
}
} else {
defaultElems = tree.MustBeDTuple(evalled[0]).D
}
jordanlewis marked this conversation as resolved.
Show resolved Hide resolved
var j json.JSON
if evalled[1] != tree.DNull {
j = tree.MustBeDJSON(evalled[1]).JSON
}
return tree.NewDTuple(tupleType, defaultElems...), j, nil
}

type jsonPopulateRecordGenerator struct {
input *tree.DTuple
target json.JSON

wasCalled bool
evalCtx *tree.EvalContext
}

// ResolvedType is part of the tree.ValueGenerator interface.
func (j jsonPopulateRecordGenerator) ResolvedType() *types.T {
jordanlewis marked this conversation as resolved.
Show resolved Hide resolved
return j.input.ResolvedType()
}

// Start is part of the tree.ValueGenerator interface.
func (j *jsonPopulateRecordGenerator) Start(_ context.Context, _ *kv.Txn) error { return nil }

// Close is part of the tree.ValueGenerator interface.
func (j *jsonPopulateRecordGenerator) Close(_ context.Context) {}

// Next is part of the tree.ValueGenerator interface.
func (j *jsonPopulateRecordGenerator) Next(_ context.Context) (bool, error) {
if !j.wasCalled {
j.wasCalled = true
return true, nil
jordanlewis marked this conversation as resolved.
Show resolved Hide resolved
}
return false, nil
}

// Values is part of the tree.ValueGenerator interface.
func (j jsonPopulateRecordGenerator) Values() (tree.Datums, error) {
if err := tree.PopulateRecordWithJSON(j.evalCtx, j.target, j.input.ResolvedType(), j.input); err != nil {
return nil, err
}
return j.input.D, nil
}

func makeJSONPopulateRecordSetGenerator(
evalCtx *tree.EvalContext, args tree.Exprs,
) (tree.ValueGenerator, error) {
tuple, j, err := jsonPopulateRecordEvalArgs(evalCtx, args)
if err != nil {
return nil, err
}

if j != nil {
if j.Type() != json.ArrayJSONType {
return nil, pgerror.Newf(pgcode.InvalidParameterValue, "argument of json_populate_recordset must be an array")
}
} else {
j = json.NewArrayBuilder(0).Build()
}

return &jsonPopulateRecordSetGenerator{
jsonPopulateRecordGenerator: jsonPopulateRecordGenerator{
evalCtx: evalCtx,
input: tuple,
target: j,
},
}, nil
}

type jsonPopulateRecordSetGenerator struct {
jsonPopulateRecordGenerator

nextIdx int
}

// ResolvedType is part of the tree.ValueGenerator interface.
func (j jsonPopulateRecordSetGenerator) ResolvedType() *types.T { return j.input.ResolvedType() }

// Start is part of the tree.ValueGenerator interface.
func (j jsonPopulateRecordSetGenerator) Start(_ context.Context, _ *kv.Txn) error { return nil }

// Close is part of the tree.ValueGenerator interface.
func (j jsonPopulateRecordSetGenerator) Close(_ context.Context) {}

// Next is part of the tree.ValueGenerator interface.
func (j *jsonPopulateRecordSetGenerator) Next(_ context.Context) (bool, error) {
if j.nextIdx >= j.target.Len() {
return false, nil
}
j.nextIdx++
return true, nil
}

// Values is part of the tree.ValueGenerator interface.
func (j *jsonPopulateRecordSetGenerator) Values() (tree.Datums, error) {
obj, err := j.target.FetchValIdx(j.nextIdx - 1)
if err != nil {
return nil, err
}
output := tree.NewDTupleWithLen(j.input.ResolvedType(), j.input.D.Len())
for i := range j.input.D {
output.D[i] = j.input.D[i]
}
if err := tree.PopulateRecordWithJSON(j.evalCtx, obj, j.input.ResolvedType(), output); err != nil {
return nil, err
}
return output.D, nil
}

type checkConsistencyGenerator struct {
db *kv.DB
from, to roachpb.Key
Expand Down
3 changes: 0 additions & 3 deletions pkg/sql/sem/builtins/geo_builtins.go
Original file line number Diff line number Diff line change
Expand Up @@ -6446,9 +6446,6 @@ The parent_only boolean is always ignored.`,
tree.Overload{
Types: tree.ArgTypes{{"geometry", types.Geometry}},
ReturnType: tree.FixedReturnType(minimumBoundingRadiusReturnType),
Fn: func(ctx *tree.EvalContext, args tree.Datums) (tree.Datum, error) {
return nil, newUnsuitableUseOfGeneratorError()
},
Generator: makeMinimumBoundGenerator,
Info: "Returns a record containing the center point and radius of the smallest circle that can fully contains the given geometry.",
Volatility: tree.VolatilityImmutable,
Expand Down
Loading