Commit 3f44e3db authored by Peter Eisentraut's avatar Peter Eisentraut

Transforms for jsonb to PL/Python

Add a new contrib module jsonb_plpython that provide a transform between
jsonb and PL/Python.  jsonb values are converted to appropriate Python
types such as dicts and lists, and vice versa.

Author: Anthony Bykov <a.bykov@postgrespro.ru>
Reviewed-by: default avatarAleksander Alekseev <a.alekseev@postgrespro.ru>
Reviewed-by: default avatarNikita Glukhov <n.gluhov@postgrespro.ru>
parent a437551a
...@@ -81,9 +81,9 @@ ALWAYS_SUBDIRS += hstore_plperl ...@@ -81,9 +81,9 @@ ALWAYS_SUBDIRS += hstore_plperl
endif endif
ifeq ($(with_python),yes) ifeq ($(with_python),yes)
SUBDIRS += hstore_plpython ltree_plpython SUBDIRS += hstore_plpython jsonb_plpython ltree_plpython
else else
ALWAYS_SUBDIRS += hstore_plpython ltree_plpython ALWAYS_SUBDIRS += hstore_plpython jsonb_plpython ltree_plpython
endif endif
# Missing: # Missing:
......
# Generated subdirectories
/expected/python3/
/log/
/results/
/sql/python3/
/tmp_check/
# contrib/jsonb_plpython/Makefile
MODULE_big = jsonb_plpython$(python_majorversion)
OBJS = jsonb_plpython.o $(WIN32RES)
PGFILEDESC = "jsonb_plpython - transform between jsonb and plpythonu"
PG_CPPFLAGS = -I$(top_srcdir)/src/pl/plpython $(python_includespec) -DPLPYTHON_LIBNAME='"plpython$(python_majorversion)"'
EXTENSION = jsonb_plpythonu jsonb_plpython2u jsonb_plpython3u
DATA = jsonb_plpythonu--1.0.sql jsonb_plpython2u--1.0.sql jsonb_plpython3u--1.0.sql
REGRESS = jsonb_plpython
REGRESS_PLPYTHON3_MANGLE := $(REGRESS)
ifdef USE_PGXS
PG_CONFIG = pg_config
PGXS := $(shell $(PG_CONFIG) --pgxs)
include $(PGXS)
else
subdir = contrib/jsonb_plpython
top_builddir = ../..
include $(top_builddir)/src/Makefile.global
include $(top_srcdir)/contrib/contrib-global.mk
endif
# We must link libpython explicitly
ifeq ($(PORTNAME), win32)
# ... see silliness in plpython Makefile ...
SHLIB_LINK += $(sort $(wildcard ../../src/pl/plpython/libpython*.a))
else
rpathdir = $(python_libdir)
SHLIB_LINK += $(python_libspec) $(python_additional_libs)
endif
ifeq ($(python_majorversion),2)
REGRESS_OPTS += --load-extension=plpythonu --load-extension=jsonb_plpythonu
endif
include $(top_srcdir)/src/pl/plpython/regress-python3-mangle.mk
CREATE EXTENSION jsonb_plpython2u CASCADE;
NOTICE: installing required extension "plpython2u"
-- test jsonb -> python dict
CREATE FUNCTION test1(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert isinstance(val, dict)
plpy.info(sorted(val.items()))
return len(val)
$$;
SELECT test1('{"a": 1, "c": "NULL"}'::jsonb);
INFO: [('a', Decimal('1')), ('c', 'NULL')]
test1
-------
2
(1 row)
-- test jsonb -> python dict
-- complex dict with dicts as value
CREATE FUNCTION test1complex(val jsonb) RETURNS int
LANGUAGE plpython2u
TRANSFORM FOR TYPE jsonb
AS $$
assert isinstance(val, dict)
assert(val == {"d": {"d": 1}})
return len(val)
$$;
SELECT test1complex('{"d": {"d": 1}}'::jsonb);
test1complex
--------------
1
(1 row)
-- test jsonb[] -> python dict
-- dict with array as value
CREATE FUNCTION test1arr(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert isinstance(val, dict)
assert(val == {"d": [12, 1]})
return len(val)
$$;
SELECT test1arr('{"d":[12, 1]}'::jsonb);
test1arr
----------
1
(1 row)
-- test jsonb[] -> python list
-- simple list
CREATE FUNCTION test2arr(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert isinstance(val, list)
assert(val == [12, 1])
return len(val)
$$;
SELECT test2arr('[12, 1]'::jsonb);
test2arr
----------
2
(1 row)
-- test jsonb[] -> python list
-- array of dicts
CREATE FUNCTION test3arr(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert isinstance(val, list)
assert(val == [{"a": 1,"b": 2}, {"c": 3,"d": 4}])
return len(val)
$$;
SELECT test3arr('[{"a": 1, "b": 2}, {"c": 3,"d": 4}]'::jsonb);
test3arr
----------
2
(1 row)
-- test jsonb int -> python int
CREATE FUNCTION test1int(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert(val == 1)
return val
$$;
SELECT test1int('1'::jsonb);
test1int
----------
1
(1 row)
-- test jsonb string -> python string
CREATE FUNCTION test1string(val jsonb) RETURNS text
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert(val == "a")
return val
$$;
SELECT test1string('"a"'::jsonb);
test1string
-------------
a
(1 row)
-- test jsonb null -> python None
CREATE FUNCTION test1null(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert(val == None)
return 1
$$;
SELECT test1null('null'::jsonb);
test1null
-----------
1
(1 row)
-- test python -> jsonb
CREATE FUNCTION roundtrip(val jsonb) RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
as $$
return val
$$;
SELECT roundtrip('null'::jsonb);
roundtrip
-----------
(1 row)
SELECT roundtrip('1'::jsonb);
roundtrip
-----------
1
(1 row)
SELECT roundtrip('1234567890.0987654321'::jsonb);
roundtrip
-----------------------
1234567890.0987654321
(1 row)
SELECT roundtrip('-1234567890.0987654321'::jsonb);
roundtrip
------------------------
-1234567890.0987654321
(1 row)
SELECT roundtrip('true'::jsonb);
roundtrip
-----------
true
(1 row)
SELECT roundtrip('"string"'::jsonb);
roundtrip
-----------
"string"
(1 row)
SELECT roundtrip('{"1": null}'::jsonb);
roundtrip
-------------
{"1": null}
(1 row)
SELECT roundtrip('{"1": 1}'::jsonb);
roundtrip
-----------
{"1": 1}
(1 row)
SELECT roundtrip('{"1": true}'::jsonb);
roundtrip
-------------
{"1": true}
(1 row)
SELECT roundtrip('{"1": "string"}'::jsonb);
roundtrip
-----------------
{"1": "string"}
(1 row)
SELECT roundtrip('[null]'::jsonb);
roundtrip
-----------
[null]
(1 row)
SELECT roundtrip('[1]'::jsonb);
roundtrip
-----------
[1]
(1 row)
SELECT roundtrip('[true]'::jsonb);
roundtrip
-----------
[true]
(1 row)
SELECT roundtrip('["string"]'::jsonb);
roundtrip
------------
["string"]
(1 row)
SELECT roundtrip('[null, 1]'::jsonb);
roundtrip
-----------
[null, 1]
(1 row)
SELECT roundtrip('[1, true]'::jsonb);
roundtrip
-----------
[1, true]
(1 row)
SELECT roundtrip('[true, "string"]'::jsonb);
roundtrip
------------------
[true, "string"]
(1 row)
SELECT roundtrip('["string", "string2"]'::jsonb);
roundtrip
-----------------------
["string", "string2"]
(1 row)
-- test python infinity -> jsonb
CREATE FUNCTION test1inf() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = float('inf')
print(x)
return x
$$;
SELECT test1inf();
ERROR: could not convert value "inf" to jsonb
CONTEXT: while creating return value
PL/Python function "test1inf"
-- test python -infinity -> jsonb
CREATE FUNCTION test2inf() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = float('-inf')
print(x)
return x
$$;
SELECT test2inf();
ERROR: could not convert value "-inf" to jsonb
CONTEXT: while creating return value
PL/Python function "test2inf"
-- test python NaN -> jsonb
CREATE FUNCTION test1nan() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = float('nan')
return x
$$;
SELECT test1nan();
test1nan
----------
NaN
(1 row)
-- complex numbers -> jsonb
CREATE FUNCTION testComplexNumbers() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = 1 + 2j
return x
$$;
SELECT testComplexNumbers();
ERROR: could not convert value "(1+2j)" to jsonb
CONTEXT: while creating return value
PL/Python function "testcomplexnumbers"
-- range -> jsonb
CREATE FUNCTION testRange() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = range(3)
return x
$$;
SELECT testRange();
testrange
-----------
[0, 1, 2]
(1 row)
-- 0xff -> jsonb
CREATE FUNCTION testDecimal() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = 0xff
return x
$$;
SELECT testDecimal();
testdecimal
-------------
255
(1 row)
-- tuple -> jsonb
CREATE FUNCTION testTuple() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = (1, 'String', None)
return x
$$;
SELECT testTuple();
testtuple
---------------------
[1, "String", null]
(1 row)
-- interesting dict -> jsonb
CREATE FUNCTION test_dict1() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = {"a": 1, None: 2, 33: 3}
return x
$$;
SELECT test_dict1();
test_dict1
--------------------------
{"": 2, "a": 1, "33": 3}
(1 row)
This diff is collapsed.
/* contrib/jsonb_plpython/jsonb_plpython2u--1.0.sql */
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION jsonb_plpython2u" to load this file. \quit
CREATE FUNCTION jsonb_to_plpython2(val internal) RETURNS internal
LANGUAGE C STRICT IMMUTABLE
AS 'MODULE_PATHNAME', 'jsonb_to_plpython';
CREATE FUNCTION plpython2_to_jsonb(val internal) RETURNS jsonb
LANGUAGE C STRICT IMMUTABLE
AS 'MODULE_PATHNAME', 'plpython_to_jsonb';
CREATE TRANSFORM FOR jsonb LANGUAGE plpython2u (
FROM SQL WITH FUNCTION jsonb_to_plpython2(internal),
TO SQL WITH FUNCTION plpython2_to_jsonb(internal)
);
COMMENT ON TRANSFORM FOR jsonb LANGUAGE plpython2u IS 'transform between jsonb and Python';
# jsonb_plpython2u extension
comment = 'transform between jsonb and plpython2u'
default_version = '1.0'
module_pathname = '$libdir/jsonb_plpython2'
relocatable = true
requires = 'plpython2u'
/* contrib/jsonb_plpython/jsonb_plpython3u--1.0.sql */
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION jsonb_plpython3u" to load this file. \quit
CREATE FUNCTION jsonb_to_plpython3(val internal) RETURNS internal
LANGUAGE C STRICT IMMUTABLE
AS 'MODULE_PATHNAME', 'jsonb_to_plpython';
CREATE FUNCTION plpython3_to_jsonb(val internal) RETURNS jsonb
LANGUAGE C STRICT IMMUTABLE
AS 'MODULE_PATHNAME', 'plpython_to_jsonb';
CREATE TRANSFORM FOR jsonb LANGUAGE plpython3u (
FROM SQL WITH FUNCTION jsonb_to_plpython3(internal),
TO SQL WITH FUNCTION plpython3_to_jsonb(internal)
);
COMMENT ON TRANSFORM FOR jsonb LANGUAGE plpython3u IS 'transform between jsonb and Python';
# jsonb_plpython3u extension
comment = 'transform between jsonb and plpython3u'
default_version = '1.0'
module_pathname = '$libdir/jsonb_plpython3'
relocatable = true
requires = 'plpython3u'
/* contrib/jsonb_plpython/jsonb_plpythonu--1.0.sql */
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION jsonb_plpythonu" to load this file. \quit
CREATE FUNCTION jsonb_to_plpython(val internal) RETURNS internal
LANGUAGE C STRICT IMMUTABLE
AS 'MODULE_PATHNAME';
CREATE FUNCTION plpython_to_jsonb(val internal) RETURNS jsonb
LANGUAGE C STRICT IMMUTABLE
AS 'MODULE_PATHNAME';
CREATE TRANSFORM FOR jsonb LANGUAGE plpythonu (
FROM SQL WITH FUNCTION jsonb_to_plpython(internal),
TO SQL WITH FUNCTION plpython_to_jsonb(internal)
);
COMMENT ON TRANSFORM FOR jsonb LANGUAGE plpythonu IS 'transform between jsonb and Python';
# jsonb_plpythonu extension
comment = 'transform between jsonb and plpythonu'
default_version = '1.0'
module_pathname = '$libdir/jsonb_plpython2'
relocatable = true
requires = 'plpythonu'
CREATE EXTENSION jsonb_plpython2u CASCADE;
-- test jsonb -> python dict
CREATE FUNCTION test1(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert isinstance(val, dict)
plpy.info(sorted(val.items()))
return len(val)
$$;
SELECT test1('{"a": 1, "c": "NULL"}'::jsonb);
-- test jsonb -> python dict
-- complex dict with dicts as value
CREATE FUNCTION test1complex(val jsonb) RETURNS int
LANGUAGE plpython2u
TRANSFORM FOR TYPE jsonb
AS $$
assert isinstance(val, dict)
assert(val == {"d": {"d": 1}})
return len(val)
$$;
SELECT test1complex('{"d": {"d": 1}}'::jsonb);
-- test jsonb[] -> python dict
-- dict with array as value
CREATE FUNCTION test1arr(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert isinstance(val, dict)
assert(val == {"d": [12, 1]})
return len(val)
$$;
SELECT test1arr('{"d":[12, 1]}'::jsonb);
-- test jsonb[] -> python list
-- simple list
CREATE FUNCTION test2arr(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert isinstance(val, list)
assert(val == [12, 1])
return len(val)
$$;
SELECT test2arr('[12, 1]'::jsonb);
-- test jsonb[] -> python list
-- array of dicts
CREATE FUNCTION test3arr(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert isinstance(val, list)
assert(val == [{"a": 1,"b": 2}, {"c": 3,"d": 4}])
return len(val)
$$;
SELECT test3arr('[{"a": 1, "b": 2}, {"c": 3,"d": 4}]'::jsonb);
-- test jsonb int -> python int
CREATE FUNCTION test1int(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert(val == 1)
return val
$$;
SELECT test1int('1'::jsonb);
-- test jsonb string -> python string
CREATE FUNCTION test1string(val jsonb) RETURNS text
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert(val == "a")
return val
$$;
SELECT test1string('"a"'::jsonb);
-- test jsonb null -> python None
CREATE FUNCTION test1null(val jsonb) RETURNS int
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
assert(val == None)
return 1
$$;
SELECT test1null('null'::jsonb);
-- test python -> jsonb
CREATE FUNCTION roundtrip(val jsonb) RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
as $$
return val
$$;
SELECT roundtrip('null'::jsonb);
SELECT roundtrip('1'::jsonb);
SELECT roundtrip('1234567890.0987654321'::jsonb);
SELECT roundtrip('-1234567890.0987654321'::jsonb);
SELECT roundtrip('true'::jsonb);
SELECT roundtrip('"string"'::jsonb);
SELECT roundtrip('{"1": null}'::jsonb);
SELECT roundtrip('{"1": 1}'::jsonb);
SELECT roundtrip('{"1": true}'::jsonb);
SELECT roundtrip('{"1": "string"}'::jsonb);
SELECT roundtrip('[null]'::jsonb);
SELECT roundtrip('[1]'::jsonb);
SELECT roundtrip('[true]'::jsonb);
SELECT roundtrip('["string"]'::jsonb);
SELECT roundtrip('[null, 1]'::jsonb);
SELECT roundtrip('[1, true]'::jsonb);
SELECT roundtrip('[true, "string"]'::jsonb);
SELECT roundtrip('["string", "string2"]'::jsonb);
-- test python infinity -> jsonb
CREATE FUNCTION test1inf() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = float('inf')
print(x)
return x
$$;
SELECT test1inf();
-- test python -infinity -> jsonb
CREATE FUNCTION test2inf() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = float('-inf')
print(x)
return x
$$;
SELECT test2inf();
-- test python NaN -> jsonb
CREATE FUNCTION test1nan() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = float('nan')
return x
$$;
SELECT test1nan();
-- complex numbers -> jsonb
CREATE FUNCTION testComplexNumbers() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = 1 + 2j
return x
$$;
SELECT testComplexNumbers();
-- range -> jsonb
CREATE FUNCTION testRange() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = range(3)
return x
$$;
SELECT testRange();
-- 0xff -> jsonb
CREATE FUNCTION testDecimal() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = 0xff
return x
$$;
SELECT testDecimal();
-- tuple -> jsonb
CREATE FUNCTION testTuple() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = (1, 'String', None)
return x
$$;
SELECT testTuple();
-- interesting dict -> jsonb
CREATE FUNCTION test_dict1() RETURNS jsonb
LANGUAGE plpythonu
TRANSFORM FOR TYPE jsonb
AS $$
x = {"a": 1, None: 2, 33: 3}
return x
$$;
SELECT test_dict1();
...@@ -569,4 +569,19 @@ SELECT jdoc-&gt;'guid', jdoc-&gt;'name' FROM api WHERE jdoc @&gt; '{"tags": ["qu ...@@ -569,4 +569,19 @@ SELECT jdoc-&gt;'guid', jdoc-&gt;'name' FROM api WHERE jdoc @&gt; '{"tags": ["qu
compared using the default database collation. compared using the default database collation.
</para> </para>
</sect2> </sect2>
<sect2>
<title>Transforms</title>
<para>
Additional extensions are available that implement transforms for the
<type>jsonb</type> type for the language PL/Python. The extensions for
PL/Python are called <literal>jsonb_plpythonu</literal>,
<literal>jsonb_plpython2u</literal>, and
<literal>jsonb_plpython3u</literal> (see <xref
linkend="plpython-python23"/> for the PL/Python naming convention). If you
use them, <type>jsonb</type> values are mapped to Python dictionaries,
lists, and scalars, as appropriate.
</para>
</sect2>
</sect1> </sect1>
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment