"Virtual models" for JSONB data?

13 views
Skip to first unread message

Pedro Ferreira

unread,
Jul 3, 2020, 9:21:31 AM7/3/20
to sqlal...@googlegroups.com
Hi,

I was wondering if there's some way to create some sort of a "virtual"
model which is not based on an actual table?

Use case: I have a model (e.g. `Room`) which contains a `data` JSONB
attribute/column which is supposed to store plugin-specific data. I
would like plugin code to be able to create a "virtual" model which
references `Room` 1-to-1 and injects a `plugin_data` backref into it.
That means I would be able to do `room.plugin_data.user`, for instance,
which would use `room.data['user_id']` to fetch a `User` object.

Right now, our plugins do this by means of an additional table. E.g., in
this case we would have `PluginRoom`, which would store `user_id` and
have a 1-to-1 relationship with `Room`, with a backref.

I was wondering if there's some way we can have a similar pattern based
on unstructured JSONB data.

Cheers,

Pedro



signature.asc

Mike Bayer

unread,
Jul 3, 2020, 10:25:30 AM7/3/20
to noreply-spamdigest via sqlalchemy
Python can do this using patterns like the `__getattr__` method.   here's a 30 second proof of concept.  note the use of flag_modified() to ensure that an attribute set is flagged for unit of work update.

from sqlalchemy import Column
from sqlalchemy import create_engine
from sqlalchemy import Integer
from sqlalchemy.dialects.postgresql import JSONB
from sqlalchemy.ext.declarative import declarative_base
from sqlalchemy.orm import Session
from sqlalchemy.orm.attributes import flag_modified

Base = declarative_base()


class A(Base):
    __tablename__ = "a"

    id = Column(Integer, primary_key=True)
    _data = Column(JSONB, default={})

    def __init__(self, **kw):
        self._data = {}
        self._data.update(kw)

    def __getattr__(self, key):
        if key.startswith("_"):
            raise AttributeError(key)

        return self._data[key]

    def __setattr__(self, key, value):
        if key.startswith("_"):
            object.__setattr__(self, key, value)
        else:
            self._data[key] = value
            flag_modified(self, "_data")


e = create_engine("postgresql://scott:tiger@localhost/test", echo=True)
Base.metadata.drop_all(e)
Base.metadata.create_all(e)

s = Session(e)

a1 = A(foo="bar", bar="bat")

s.add(a1)
s.commit()


assert s.query(A._data).first() == ({"foo": "bar", "bar": "bat"},)

a1.bar = "new bat"

s.commit()

assert s.query(A._data).first() == ({"foo": "bar", "bar": "new bat"},)







Cheers,

Pedro



-- 
SQLAlchemy - 
The Python SQL Toolkit and Object Relational Mapper


To post example code, please provide an MCVE: Minimal, Complete, and Verifiable Example.  See  http://stackoverflow.com/help/mcve for a full description.
--- 
You received this message because you are subscribed to the Google Groups "sqlalchemy" group.
To unsubscribe from this group and stop receiving emails from it, send an email to sqlalchemy+...@googlegroups.com.


Attachments:
  • signature.asc

Pedro Ferreira

unread,
Jul 6, 2020, 3:15:00 AM7/6/20
to Mike Bayer, sqlal...@googlegroups.com
OK, thanks a lot anyway! I was just wondering if there was already some
solution I could reuse.

Cheers,

Pedro

On 03.07.20 17:26, Mike Bayer wrote:

> I suppose.  that seems really complicated.    When we use the ORM, we're
> defining our domain model in terms of objects, then we define a
> persistence layer in terms of relational tables.   The Declarative
> approach is a compromise between the more strict mapper() approach,
> which looks like mapper(class, Table) and the need to have the
> declaration of classes and their data members be succinct and
> localized.      however if you are defining an alternative form of
> persistence , then all of the ORM capabilities go away, they'd have to
> be reimplemented in terms of that new persistence model.
>
> short answer, things like relationships and all that you would need to
> re-implement in some other way that works in terms of json records.
>

signature.asc

Burak Arslan

unread,
Jul 7, 2020, 9:25:38 AM7/7/20
to sqlal...@googlegroups.com, Pedro Ferreira

On 03/07/2020 16:21, Pedro Ferreira wrote:
Hi,

I was wondering if there's some way to create some sort of a "virtual"
model which is not based on an actual table?

Use case: I have a model (e.g. `Room`) which contains a `data` JSONB
attribute/column which is supposed to store plugin-specific data. I
would like plugin code to be able to create a "virtual" model which
references `Room` 1-to-1 and injects a `plugin_data` backref into it.
That means I would be able to do `room.plugin_data.user`, for instance,
which would use `room.data['user_id']` to fetch a `User` object.


Spyne contains some work towards that goal.

I added an example[1]. What works: the Preferences object gets serialized to json and stored as jsonb. It's also deserialized from json to an instance when read. It's implemented as a generic UserDefinedType[2].

Caveats:
  1. It's postgresql-only (never tested on other RDBMS, maybe it'll work! help is welcome)
  2. It doesn't do fancy orm stuff like mapping the value of a user_id field to a user instance.
  3. Doesn't automatically mark stuff dirty as a field in the subobject changes[3].
  4. Doesn't support marking subfields dirty -- When the subobject is marked as dirty (using flag_dirty[4]), the whole json document is updated instead of just the changed subfield. (using jsonb_set[5]).

Disclaimer: I'm the author of Spyne.

I hope it helps!

Best,
Burak

[1]: https://github.com/arskom/spyne/blob/bc8c3567992abcc387c135d5f8e19c76439c2482/examples/sql/sql_crud.py#L60

[2]: https://github.com/arskom/spyne/blob/bc8c3567992abcc387c135d5f8e19c76439c2482/spyne/store/relational/document.py#L187

[3]: https://github.com/arskom/spyne/blob/bc8c3567992abcc387c135d5f8e19c76439c2482/spyne/test/test_sqlalchemy.py#L148

[4]: https://docs.sqlalchemy.org/en/13/orm/session_api.html#sqlalchemy.orm.attributes.flag_dirt

[5]: https://www.postgresql.org/docs/12/functions-json.html#FUNCTIONS-JSON-PROCESSING-TABLE

Reply all
Reply to author
Forward
0 new messages