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: limited applicability of jsonb_array_elements function due to lack of correlated SQs #24676

Closed
ms-mullins opened this issue Apr 11, 2018 · 9 comments · Fixed by #36613
Closed
Assignees
Labels
A-sql-pgcompat Semantic compatibility with PostgreSQL C-enhancement Solution expected to add code/behavior + preserve backward-compat (pg compat issues are exception) O-community Originated from the community

Comments

@ms-mullins
Copy link

We're attempting to use the jsonb_array_elements function with CockroachDb 2.0 and it appears to generate an error. Here’s the test case to reproduce:

 create table test(
       id SERIAL,
       data jsonb,
       primary key (id)
    );
 
insert into test(data) values('{"name": "foo", "members": [{"name": "admin", "type": "USER"}]}');

select * from jsonb_array_elements(test.data->'groupMembers');

We getting: "SQL Error [42P01]: ERROR: no data source matches prefix: test". If we’re doing something incorrect, it’s unclear what that is.

cockroach version
Build Tag: v2.0.0
Build Time: 2018/04/04 14:43:38
Distribution: CCL
Platform: darwin amd64 (x86_64-apple-darwin17.3.0)
Go Version: go1.10.1
C Compiler: 4.2.1 Compatible Apple LLVM 9.0.0 (clang-900.0.39.2)
Build SHA-1: a6b498b
Build Type: development

@justinj
Copy link
Contributor

justinj commented Apr 11, 2018

Hi @ms-mullins,

I agree that error message is not particularly helpful, but what are you trying to achieve? If you want to return every single member of a members array, the following will work in Postgres:

select jsonb_array_elements(data->'members') from test;

but not in CockroachDB, since there's an implicit correlated subquery, which we don't support today. I'm not sure if there's a way in CockroachDB's current dialect to achieve this (though we're planning to support correlated subqueries in 2.1).

Can you outline what the output you're hoping for is, and maybe we can find a way to write a query to return it?

cc @knz, I think the root problem here is that the error message doesn't illustrate the fact that the query is actually wrong, or give a hint at how to fix it.

@knz
Copy link
Contributor

knz commented Apr 11, 2018

I filed #24684 to address this (how to detect and report correlation). Justin can you bring that issue to our next roundtable?

@rnestertsov
Copy link

Usage of functions like jsonb_array_elements and others seems really limited to me right now, since CockroachDB doesn't support correlated subqueries.
Let's suppose I have following test data:

drop table if exists groups;
create table groups(
  id SERIAL,
  data jsonb,
  primary key (id)
);
 
insert into groups(data) values('{"name": "Group 1", "members": [{"name": "admin", "type": "USER"}, {"name": "user", "type": "USER"}]}');
insert into groups(data) values('{"name": "Group 2", "members": [{"name": "admin2", "type": "USER"}]}');

I want to output an expanded list of users with correspondent group name. My result set should look like:

role_name user
Group 1 {"name": "admin", "type": "USER"}
Group 1 {"name": "user", "type": "USER"}
Group 2 {"name": "admin2", "type": "USER"}

In PostgreSQL I can use following query (here I specify explicit subquery):

SELECT
  g.data->>'name' AS group_name,
  jsonb_array_elements( (SELECT gg.data->'members' FROM groups gg WHERE gg.data->>'name' = g.data->>'name') )
FROM
  groups g
;

but in CockroachDB it doesn't work.
Could you please give some advice on how such type of queries can be written in CockroachDB?

@nvanbenschoten
Copy link
Member

nvanbenschoten commented Apr 13, 2018

@rnestertsov you're correct that without correlated subqueries the query you posted won't work in Cockroach. This is unfortunate, and we're actively looking to address the issue by adding in correlated subquery support.

For now, you can try the following query, which acheives the same outcome (in a less efficient way):

SELECT DATA->'name' AS role_name,
       DATA->'members'->i AS user_name
FROM groups,
  (SELECT generate_series(0,
                            (SELECT max(json_array_length(DATA->'members')) - 1
                             FROM groups)::INT) AS i)
WHERE DATA->'members'->i IS NOT NULL;

@jordanlewis jordanlewis added C-enhancement Solution expected to add code/behavior + preserve backward-compat (pg compat issues are exception) O-community Originated from the community labels Apr 25, 2018
@knz knz changed the title BUG: jsonb_array_elements function sql: limited applicability of jsonb_array_elements function due to lack of correlated SQs Apr 28, 2018
@knz knz added the A-sql-pgcompat Semantic compatibility with PostgreSQL label Apr 28, 2018
@awoods187
Copy link
Contributor

@jordanlewis and @andy-kimball i was expecting this to work post-Apply and I just checked on master (v19.1.0-beta.20190304-458-g70e3468) and it does not:

root@localhost:26257/tpcc> create table test(                                                                                                                                                                                                                                   id SERIAL,                                                                                                                                                                                                                                                               data jsonb,                                                                                                                                                                                                                                                              primary key (id)                                                                                                                                                                                                                                                      );
CREATE TABLE

Time: 1.85184438s

root@localhost:26257/tpcc> insert into test(data) values('{"name": "foo", "members": [{"name": "admin", "type": "USER"}]}');
INSERT 1

Time: 762.728077ms

root@localhost:26257/tpcc> select * from jsonb_array_elements(test.data->'groupMembers');
pq: no data source matches prefix: test

@jordanlewis
Copy link
Member

@awoods187 yeah that one doesn't work because we still don't support the implicit lateral join thing - but the one where you reorder it to put the data source in the FROM (a valid workaround) does.

select jsonb_array_elements(data->'members') from test;

@justinj
Copy link
Contributor

justinj commented Mar 16, 2019

The original query in this issue isn't valid, even in Postgres:

postgres=# select * from jsonb_array_elements(test.data->'groupMembers');
ERROR:  missing FROM-clause entry for table "test"
LINE 1: select * from jsonb_array_elements(test.data->'groupMembers'...

Jordan's modified version is the right way to do this, and we support it.

@knz
Copy link
Contributor

knz commented Mar 16, 2019

select * from jsonb_array_elements(test.data->'groupMembers');

This does not work in pg, however this does:

select * from test, jsonb_array_elements(test.data->'groupMembers');

however, it does not in cockroachdb.

This is because crdb does not know about the following rule: in a cross-join expression a,b, if b is a SRF applicaiton, then lateral should be implicitly assumed.

@awoods187
Copy link
Contributor

Here is the related lateral join issue for tracking #24560

justinj pushed a commit to justinj/cockroach that referenced this issue Apr 8, 2019
Fixes cockroachdb#24676.
Partial fix for cockroachdb#24560.

This commit adds support for LATERAL in the FROM clause of a SELECT.
LATERAL allows a subquery or SRF to refer to columns in tables earlier
in the FROM clause. This is semantically an inner apply join.

A hiccup with this is that we build join trees in a FROM clause
right-deep, but the semantics of LATERAL force the tree to be left-deep.
Changing the default to be left-deep could cause some hand-optimized
queries to become slower, so we only change the order if there is a
LATERAL subquery. Note that SRFs are always implicitly LATERAL.

This commit does *not* add support for LATERAL as a keyword to explicit
`JOIN` expressions.

Release note (sql change): the LATERAL keyword in a FROM clause is now
supported.
justinj pushed a commit to justinj/cockroach that referenced this issue Apr 16, 2019
Fixes cockroachdb#24676.
Partial fix for cockroachdb#24560.

This commit adds support for LATERAL in the FROM clause of a SELECT.
LATERAL allows a subquery or SRF to refer to columns in tables earlier
in the FROM clause. This is semantically an inner apply join.

A hiccup with this is that we build join trees in a FROM clause
right-deep, but the semantics of LATERAL force the tree to be left-deep.
Changing the default to be left-deep could cause some hand-optimized
queries to become slower, so we only change the order if there is a
LATERAL subquery. Note that SRFs are always implicitly LATERAL.

This commit does *not* add support for LATERAL as a keyword to explicit
`JOIN` expressions.

Release note (sql change): the LATERAL keyword in a FROM clause is now
supported.
craig bot pushed a commit that referenced this issue Apr 16, 2019
36613: opt: add support for LATERAL in FROM clause r=justinj a=justinj

Fixes #24676.
Partial fix for #24560.

This commit adds support for LATERAL in the FROM clause of a SELECT.
LATERAL allows a subquery or SRF to refer to columns in tables earlier
in the FROM clause. This is semantically an inner apply join.

A hiccup with this is that we build join trees in a FROM clause
right-deep, but the semantics of LATERAL force the tree to be left-deep.
Changing the default to be left-deep could cause some hand-optimized
queries to become slower, so we only change the order if there is a
LATERAL subquery. Note that SRFs are always implicitly LATERAL.

This commit does *not* add support for LATERAL as a keyword to explicit
`JOIN` expressions.

Release note (sql change): the LATERAL keyword in a FROM clause is now
supported.

Co-authored-by: Justin Jaffray <[email protected]>
@craig craig bot closed this as completed in #36613 Apr 16, 2019
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
A-sql-pgcompat Semantic compatibility with PostgreSQL C-enhancement Solution expected to add code/behavior + preserve backward-compat (pg compat issues are exception) O-community Originated from the community
Projects
None yet
Development

Successfully merging a pull request may close this issue.

8 participants