File: dictlike.py

package info (click to toggle)
sqlalchemy 1.0.15%2Bds1-1
  • links: PTS, VCS
  • area: main
  • in suites: stretch
  • size: 13,056 kB
  • ctags: 26,600
  • sloc: python: 169,901; ansic: 1,346; makefile: 260; xml: 17
file content (165 lines) | stat: -rw-r--r-- 5,034 bytes parent folder | download | duplicates (4)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
"""Mapping a vertical table as a dictionary.

This example illustrates accessing and modifying a "vertical" (or
"properties", or pivoted) table via a dict-like interface.  These are tables
that store free-form object properties as rows instead of columns.  For
example, instead of::

  # A regular ("horizontal") table has columns for 'species' and 'size'
  Table('animal', metadata,
        Column('id', Integer, primary_key=True),
        Column('species', Unicode),
        Column('size', Unicode))

A vertical table models this as two tables: one table for the base or parent
entity, and another related table holding key/value pairs::

  Table('animal', metadata,
        Column('id', Integer, primary_key=True))

  # The properties table will have one row for a 'species' value, and
  # another row for the 'size' value.
  Table('properties', metadata
        Column('animal_id', Integer, ForeignKey('animal.id'),
               primary_key=True),
        Column('key', UnicodeText),
        Column('value', UnicodeText))

Because the key/value pairs in a vertical scheme are not fixed in advance,
accessing them like a Python dict can be very convenient.  The example below
can be used with many common vertical schemas as-is or with minor adaptations.

"""
from __future__ import unicode_literals

class ProxiedDictMixin(object):
    """Adds obj[key] access to a mapped class.

    This class basically proxies dictionary access to an attribute
    called ``_proxied``.  The class which inherits this class
    should have an attribute called ``_proxied`` which points to a dictionary.

    """

    def __len__(self):
        return len(self._proxied)

    def __iter__(self):
        return iter(self._proxied)

    def __getitem__(self, key):
        return self._proxied[key]

    def __contains__(self, key):
        return key in self._proxied

    def __setitem__(self, key, value):
        self._proxied[key] = value

    def __delitem__(self, key):
        del self._proxied[key]


if __name__ == '__main__':
    from sqlalchemy import (Column, Integer, Unicode,
        ForeignKey, UnicodeText, and_, create_engine)
    from sqlalchemy.orm import relationship, Session
    from sqlalchemy.orm.collections import attribute_mapped_collection
    from sqlalchemy.ext.declarative import declarative_base
    from sqlalchemy.ext.associationproxy import association_proxy

    Base = declarative_base()

    class AnimalFact(Base):
        """A fact about an animal."""

        __tablename__ = 'animal_fact'

        animal_id = Column(ForeignKey('animal.id'), primary_key=True)
        key = Column(Unicode(64), primary_key=True)
        value = Column(UnicodeText)

    class Animal(ProxiedDictMixin, Base):
        """an Animal"""

        __tablename__ = 'animal'

        id = Column(Integer, primary_key=True)
        name = Column(Unicode(100))

        facts = relationship("AnimalFact",
                    collection_class=attribute_mapped_collection('key'))

        _proxied = association_proxy("facts", "value",
                            creator=
                            lambda key, value: AnimalFact(key=key, value=value))

        def __init__(self, name):
            self.name = name

        def __repr__(self):
            return "Animal(%r)" % self.name

        @classmethod
        def with_characteristic(self, key, value):
            return self.facts.any(key=key, value=value)

    engine = create_engine("sqlite://")
    Base.metadata.create_all(engine)

    session = Session(bind=engine)

    stoat = Animal('stoat')
    stoat['color'] = 'reddish'
    stoat['cuteness'] = 'somewhat'

    # dict-like assignment transparently creates entries in the
    # stoat.facts collection:
    print(stoat.facts['color'])

    session.add(stoat)
    session.commit()

    critter = session.query(Animal).filter(Animal.name == 'stoat').one()
    print(critter['color'])
    print(critter['cuteness'])

    critter['cuteness'] = 'very'

    print('changing cuteness:')

    marten = Animal('marten')
    marten['color'] = 'brown'
    marten['cuteness'] = 'somewhat'
    session.add(marten)

    shrew = Animal('shrew')
    shrew['cuteness'] = 'somewhat'
    shrew['poisonous-part'] = 'saliva'
    session.add(shrew)

    loris = Animal('slow loris')
    loris['cuteness'] = 'fairly'
    loris['poisonous-part'] = 'elbows'
    session.add(loris)

    q = (session.query(Animal).
         filter(Animal.facts.any(
           and_(AnimalFact.key == 'color',
                AnimalFact.value == 'reddish'))))
    print('reddish animals', q.all())

    q = session.query(Animal).\
            filter(Animal.with_characteristic("color", 'brown'))
    print('brown animals', q.all())

    q = session.query(Animal).\
           filter(~Animal.with_characteristic("poisonous-part", 'elbows'))
    print('animals without poisonous-part == elbows', q.all())

    q = (session.query(Animal).
         filter(Animal.facts.any(value='somewhat')))
    print('any animal with any .value of "somewhat"', q.all())