diff options
author | Mike Bayer <mike_mp@zzzcomputing.com> | 2013-12-05 12:17:16 -0500 |
---|---|---|
committer | Mike Bayer <mike_mp@zzzcomputing.com> | 2013-12-05 12:17:16 -0500 |
commit | 3a03c2e715544476ab2e53ab9b26d83800e437ed (patch) | |
tree | de8cc6ec857af684d018b329823b6b805152a32b | |
parent | 7c1bb7690497e9dcb1a15a6d84e323bf0a966fbe (diff) | |
download | sqlalchemy-3a03c2e715544476ab2e53ab9b26d83800e437ed.tar.gz |
- add a new example section for "join conditions", start putting
the primaryjoin examples there
-rw-r--r-- | doc/build/orm/examples.rst | 7 | ||||
-rw-r--r-- | examples/join_conditions/__init__.py | 7 | ||||
-rw-r--r-- | examples/join_conditions/cast.py | 95 | ||||
-rw-r--r-- | examples/join_conditions/threeway.py | 108 |
4 files changed, 217 insertions, 0 deletions
diff --git a/doc/build/orm/examples.rst b/doc/build/orm/examples.rst index 484865e7e..99ca4bb8d 100644 --- a/doc/build/orm/examples.rst +++ b/doc/build/orm/examples.rst @@ -57,6 +57,13 @@ Nested Sets .. automodule:: examples.nested_sets +.. _examples_relationships: + +Relationship Join Conditions +---------------------------- + +.. automodule:: examples.join_conditions + .. _examples_xmlpersistence: XML Persistence diff --git a/examples/join_conditions/__init__.py b/examples/join_conditions/__init__.py new file mode 100644 index 000000000..3a561d084 --- /dev/null +++ b/examples/join_conditions/__init__.py @@ -0,0 +1,7 @@ +"""Examples of various :func:`.orm.relationship` configurations, +which make use of the ``primaryjoin`` argument to compose special types +of join conditions. + +.. autosource:: + +"""
\ No newline at end of file diff --git a/examples/join_conditions/cast.py b/examples/join_conditions/cast.py new file mode 100644 index 000000000..246bc1d57 --- /dev/null +++ b/examples/join_conditions/cast.py @@ -0,0 +1,95 @@ +"""Illustrate a :func:`.relationship` that joins two columns where those +columns are not of the same type, and a CAST must be used on the SQL +side in order to match them. + +When complete, we'd like to see a load of the relationship to look like:: + + -- load the primary row, a_id is a string + SELECT a.id AS a_id_1, a.a_id AS a_a_id + FROM a + WHERE a.a_id = '2' + + -- then load the collection using CAST, b.a_id is an integer + SELECT b.id AS b_id, b.a_id AS b_a_id + FROM b + WHERE CAST('2' AS INTEGER) = b.a_id + +The relationship is essentially configured as follows:: + + class B(Base): + # ... + + a = relationship(A, + primaryjoin=cast(A.a_id, Integer) == foreign(B.a_id), + backref="bs") + +Where above, we are making use of the :func:`.cast` function in order +to produce CAST, as well as the :func:`.foreign` :term:`annotation` function +in order to note to the ORM that ``B.a_id`` should be treated like the +"foreign key" column. + +""" +from sqlalchemy import * +from sqlalchemy.orm import * +from sqlalchemy.ext.declarative import declarative_base + +Base = declarative_base() + +class StringAsInt(TypeDecorator): + """Coerce string->integer type. + + This is needed only if the relationship() from + int to string is writable, as SQLAlchemy will copy + the string parent values into the integer attribute + on the child during a flush. + + """ + impl = Integer + def process_bind_param(self, value, dialect): + if value is not None: + value = int(value) + return value + +class A(Base): + """Parent. The referenced column is a string type.""" + + __tablename__ = 'a' + + id = Column(Integer, primary_key=True) + a_id = Column(String) + +class B(Base): + """Child. The column we reference 'A' with is an integer.""" + + __tablename__ = 'b' + + id = Column(Integer, primary_key=True) + a_id = Column(StringAsInt) + a = relationship("A", + # specify primaryjoin. The string form is optional + # here, but note that Declarative makes available all + # of the built-in functions we might need, including + # cast() and foreign(). + primaryjoin="cast(A.a_id, Integer) == foreign(B.a_id)", + backref="bs") + +# we demonstrate with SQLite, but the important part +# is the CAST rendered in the SQL output. + +e = create_engine('sqlite://', echo=True) +Base.metadata.create_all(e) + +s = Session(e) + +s.add_all([ + A(a_id="1"), + A(a_id="2", bs=[B(), B()]), + A(a_id="3", bs=[B()]), +]) +s.commit() + +b1 = s.query(B).filter_by(a_id="2").first() +print(b1.a) + +a1 = s.query(A).filter_by(a_id="2").first() +print(a1.bs)
\ No newline at end of file diff --git a/examples/join_conditions/threeway.py b/examples/join_conditions/threeway.py new file mode 100644 index 000000000..13df0f349 --- /dev/null +++ b/examples/join_conditions/threeway.py @@ -0,0 +1,108 @@ +"""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 * +from sqlalchemy.orm import * +from sqlalchemy.ext.declarative import declarative_base + +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) |