Skip to content

Issue 2581 -- support for postgresql json type #50

Merged
merged 6 commits into from Dec 17, 2013

2 participants

@nathan-rice

Very simple, based on the HSTORE data type.

I added support on the type itself for custom serializer/deserializer, and a different json module can be monkey patched in and will work properly (assuming it is api-compatible with python's json module, which most of them are).

nathan-rice added some commits Dec 9, 2013
@nathan-rice nathan-rice sqlalchemy/dialects/postgresql/__init__.py:
- Added import references to JSON class

 sqlalchemy/dialects/postgresql/base.py:
 - Added visitor method for JSON class

 sqlalchemy/dialects/postgresql/pgjson (new):
 - JSON class, supports automatic serialization and deserialization of json data, as well as basic json operators.
64288c7
@nathan-rice nathan-rice Merge branch 'rel_0_9' of https://github.com/nathan-rice/sqlalchemy i…
…nto rel_0_9
ba73d61
@zzzeek zzzeek commented on an outdated diff Dec 9, 2013
lib/sqlalchemy/dialects/postgresql/pgjson.py
+# This module is part of SQLAlchemy and is released under
+# the MIT License: http://www.opensource.org/licenses/mit-license.php
+
+import json
+
+from .base import ARRAY, ischema_names
+from ... import types as sqltypes
+from ...sql import functions as sqlfunc
+from ...sql.operators import custom_op
+from ... import util
+
+__all__ = ('JSON', 'json')
+
+
+class JSON(sqltypes.TypeEngine):
+ """Represent the Postgresql HSTORE type.
@zzzeek
Owner
zzzeek added a note Dec 9, 2013

change this to JSON ;)

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
@zzzeek zzzeek commented on an outdated diff Dec 9, 2013
lib/sqlalchemy/dialects/postgresql/pgjson.py
+ conn.execute(
+ data_table.insert(),
+ data = {"key1": "value1", "key2": "value2"}
+ )
+
+ :class:`.JSON` provides two operations:
+
+ * Index operations::
+
+ data_table.c.data['some key'] == 'some value'
+
+ * Path Index operations::
+
+ data_table.c.data.get_path('{key_1, key_2, ..., key_n}']
+
+ Please be aware that when used with the SQL Alchemy ORM, you will need to
@zzzeek
Owner
zzzeek added a note Dec 9, 2013

SQLAlchemy, seems like a misbehaving spellchecker

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
@zzzeek zzzeek commented on the diff Dec 9, 2013
lib/sqlalchemy/dialects/postgresql/pgjson.py
+ def process(value):
+ return self.json_serializer(value).encode(encoding)
+ else:
+ def process(value):
+ return self.json_serializer(value)
+ return process
+
+ def result_processor(self, dialect, coltype):
+ if util.py2k:
+ encoding = dialect.encoding
+ def process(value):
+ return self.json_deserializer(value.decode(encoding))
+ else:
+ def process(value):
+ return self.json_deserializer(value)
+ return process
@zzzeek
Owner
zzzeek added a note Dec 9, 2013
@nathan-rice
nathan-rice added a note Dec 9, 2013

Thanks for this note. It turns out that psycopg2's json support is pretty recent (up to date ubuntu packages don't have it), and it is on by default, so this code will actually error tests if psycopg2 is up to date. I'll see what I can do about this.

@nathan-rice
nathan-rice added a note Dec 9, 2013

There is a problem having a use_native_json kwarg. Specifically, in order to not use native json with psycopg2 >= 2.5, you have to monkey-patch the module. I could check on dialect init to see if the module has been monkey-patched and revert if necessary, but I think it would be better to just pass on letting the user turn off json processing.

@zzzeek
Owner
zzzeek added a note Dec 10, 2013

that's not a problem, we don't need a "use_native_json" kwarg then - just use psycopg2's facility when it is detected (though we have to figure out a decent way to test the non-psycopg2 version considering that the tests usually run just on psycopg2...)

@zzzeek
Owner
zzzeek added a note Dec 10, 2013

ok we maybe can test it if we detect psycopg2 using their Json object with a null-dumper, but don't worry about that part, that's kind of intricate and I'll figure out how that might work. if we can just get tests to pass for now that's enough for the PR.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
@zzzeek zzzeek commented on an outdated diff Dec 9, 2013
test/dialect/postgresql/test_types.py
+ data = testing.db.execute(
+ select([self.tables.data_table.c.data]).
+ order_by(self.tables.data_table.c.name)
+ ).fetchall()
+ eq_([d for d, in data], compare)
+
+ def _test_insert(self, engine):
+ engine.execute(
+ self.tables.data_table.insert(),
+ {'name': 'r1', 'data': {"k1": "r1v1", "k2": "r1v2"}}
+ )
+ self._assert_data([{"k1": "r1v1", "k2": "r1v2"}])
+
+ def _non_native_engine(self):
+ if testing.against("postgresql+psycopg2"):
+ engine = engines.testing_engine(options=dict(use_native_hstore=False))
@zzzeek
Owner
zzzeek added a note Dec 9, 2013

yeah this would have to be "use_native_json=False" once that flag is implemented

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
@zzzeek
Owner
zzzeek commented Dec 9, 2013

looks very nice, if we can add the psycopg2 support and fix a few typos we'll be in good shape :)

nathan-rice added some commits Dec 10, 2013
@nathan-rice nathan-rice sqlalchemy/dialects/postgresql/pgjson:
 - Fixed reference to HSTORE
 - Corrected spelling of SQLAlchemy

 sqlalchemy/dialects/postgresql/psycopg2:
 - Added psycopg2 specific wrapper type for JSON which uses inherent json deserialization facilities
 - Added code to detect and utilize the JSON wrapper if psycopg2 >= 2.5

test/dialect/postgresql/test_types:
- removed reference to use_native_hstore
f285b35
@nathan-rice nathan-rice sqlalchemy/dialects/postgresql/psycopg2:
 - Removed unneeded import of psycopg2.extensions
059039e
@nathan-rice nathan-rice sqlalchemy/dialects/postgresql/pgjson:
 - Added support for additional operators
 - Made return as json default (rather than text)
015c73c
@nathan-rice nathan-rice sqlalchemy/dialects/postgresql/pgjson:
 - Updated documentation for JSON class
c64b7aa
@nathan-rice

This should be good to go now.

@zzzeek zzzeek commented on the diff Dec 17, 2013
lib/sqlalchemy/dialects/postgresql/psycopg2.py
@@ -363,6 +377,7 @@ def initialize(self, connection):
self._has_native_hstore = self.use_native_hstore and \
self._hstore_oids(connection.connection) \
is not None
+ self._has_native_json = self.psycopg2_version >= (2, 5)
@zzzeek
Owner
zzzeek added a note Dec 17, 2013

nailed it! nice.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
@zzzeek zzzeek commented on the diff Dec 17, 2013
test/dialect/postgresql/test_types.py
+
+ def test_where_path_as_text(self):
+ self._test_where(
+ self.jsoncol.get_path_as_text('{"foo", 1}') == None,
+ "(test_table.test_column #>> %(test_column_1)s) IS NULL"
+ )
+
+ def test_cols_get(self):
+ self._test_cols(
+ self.jsoncol['foo'],
+ "test_table.test_column -> %(test_column_1)s AS anon_1",
+ True
+ )
+
+
+class JSONRoundTripTest(fixtures.TablesTest):
@zzzeek
Owner
zzzeek added a note Dec 17, 2013

great job on this

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
@zzzeek zzzeek commented on the diff Dec 17, 2013
lib/sqlalchemy/dialects/postgresql/pgjson.py
+ def __getitem__(self, other):
+ """Text expression. Get the value at a given key."""
+ # I'm choosing to return text here so the result can be cast,
+ # compared with strings, etc.
+ #
+ # The only downside to this is that you cannot dereference more
+ # than one level deep in json structures, though comparator
+ # support for multi-level dereference is lacking anyhow.
+ return self.expr.op('->', precedence=5)(other)
+
+ def get_item_as_text(self, other):
+ """Text expression. Get the value at the given key as text. Use
+ this when you need to cast the type of the returned value."""
+ return self.expr.op('->>', precedence=5)(other)
+
+ def get_path(self, other):
@zzzeek
Owner
zzzeek added a note Dec 17, 2013

im thinking of streamlining the operators here. Looking at http://www.postgresql.org/docs/9.3/static/functions-json.html it seems like our operators are: getitem, getarray, and then both have the option to be "text".

so how about this:

json_col['some_element']    # get the element
json_col.astext['some_element']    # get the element as text
json_col[('a', 'b', 2)]  # get by path
json_col.astext[('a', 'b', 2)] # get by path as text

seems like also these ops are only in pg 9.3....ill add some qualifiers to the tests and I also want to add some round trips for these. going to install 9.3 now...

@nathan-rice
nathan-rice added a note Dec 17, 2013

That is a much nicer interface, for sure.

What all are you planning on coding? I'm happy to code up all the stuff you mentioned, I just don't want to duplicate work.

@zzzeek
Owner
zzzeek added a note Dec 17, 2013

i think you're done! im just going to try to test this stuff out and familiarize, make that change, add a few more tests. you've laid out all the groundwork here so thanks!

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
@zzzeek zzzeek merged commit c64b7aa into zzzeek:master Dec 17, 2013
@zzzeek zzzeek pushed a commit that referenced this pull request Jan 7, 2016
Mike Bayer Merged in jvanasco/sqlalchemy-alt/issue_docs_scoped_session (pull req…
…uest #50)

updated docstrings for orm.scoping
1539268
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Something went wrong with that request. Please try again.