From c1389d9e0781a7ee82ab65d64e6f151d0e6ee448 Mon Sep 17 00:00:00 2001 From: Konsta Vesterinen Date: Thu, 8 Jan 2015 13:49:14 +0200 Subject: [PATCH] Add json_sql helper function --- CHANGES.rst | 3 +- docs/database_helpers.rst | 6 +++ sqlalchemy_utils/__init__.py | 3 +- sqlalchemy_utils/functions/__init__.py | 2 + sqlalchemy_utils/functions/database.py | 71 ++++++++++++++++++++++++++ tests/functions/test_is_loaded.py | 1 - tests/functions/test_json_sql.py | 31 +++++++++++ 7 files changed, 114 insertions(+), 3 deletions(-) create mode 100644 tests/functions/test_json_sql.py diff --git a/CHANGES.rst b/CHANGES.rst index b144c37..0d61a5d 100644 --- a/CHANGES.rst +++ b/CHANGES.rst @@ -4,10 +4,11 @@ Changelog Here you can see the full list of changes between each SQLAlchemy-Utils release. -0.29.2 (2015-01-xx) +0.29.2 (2015-01-08) ^^^^^^^^^^^^^^^^^^^ - Removed deprecated defer_except (SQLAlchemy's own load_only should be used from now on) +- Added json_sql PostgreSQL helper function 0.29.1 (2015-01-03) diff --git a/docs/database_helpers.rst b/docs/database_helpers.rst index 7ce8ff1..d22e00f 100644 --- a/docs/database_helpers.rst +++ b/docs/database_helpers.rst @@ -41,6 +41,12 @@ has_unique_index .. autofunction:: has_unique_index +json_sql +^^^^^^^^ + +.. autofunction:: json_sql + + render_expression ^^^^^^^^^^^^^^^^^ diff --git a/sqlalchemy_utils/__init__.py b/sqlalchemy_utils/__init__.py index c5e048b..0e97c92 100644 --- a/sqlalchemy_utils/__init__.py +++ b/sqlalchemy_utils/__init__.py @@ -34,6 +34,7 @@ from .functions import ( has_unique_index, identity, is_loaded, + json_sql, merge_references, mock_engine, naturally_equivalent, @@ -86,7 +87,7 @@ from .types import ( from .models import Timestamp -__version__ = '0.29.1' +__version__ = '0.29.2' __all__ = ( diff --git a/sqlalchemy_utils/functions/__init__.py b/sqlalchemy_utils/functions/__init__.py index e399671..188316a 100644 --- a/sqlalchemy_utils/functions/__init__.py +++ b/sqlalchemy_utils/functions/__init__.py @@ -14,6 +14,7 @@ from .database import ( has_index, has_unique_index, is_auto_assigned_date_column, + json_sql ) from .foreign_keys import ( dependent_objects, @@ -65,6 +66,7 @@ __all__ = ( 'is_loaded', 'is_auto_assigned_date_column', 'is_indexed_foreign_key', + 'json_sql', 'make_order_by_deterministic', 'mock_engine', 'naturally_equivalent', diff --git a/sqlalchemy_utils/functions/database.py b/sqlalchemy_utils/functions/database.py index c48f62a..225360f 100644 --- a/sqlalchemy_utils/functions/database.py +++ b/sqlalchemy_utils/functions/database.py @@ -1,3 +1,5 @@ +import collections +import itertools import os from copy import copy @@ -105,6 +107,75 @@ def escape_like(string, escape_char='*'): ) +def json_sql(value, scalars_to_json=True): + """ + Convert python data structures to PostgreSQL specific SQLAlchemy JSON + constructs. This function is extremly useful if you need to build + PostgreSQL JSON on python side. + + .. note:: + + This function needs PostgreSQL >= 9.4 + + Scalars are converted to to_json SQLAlchemy function objects + + :: + + json_sql(1) # Equals SQL: to_json(1) + + json_sql('a') # to_json('a') + + + Mappings are converted to json_build_object constructs + + :: + + json_sql({'a': 'c', '2': 5}) # json_build_object('a', 'c', '2', 5) + + + Sequences (other than strings) are converted to json_build_array constructs + + :: + + json_sql([1, 2, 3]) # json_build_array(1, 2, 3) + + + You can also nest these data structures + + :: + + json_sql({'a': [1, 2, 3]}) + # json_build_object('a', json_build_array[1, 2, 3]) + + + :param value: + value to be converted to SQLAlchemy PostgreSQL function constructs + """ + scalar_convert = sa.text + if scalars_to_json: + scalar_convert = lambda a: sa.func.to_json(sa.text(a)) + + if isinstance(value, collections.Mapping): + return sa.func.json_build_object( + *( + json_sql(v, scalars_to_json=False) + for v in itertools.chain(*value.items()) + ) + ) + elif isinstance(value, str): + return scalar_convert("'{0}'".format(value)) + elif isinstance(value, collections.Sequence): + return sa.func.json_build_array( + *( + json_sql(v, scalars_to_json=False) + for v in value + ) + ) + elif isinstance(value, (int, float)): + return scalar_convert(str(value)) + return value + + def has_index(column): """ Return whether or not given column has an index. A column has an index if diff --git a/tests/functions/test_is_loaded.py b/tests/functions/test_is_loaded.py index 1996c86..68d7d24 100644 --- a/tests/functions/test_is_loaded.py +++ b/tests/functions/test_is_loaded.py @@ -22,4 +22,3 @@ class TestIsLoaded(object): def test_unloaded_property(self): article = self.Article(id=4) assert not is_loaded(article, 'title') - diff --git a/tests/functions/test_json_sql.py b/tests/functions/test_json_sql.py new file mode 100644 index 0000000..5833dc9 --- /dev/null +++ b/tests/functions/test_json_sql.py @@ -0,0 +1,31 @@ +import pytest +import sqlalchemy as sa +from sqlalchemy_utils import json_sql + +from tests import TestCase + + +class TestJSONSQL(TestCase): + dns = 'postgres://postgres@localhost/sqlalchemy_utils_test' + + @pytest.mark.parametrize( + ('value', 'compiled'), + ( + (1, 'to_json(1)'), + (14.14, 'to_json(14.14)'), + ({'a': 2, 'b': 'c'}, "json_build_object('a', 2, 'b', 'c')"), + ( + {'a': {'b': 'c'}}, + "json_build_object('a', json_build_object('b', 'c'))" + ), + ({}, 'json_build_object()'), + ([1, 2], 'json_build_array(1, 2)'), + ([], 'json_build_array()'), + ( + [sa.select([sa.text('1')])], + 'json_build_array((SELECT 1))' + ) + ) + ) + def test_compiled_scalars(self, value, compiled): + assert str(json_sql(value).compile(self.connection)) == compiled