File: threeway.py

package info (click to toggle)
sqlalchemy 1.2.18%2Bds1-2
  • links: PTS, VCS
  • area: main
  • in suites: buster
  • size: 16,080 kB
  • sloc: python: 239,496; ansic: 1,345; makefile: 264; xml: 17
file content (129 lines) | stat: -rw-r--r-- 4,074 bytes parent folder | download | duplicates (3)
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
"""Illustrate a "three way join" - where a primary table joins to a remote
table via an association table, but then the primary table also needs
to refer to some columns in the remote table directly.

E.g.::

    first.first_id      -> second.first_id
                           second.other_id --> partitioned.other_id
    first.partition_key ---------------------> partitioned.partition_key

For a relationship like this, "second" is a lot like a "secondary" table,
but the mechanics aren't present within the "secondary" feature to allow
for the join directly between first and partitioned.  Instead, we
will derive a selectable from partitioned and second combined together, then
link first to that derived selectable.

If we define the derived selectable as::

    second JOIN partitioned ON second.other_id = partitioned.other_id

A JOIN from first to this derived selectable is then::

    first JOIN (second JOIN partitioned
                ON second.other_id = partitioned.other_id)
          ON first.first_id = second.first_id AND
             first.partition_key = partitioned.partition_key

We will use the "non primary mapper" feature in order to produce this.
A non primary mapper is essentially an "extra" :func:`.mapper` that we can
use to associate a particular class with some selectable that is
not its usual mapped table.   It is used only when called upon within
a Query (or a :func:`.relationship`).


"""
from sqlalchemy import and_
from sqlalchemy import Column
from sqlalchemy import create_engine
from sqlalchemy import Integer
from sqlalchemy import join
from sqlalchemy import String
from sqlalchemy.ext.declarative import declarative_base
from sqlalchemy.orm import foreign
from sqlalchemy.orm import mapper
from sqlalchemy.orm import relationship
from sqlalchemy.orm import Session


Base = declarative_base()


class First(Base):
    __tablename__ = "first"

    first_id = Column(Integer, primary_key=True)
    partition_key = Column(String)

    def __repr__(self):
        return "First(%s, %s)" % (self.first_id, self.partition_key)


class Second(Base):
    __tablename__ = "second"

    first_id = Column(Integer, primary_key=True)
    other_id = Column(Integer, primary_key=True)


class Partitioned(Base):
    __tablename__ = "partitioned"

    other_id = Column(Integer, primary_key=True)
    partition_key = Column(String, primary_key=True)

    def __repr__(self):
        return "Partitioned(%s, %s)" % (self.other_id, self.partition_key)


j = join(Partitioned, Second, Partitioned.other_id == Second.other_id)

partitioned_second = mapper(
    Partitioned,
    j,
    non_primary=True,
    properties={
        # note we need to disambiguate columns here - the join()
        # will provide them as j.c.<tablename>_<colname> for access,
        # but they retain their real names in the mapping
        "other_id": [j.c.partitioned_other_id, j.c.second_other_id]
    },
)

First.partitioned = relationship(
    partitioned_second,
    primaryjoin=and_(
        First.partition_key == partitioned_second.c.partition_key,
        First.first_id == foreign(partitioned_second.c.first_id),
    ),
    innerjoin=True,
)

# when using any database other than SQLite, we will get a nested
# join, e.g. "first JOIN (partitioned JOIN second ON ..) ON ..".
# On SQLite, SQLAlchemy needs to render a full subquery.
e = create_engine("sqlite://", echo=True)

Base.metadata.create_all(e)
s = Session(e)
s.add_all(
    [
        First(first_id=1, partition_key="p1"),
        First(first_id=2, partition_key="p1"),
        First(first_id=3, partition_key="p2"),
        Second(first_id=1, other_id=1),
        Second(first_id=2, other_id=1),
        Second(first_id=3, other_id=2),
        Partitioned(partition_key="p1", other_id=1),
        Partitioned(partition_key="p1", other_id=2),
        Partitioned(partition_key="p2", other_id=2),
    ]
)
s.commit()

for row in s.query(First, Partitioned).join(First.partitioned):
    print(row)

for f in s.query(First):
    for p in f.partitioned:
        print(f.partition_key, p.partition_key)