I'm trying to create a Postgres GIN index to speed up the following query:
CREATE TABLE foo (
id serial primary key,
a jsonb not null
);
insert into foo(a) values
('[{"b": "aaa"}, {"b": "ddd"}]'::jsonb),
('[{"b": "aaa"}, {"b": "aaa"}]'::jsonb),
('[{"b": "aaa"}]'::jsonb),
('[{"b": "aaa"}]'::jsonb),
('[{"b": "aaa"}]'::jsonb),
('[{"b": "bbb"}]'::jsonb),
('[{"b": "bbb"}]'::jsonb),
('[{"b": "bbb"}]'::jsonb),
('[{"b": "ccc"}]'::jsonb),
('[]'::jsonb);
select distinct id from (
select id, jsonb_array_elements(a)->>'b' as b from foo
) t where t.b = 'aaa'
Is such a thing possible in Postgres? I am open to other alternatives as well. Unfortunately, I can't normalize the table, so I'll need to work with the table structure that I already have.
Yes, you can apply a GIN index here but it may not be particularly useful:
CREATE INDEX find_fast_jsonb_value
ON foo USING GIN (a jsonb_path_ops);
Now you still have to search through the arrays for matching key/value pairs. Your query then becomes:
SELECT DISTINCT id
FROM foo, jsonb_array_elements(a) AS t(b) -- Implicit LATERAL join
WHERE b @> '{"b": "aaa"}'; -- Comparing json key/values here
This also places the set-returning-function jsonb_array_elements()
in the FROM
clause, where it belongs.