Permalink
Browse files

Native GIN operator class

  • Loading branch information...
1 parent 430b8f3 commit 6d30e22acb448a05169b34a8ef5cd7fdac157925 @theirix committed Aug 27, 2012
Showing with 114 additions and 21 deletions.
  1. +7 −2 postgre-json-functions--1.0.sql
  2. +25 −19 postgre-json-functions.c
  3. +82 −0 sql/postgre-json-gin.sql
@@ -83,12 +83,17 @@ create or replace function json_gin_consistent(internal, internal, internal, int
create or replace function json_gin_compare_partial(internal, internal, internal, internal) returns internal
as 'MODULE_PATHNAME' language C immutable strict;
--- opclass
+-- GIN operator class
+
+-- Operators:
+-- text[] op text[]
+-- json_object_get_text_array(val, 'tags') @> array['foo']
+-- json_object_get_text_array(val, 'tags') @< array['all', 'your', 'base']
create operator class json_gin_ops
for type _text using gin
as
- operator 7 @> (anyarray,anyarray), -- text, text[]
+ operator 7 @> (anyarray,anyarray), -- text[], text[]
function 1 json_gin_compare(internal, internal),
function 2 json_gin_extract_value(internal, internal, internal),
function 3 json_gin_extract_query(internal, internal, internal, internal, internal, internal, internal),
@@ -243,7 +243,7 @@ Datum json_object_get_generic(text *argJson, text *argKey, int json_type, pextra
{
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("cannot parse json string \"%s\"", strJson)));
+ errmsg("cannot parse json string \"%s\", scalar parser", strJson)));
}
// TODO leak
@@ -355,7 +355,7 @@ Datum json_array_to_array_generic(text *argJson, int json_type, Oid elem_oid, pe
{
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("cannot parse json string \"%s\"", strJson)));
+ errmsg("cannot parse json string \"%s\", array parser", strJson)));
}
pfree(strJson);
@@ -584,17 +584,7 @@ json_gin_compare(PG_FUNCTION_ARGS)
text *key1 = PG_GETARG_TEXT_P(0);
text *key2 = PG_GETARG_TEXT_P(1);
- char *pstr1, *pstr2;
- int32 result;
-
- result = DatumGetInt32(DirectFunctionCall2(bttextcmp, PointerGetDatum(key1), PointerGetDatum(key2)));
-
- /* always log */
- pstr1 = text_to_cstring(key1);
- pstr2 = text_to_cstring(key2);
- elog(PGJSON_TRACE_LEVEL, "GIN compare: key=%s vs key=%s -> %d", pstr1, pstr2, result);
- pfree(pstr1);
- pfree(pstr2);
+ int32 result = DatumGetInt32(DirectFunctionCall2Coll(bttextcmp, DEFAULT_COLLATION_OID, PointerGetDatum(key1), PointerGetDatum(key2)));
PG_RETURN_INT32(result);
}
@@ -603,22 +593,38 @@ json_gin_compare(PG_FUNCTION_ARGS)
Datum
json_gin_extract_value(PG_FUNCTION_ARGS)
{
- text *itemValue = PG_GETARG_TEXT_P(0);
+ ArrayType *itemValue = PG_GETARG_ARRAYTYPE_P_COPY(0);
int32 *nkeys = (int32*)PG_GETARG_POINTER(1);
+ bool **nullFlags = (bool**)PG_GETARG_POINTER(3);
- char *pstr;
- ArrayType *keys;
+ Datum *keys;
+ int16 elmlen;
+ bool elmbyval;
+ char elmalign;
+ int nelems;
+
+ get_typlenbyvalalign(ARR_ELEMTYPE(itemValue),
+ &elmlen, &elmbyval, &elmalign);
+
+ deconstruct_array(itemValue, ARR_ELEMTYPE(itemValue),
+ elmlen, elmbyval, elmalign,
+ &keys, nullFlags, &nelems);
+
+ *nkeys = nelems;
+
+/* char *pstr;
+
keys = DatumGetArrayTypeP(json_array_to_array_generic(itemValue, cJSON_String, TEXTOID, extract_json_string));
if (keys)
*nkeys = ARR_DIMS(keys)[0];
else
- *nkeys = 0;
+ *nkeys = 0;*/
/* always log */
- pstr = text_to_cstring(itemValue);
+ /*pstr = text_to_cstring(itemValue);
elog(PGJSON_TRACE_LEVEL, "GIN extract_value: json=%s -> %d items", pstr, *nkeys);
- pfree(pstr);
+ pfree(pstr);*/
PG_RETURN_POINTER(keys);
}
@@ -0,0 +1,82 @@
+-- JSON index usage example, see
+-- http://people.planetpostgresql.org/andrew/index.php?/archives/249-Using-PLV8-to-index-JSON.html
+-- http://sjsnyder.com/using-postgresql-arrays-with-gin-indexes-for
+
+-- create table
+drop table if exists test_table;
+create table test_table(id bigserial, val text);
+
+-- insert data (1572867 rows)
+insert into test_table(val) values('{"create_date":"2009-12-01 01:23:45","tags":["foo1","bar1","baz1"]}');
+insert into test_table(val) values('{"create_date":"2009-12-02 01:23:45","tags":["foo2","bar2","baz2"]}');
+insert into test_table(val) values('{"create_date":"2009-12-03 01:23:45","tags":["foo3","bar3","baz3"]}');
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) select val from test_table;
+insert into test_table(val) values('{"create_date":"2009-12-04 01:23:45","tags":["foo4","bar4","baz4"]}');
+insert into test_table(val) values('{"create_date":"2009-12-04 01:23:45","tags":["foo4","bar4","baz4"]}');
+insert into test_table(val) values('{"create_date":"2009-12-04 01:23:45","tags":["foo4","bar4","baz4"]}');
+
+-- JSON object fields query
+
+-- slow query
+select * from test_table where json_object_get_timestamp(val, 'create_date') between '2009-12-04 01:00:00' and '2009-12-04 02:00:00';
+-- Seq Scan on test_table (cost=0.00..830998.51 rows=7864 width=76) (actual time=21904.068..21904.124 rows=3 loops=1)
+-- Filter: ((json_object_get_timestamp(val, 'create_date'::text) >= '2009-12-04 01:00:00'::timestamp without time zone) AND (json_object_get_timestamp(val, 'create_date'::text) <= '2009-12-04 02:00:00'::timestamp without time zone))
+-- Total runtime: 21904.157 ms
+
+-- create btree index
+drop index if exists test_date_idx;
+create index test_date_idx on test_table using btree (json_object_get_timestamp(val, 'create_date'));
+
+-- fast query
+select * from test_table where json_object_get_timestamp(val, 'create_date') between '2009-12-04 01:00:00' and '2009-12-04 02:00:00';
+-- Bitmap Heap Scan on test_table (cost=169.53..19545.85 rows=7864 width=76) (actual time=0.023..0.026 rows=3 loops=1)
+-- Recheck Cond: ((json_object_get_timestamp(val, 'create_date'::text) >= '2009-12-04 01:00:00'::timestamp without time zone) AND (json_object_get_timestamp(val, 'create_date'::text) <= '2009-12-04 02:00:00'::timestamp without time zone))
+-- -> Bitmap Index Scan on test_date_idx (cost=0.00..167.56 rows=7864 width=0) (actual time=0.015..0.015 rows=3 loops=1)
+-- Index Cond: ((json_object_get_timestamp(val, 'create_date'::text) >= '2009-12-04 01:00:00'::timestamp without time zone) AND (json_object_get_timestamp(val, 'create_date'::text) <= '2009-12-04 02:00:00'::timestamp without time zone))
+-- Total runtime: 0.057 ms
+
+-- JSON array inclusion query
+
+-- slow query
+explain analyze select * from test_table where json_object_get_text_array(val, 'tags') @> array['bar4'];
+-- Seq Scan on test_table (cost=0.00..827066.34 rows=1573 width=76) (actual time=41336.691..41336.749 rows=3 loops=1)
+-- Filter: (json_array_to_text_array(json_object_get_text(val, 'tags'::text)) @> '{bar4}'::text[])
+-- Total runtime: 41336.799 ms
+
+-- create gin index, Mk I
+-- http://www.postgresql.org/docs/9.0/static/gin.html
+drop index if exists test_tags_idx;
+create index test_tags_idx on test_table using gin (json_object_get_text_array(val, 'tags'));
+
+-- fast query
+explain analyze select * from test_table where json_object_get_text_array(val, 'tags') @> array['bar4'];
+-- Bitmap Heap Scan on test_table (cost=29.08..5679.25 rows=1573 width=76) (actual time=0.050..0.055 rows=3 loops=1)
+-- Recheck Cond: (json_array_to_text_array(json_object_get_text(val, 'tags'::text)) @> '{bar4}'::text[])
+-- -> Bitmap Index Scan on test_tags_idx (cost=0.00..28.69 rows=1573 width=0) (actual time=0.037..0.037 rows=3 loops=1)
+-- Index Cond: (json_array_to_text_array(json_object_get_text(val, 'tags'::text)) @> '{bar4}'::text[])
+-- Total runtime: 0.129 ms
+
+-- create gin index, Mk II
+drop index if exists test_tags_idx;
+create index test_tags_idx on test_table using gin (json_object_get_text_array(val, 'tags') json_gin_ops);
+
+-- fast query
+explain analyze select * from test_table where json_object_get_text_array(val, 'tags') @> array['bar4'];

0 comments on commit 6d30e22

Please sign in to comment.