--- /dev/null
+from test.lib.testing import eq_, assert_raises, assert_raises_message
+import operator
+from sqlalchemy import *
+from sqlalchemy import exc as sa_exc, util
+from sqlalchemy.sql import compiler, table, column
+from sqlalchemy.engine import default
+from sqlalchemy.orm import *
+from sqlalchemy.orm import attributes
+
+from test.lib.testing import eq_
+
+import sqlalchemy as sa
+from test.lib import testing, AssertsCompiledSQL, Column, engines
+
+from test.orm import _fixtures
+from test.orm._fixtures import keywords, addresses, Base, \
+ Keyword, FixtureTest, \
+ Dingaling, item_keywords, dingalings, User, items,\
+ orders, Address, users, nodes, \
+ order_items, Item, Order, Node, \
+ composite_pk_table, CompositePk
+
+from test.orm import _base
+
+from sqlalchemy.orm.util import join, outerjoin, with_parent
+
+class QueryTest(_fixtures.FixtureTest):
+ run_setup_mappers = 'once'
+ run_inserts = 'once'
+ run_deletes = None
+
+
+ @classmethod
+ def setup_mappers(cls):
+ mapper(User, users, properties={
+ 'addresses':relationship(Address, backref='user', order_by=addresses.c.id),
+ 'orders':relationship(Order, backref='user', order_by=orders.c.id), # o2m, m2o
+ })
+ mapper(Address, addresses, properties={
+ 'dingaling':relationship(Dingaling, uselist=False, backref="address") #o2o
+ })
+ mapper(Dingaling, dingalings)
+ mapper(Order, orders, properties={
+ 'items':relationship(Item, secondary=order_items, order_by=items.c.id), #m2m
+ 'address':relationship(Address), # m2o
+ })
+ mapper(Item, items, properties={
+ 'keywords':relationship(Keyword, secondary=item_keywords) #m2m
+ })
+ mapper(Keyword, keywords)
+
+ mapper(Node, nodes, properties={
+ 'children':relationship(Node,
+ backref=backref('parent', remote_side=[nodes.c.id])
+ )
+ })
+
+ mapper(CompositePk, composite_pk_table)
+
+ configure_mappers()
+
+
+class RawSelectTest(QueryTest, AssertsCompiledSQL):
+ """compare a bunch of select() tests with the equivalent Query using straight table/columns.
+
+ Results should be the same as Query should act as a select() pass-thru for ClauseElement entities.
+
+ """
+ def test_select(self):
+ sess = create_session()
+
+ self.assert_compile(sess.query(users).select_from(users.select()).with_labels().statement,
+ "SELECT users.id AS users_id, users.name AS users_name FROM users, "
+ "(SELECT users.id AS id, users.name AS name FROM users) AS anon_1",
+ dialect=default.DefaultDialect()
+ )
+
+ self.assert_compile(sess.query(users, exists([1], from_obj=addresses)).with_labels().statement,
+ "SELECT users.id AS users_id, users.name AS users_name, EXISTS "
+ "(SELECT 1 FROM addresses) AS anon_1 FROM users",
+ dialect=default.DefaultDialect()
+ )
+
+ # a little tedious here, adding labels to work around Query's auto-labelling.
+ # also correlate needed explicitly. hmmm.....
+ # TODO: can we detect only one table in the "froms" and then turn off use_labels ?
+ s = sess.query(addresses.c.id.label('id'), addresses.c.email_address.label('email')).\
+ filter(addresses.c.user_id==users.c.id).correlate(users).statement.alias()
+
+ self.assert_compile(sess.query(users, s.c.email).select_from(users.join(s, s.c.id==users.c.id)).with_labels().statement,
+ "SELECT users.id AS users_id, users.name AS users_name, anon_1.email AS anon_1_email "
+ "FROM users JOIN (SELECT addresses.id AS id, addresses.email_address AS email FROM addresses "
+ "WHERE addresses.user_id = users.id) AS anon_1 ON anon_1.id = users.id",
+ dialect=default.DefaultDialect()
+ )
+
+ x = func.lala(users.c.id).label('foo')
+ self.assert_compile(sess.query(x).filter(x==5).statement,
+ "SELECT lala(users.id) AS foo FROM users WHERE lala(users.id) = :param_1", dialect=default.DefaultDialect())
+
+ self.assert_compile(sess.query(func.sum(x).label('bar')).statement,
+ "SELECT sum(lala(users.id)) AS bar FROM users", dialect=default.DefaultDialect())
+
+
+class FromSelfTest(QueryTest, AssertsCompiledSQL):
+ def test_filter(self):
+
+ assert [User(id=8), User(id=9)] == create_session().query(User).filter(User.id.in_([8,9])).from_self().all()
+
+ assert [User(id=8), User(id=9)] == create_session().query(User).order_by(User.id).slice(1,3).from_self().all()
+ assert [User(id=8)] == list(create_session().query(User).filter(User.id.in_([8,9])).from_self().order_by(User.id)[0:1])
+
+ def test_join(self):
+ assert [
+ (User(id=8), Address(id=2)),
+ (User(id=8), Address(id=3)),
+ (User(id=8), Address(id=4)),
+ (User(id=9), Address(id=5))
+ ] == create_session().query(User).filter(User.id.in_([8,9])).from_self().\
+ join('addresses').add_entity(Address).order_by(User.id, Address.id).all()
+
+ def test_group_by(self):
+ eq_(
+ create_session().query(Address.user_id, func.count(Address.id).label('count')).\
+ group_by(Address.user_id).order_by(Address.user_id).all(),
+ [(7, 1), (8, 3), (9, 1)]
+ )
+
+ eq_(
+ create_session().query(Address.user_id, Address.id).\
+ from_self(Address.user_id, func.count(Address.id)).\
+ group_by(Address.user_id).order_by(Address.user_id).all(),
+ [(7, 1), (8, 3), (9, 1)]
+ )
+
+ def test_no_joinedload(self):
+ """test that joinedloads are pushed outwards and not rendered in subqueries."""
+
+ s = create_session()
+
+ oracle_as = not testing.against('oracle') and "AS " or ""
+
+ self.assert_compile(
+ s.query(User).options(joinedload(User.addresses)).from_self().statement,
+ "SELECT anon_1.users_id, anon_1.users_name, addresses_1.id, addresses_1.user_id, "\
+ "addresses_1.email_address FROM (SELECT users.id AS users_id, users.name AS users_name FROM users) %(oracle_as)sanon_1 "\
+ "LEFT OUTER JOIN addresses %(oracle_as)saddresses_1 ON anon_1.users_id = addresses_1.user_id ORDER BY addresses_1.id" % {
+ 'oracle_as':oracle_as
+ }
+ )
+
+ def test_aliases(self):
+ """test that aliased objects are accessible externally to a from_self() call."""
+
+ s = create_session()
+
+ ualias = aliased(User)
+ eq_(
+ s.query(User, ualias).filter(User.id > ualias.id).from_self(User.name, ualias.name).
+ order_by(User.name, ualias.name).all(),
+ [
+ (u'chuck', u'ed'),
+ (u'chuck', u'fred'),
+ (u'chuck', u'jack'),
+ (u'ed', u'jack'),
+ (u'fred', u'ed'),
+ (u'fred', u'jack')
+ ]
+ )
+
+ eq_(
+ s.query(User, ualias).filter(User.id > ualias.id).from_self(User.name, ualias.name).filter(ualias.name=='ed')\
+ .order_by(User.name, ualias.name).all(),
+ [(u'chuck', u'ed'), (u'fred', u'ed')]
+ )
+
+ eq_(
+ s.query(User, ualias).filter(User.id > ualias.id).from_self(ualias.name, Address.email_address).
+ join(ualias.addresses).order_by(ualias.name, Address.email_address).all(),
+ [
+ (u'ed', u'fred@fred.com'),
+ (u'jack', u'ed@bettyboop.com'),
+ (u'jack', u'ed@lala.com'),
+ (u'jack', u'ed@wood.com'),
+ (u'jack', u'fred@fred.com')]
+ )
+
+
+ def test_multiple_entities(self):
+ sess = create_session()
+
+ eq_(
+ sess.query(User, Address).filter(User.id==Address.user_id).filter(Address.id.in_([2, 5])).from_self().all(),
+ [
+ (User(id=8), Address(id=2)),
+ (User(id=9), Address(id=5))
+ ]
+ )
+
+ eq_(
+ sess.query(User, Address).filter(User.id==Address.user_id).filter(Address.id.in_([2, 5])).from_self().options(joinedload('addresses')).first(),
+
+ # order_by(User.id, Address.id).first(),
+ (User(id=8, addresses=[Address(), Address(), Address()]), Address(id=2)),
+ )
+
+ def test_multiple_with_column_entities(self):
+ sess = create_session()
+
+ eq_(
+ sess.query(User.id).from_self().\
+ add_column(func.count().label('foo')).\
+ group_by(User.id).\
+ order_by(User.id).\
+ from_self().all(),
+ [
+ (7,1), (8, 1), (9, 1), (10, 1)
+ ]
+
+ )
+
+class AddEntityEquivalenceTest(_base.MappedTest, AssertsCompiledSQL):
+ run_setup_mappers = 'once'
+
+ @classmethod
+ def define_tables(cls, metadata):
+ Table('a', metadata,
+ Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('name', String(50)),
+ Column('type', String(20)),
+ Column('bid', Integer, ForeignKey('b.id'))
+ )
+
+ Table('b', metadata,
+ Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('name', String(50)),
+ Column('type', String(20))
+ )
+
+ Table('c', metadata,
+ Column('id', Integer, ForeignKey('b.id'), primary_key=True),
+ Column('age', Integer)
+ )
+
+ Table('d', metadata,
+ Column('id', Integer, ForeignKey('a.id'), primary_key=True),
+ Column('dede', Integer)
+ )
+
+ @classmethod
+ @testing.resolve_artifact_names
+ def setup_classes(cls):
+ class A(_fixtures.Base):
+ pass
+
+ class B(_fixtures.Base):
+ pass
+
+ class C(B):
+ pass
+
+ class D(A):
+ pass
+
+ mapper(A, a,
+ polymorphic_identity='a',
+ polymorphic_on=a.c.type,
+ with_polymorphic= ('*', None),
+ properties={
+ 'link':relation( B, uselist=False, backref='back')
+ })
+ mapper(B, b,
+ polymorphic_identity='b',
+ polymorphic_on=b.c.type,
+ with_polymorphic= ('*', None)
+ )
+ mapper(C, c, inherits=B, polymorphic_identity='c')
+ mapper(D, d, inherits=A, polymorphic_identity='d')
+
+ @classmethod
+ @testing.resolve_artifact_names
+ def insert_data(cls):
+ sess = create_session()
+ sess.add_all([
+ B(name='b1'),
+ A(name='a1', link= C(name='c1',age=3)),
+ C(name='c2',age=6),
+ A(name='a2')
+ ])
+ sess.flush()
+
+ @testing.resolve_artifact_names
+ def test_add_entity_equivalence(self):
+ sess = create_session()
+
+ for q in [
+ sess.query( A,B).join( A.link),
+ sess.query( A).join( A.link).add_entity(B),
+ ]:
+ eq_(
+ q.all(),
+ [(
+ A(bid=2, id=1, name=u'a1', type=u'a'),
+ C(age=3, id=2, name=u'c1', type=u'c')
+ )]
+ )
+
+ for q in [
+ sess.query( B,A).join( B.back),
+ sess.query( B).join( B.back).add_entity(A),
+ sess.query( B).add_entity(A).join( B.back)
+ ]:
+ eq_(
+ q.all(),
+ [(
+ C(age=3, id=2, name=u'c1', type=u'c'),
+ A(bid=2, id=1, name=u'a1', type=u'a')
+ )]
+ )
+
+
+class InstancesTest(QueryTest, AssertsCompiledSQL):
+
+ def test_from_alias(self):
+
+ query = users.select(users.c.id==7).\
+ union(users.select(users.c.id>7)).\
+ alias('ulist').\
+ outerjoin(addresses).\
+ select(use_labels=True,
+ order_by=['ulist.id', addresses.c.id])
+ sess =create_session()
+ q = sess.query(User)
+
+ def go():
+ l = list(q.options(contains_alias('ulist'),
+ contains_eager('addresses')).\
+ instances(query.execute()))
+ assert self.static.user_address_result == l
+ self.assert_sql_count(testing.db, go, 1)
+
+ sess.expunge_all()
+
+ def go():
+ l = q.options(contains_alias('ulist'),
+ contains_eager('addresses')).\
+ from_statement(query).all()
+ assert self.static.user_address_result == l
+ self.assert_sql_count(testing.db, go, 1)
+
+ # better way. use select_from()
+ def go():
+ l = sess.query(User).select_from(query).\
+ options(contains_eager('addresses')).all()
+ assert self.static.user_address_result == l
+ self.assert_sql_count(testing.db, go, 1)
+
+ # same thing, but alias addresses, so that the adapter
+ # generated by select_from() is wrapped within
+ # the adapter created by contains_eager()
+ adalias = addresses.alias()
+ query = users.select(users.c.id==7).\
+ union(users.select(users.c.id>7)).\
+ alias('ulist').\
+ outerjoin(adalias).\
+ select(use_labels=True,
+ order_by=['ulist.id', adalias.c.id])
+ def go():
+ l = sess.query(User).select_from(query).\
+ options(contains_eager('addresses', alias=adalias)).all()
+ assert self.static.user_address_result == l
+ self.assert_sql_count(testing.db, go, 1)
+
+ def test_contains_eager(self):
+ sess = create_session()
+
+ # test that contains_eager suppresses the normal outer join rendering
+ q = sess.query(User).outerjoin(User.addresses).\
+ options(contains_eager(User.addresses)).\
+ order_by(User.id, addresses.c.id)
+ self.assert_compile(q.with_labels().statement,
+ 'SELECT addresses.id AS addresses_id, '
+ 'addresses.user_id AS addresses_user_id, '
+ 'addresses.email_address AS '
+ 'addresses_email_address, users.id AS '
+ 'users_id, users.name AS users_name FROM '
+ 'users LEFT OUTER JOIN addresses ON '
+ 'users.id = addresses.user_id ORDER BY '
+ 'users.id, addresses.id',
+ dialect=default.DefaultDialect())
+
+ def go():
+ assert self.static.user_address_result == q.all()
+ self.assert_sql_count(testing.db, go, 1)
+ sess.expunge_all()
+
+ adalias = addresses.alias()
+ q = sess.query(User).select_from(users.outerjoin(adalias)).options(contains_eager(User.addresses, alias=adalias)).order_by(User.id, adalias.c.id)
+ def go():
+ eq_(self.static.user_address_result, q.order_by(User.id).all())
+ self.assert_sql_count(testing.db, go, 1)
+ sess.expunge_all()
+
+ selectquery = users.outerjoin(addresses).select(users.c.id<10, use_labels=True, order_by=[users.c.id, addresses.c.id])
+ q = sess.query(User)
+
+ def go():
+ l = list(q.options(contains_eager('addresses')).instances(selectquery.execute()))
+ assert self.static.user_address_result[0:3] == l
+ self.assert_sql_count(testing.db, go, 1)
+
+ sess.expunge_all()
+
+ def go():
+ l = list(q.options(contains_eager(User.addresses)).instances(selectquery.execute()))
+ assert self.static.user_address_result[0:3] == l
+ self.assert_sql_count(testing.db, go, 1)
+ sess.expunge_all()
+
+ def go():
+ l = q.options(contains_eager('addresses')).from_statement(selectquery).all()
+ assert self.static.user_address_result[0:3] == l
+ self.assert_sql_count(testing.db, go, 1)
+
+ def test_contains_eager_alias(self):
+ adalias = addresses.alias('adalias')
+ selectquery = users.outerjoin(adalias).select(use_labels=True, order_by=[users.c.id, adalias.c.id])
+ sess = create_session()
+ q = sess.query(User)
+
+ # string alias name
+ def go():
+ l = list(q.options(contains_eager('addresses', alias="adalias")).instances(selectquery.execute()))
+ assert self.static.user_address_result == l
+ self.assert_sql_count(testing.db, go, 1)
+ sess.expunge_all()
+
+ # expression.Alias object
+ def go():
+ l = list(q.options(contains_eager('addresses', alias=adalias)).instances(selectquery.execute()))
+ assert self.static.user_address_result == l
+ self.assert_sql_count(testing.db, go, 1)
+
+ sess.expunge_all()
+
+ # Aliased object
+ adalias = aliased(Address)
+ def go():
+ l = q.options(contains_eager('addresses', alias=adalias)).outerjoin(adalias, User.addresses).order_by(User.id, adalias.id)
+ assert self.static.user_address_result == l.all()
+ self.assert_sql_count(testing.db, go, 1)
+ sess.expunge_all()
+
+ oalias = orders.alias('o1')
+ ialias = items.alias('i1')
+ query = users.outerjoin(oalias).outerjoin(order_items).outerjoin(ialias).select(use_labels=True).order_by(users.c.id, oalias.c.id, ialias.c.id)
+ q = create_session().query(User)
+ # test using string alias with more than one level deep
+ def go():
+ l = list(q.options(contains_eager('orders', alias='o1'), contains_eager('orders.items', alias='i1')).instances(query.execute()))
+ assert self.static.user_order_result == l
+ self.assert_sql_count(testing.db, go, 1)
+
+ sess.expunge_all()
+
+ # test using Alias with more than one level deep
+ def go():
+ l = list(q.options(contains_eager('orders', alias=oalias), contains_eager('orders.items', alias=ialias)).instances(query.execute()))
+ assert self.static.user_order_result == l
+ self.assert_sql_count(testing.db, go, 1)
+ sess.expunge_all()
+
+ # test using Aliased with more than one level deep
+ oalias = aliased(Order)
+ ialias = aliased(Item)
+ def go():
+ l = q.options(contains_eager(User.orders, alias=oalias),
+ contains_eager(User.orders, Order.items, alias=ialias)).\
+ outerjoin(oalias, User.orders).\
+ outerjoin(ialias, oalias.items).order_by(User.id, oalias.id, ialias.id)
+ assert self.static.user_order_result == l.all()
+ self.assert_sql_count(testing.db, go, 1)
+ sess.expunge_all()
+
+ def test_mixed_eager_contains_with_limit(self):
+ sess = create_session()
+
+ q = sess.query(User)
+ def go():
+ # outerjoin to User.orders, offset 1/limit 2 so we get user
+ # 7 + second two orders. then joinedload the addresses.
+ # User + Order columns go into the subquery, address left
+ # outer joins to the subquery, joinedloader for User.orders
+ # applies context.adapter to result rows. This was
+ # [ticket:1180].
+
+ l = \
+ q.outerjoin(User.orders).options(joinedload(User.addresses),
+ contains_eager(User.orders)).order_by(User.id,
+ Order.id).offset(1).limit(2).all()
+ eq_(l, [User(id=7,
+ addresses=[Address(email_address=u'jack@bean.com',
+ user_id=7, id=1)], name=u'jack',
+ orders=[Order(address_id=1, user_id=7,
+ description=u'order 3', isopen=1, id=3),
+ Order(address_id=None, user_id=7, description=u'order 5'
+ , isopen=0, id=5)])])
+
+ self.assert_sql_count(testing.db, go, 1)
+ sess.expunge_all()
+
+ def go():
+
+ # same as above, except Order is aliased, so two adapters
+ # are applied by the eager loader
+
+ oalias = aliased(Order)
+ l = q.outerjoin(oalias, User.orders).\
+ options(joinedload(User.addresses),
+ contains_eager(User.orders, alias=oalias)).\
+ order_by(User.id, oalias.id).\
+ offset(1).limit(2).all()
+ eq_(l, [User(id=7,
+ addresses=[Address(email_address=u'jack@bean.com',
+ user_id=7, id=1)], name=u'jack',
+ orders=[Order(address_id=1, user_id=7,
+ description=u'order 3', isopen=1, id=3),
+ Order(address_id=None, user_id=7, description=u'order 5'
+ , isopen=0, id=5)])])
+
+ self.assert_sql_count(testing.db, go, 1)
+
+
+class MixedEntitiesTest(QueryTest, AssertsCompiledSQL):
+
+ def test_values(self):
+ sess = create_session()
+
+ assert list(sess.query(User).values()) == list()
+
+ sel = users.select(User.id.in_([7, 8])).alias()
+ q = sess.query(User)
+ q2 = q.select_from(sel).values(User.name)
+ eq_(list(q2), [(u'jack',), (u'ed',)])
+
+ q = sess.query(User)
+ q2 = q.order_by(User.id).\
+ values(User.name, User.name + " " + cast(User.id, String(50)))
+ eq_(
+ list(q2),
+ [(u'jack', u'jack 7'), (u'ed', u'ed 8'),
+ (u'fred', u'fred 9'), (u'chuck', u'chuck 10')]
+ )
+
+ q2 = q.join('addresses').\
+ filter(User.name.like('%e%')).\
+ order_by(User.id, Address.id).\
+ values(User.name, Address.email_address)
+ eq_(list(q2),
+ [(u'ed', u'ed@wood.com'), (u'ed', u'ed@bettyboop.com'),
+ (u'ed', u'ed@lala.com'), (u'fred', u'fred@fred.com')])
+
+ q2 = q.join('addresses').\
+ filter(User.name.like('%e%')).\
+ order_by(desc(Address.email_address)).\
+ slice(1, 3).values(User.name, Address.email_address)
+ eq_(list(q2), [(u'ed', u'ed@wood.com'), (u'ed', u'ed@lala.com')])
+
+ adalias = aliased(Address)
+ q2 = q.join(adalias, 'addresses').\
+ filter(User.name.like('%e%')).\
+ values(User.name, adalias.email_address)
+ eq_(list(q2), [(u'ed', u'ed@wood.com'), (u'ed', u'ed@bettyboop.com'),
+ (u'ed', u'ed@lala.com'), (u'fred', u'fred@fred.com')])
+
+ q2 = q.values(func.count(User.name))
+ assert q2.next() == (4,)
+
+ q2 = q.select_from(sel).filter(User.id==8).values(User.name, sel.c.name, User.name)
+ eq_(list(q2), [(u'ed', u'ed', u'ed')])
+
+ # using User.xxx is alised against "sel", so this query returns nothing
+ q2 = q.select_from(sel).\
+ filter(User.id==8).\
+ filter(User.id>sel.c.id).values(User.name, sel.c.name, User.name)
+ eq_(list(q2), [])
+
+ # whereas this uses users.c.xxx, is not aliased and creates a new join
+ q2 = q.select_from(sel).\
+ filter(users.c.id==8).\
+ filter(users.c.id>sel.c.id).values(users.c.name, sel.c.name, User.name)
+ eq_(list(q2), [(u'ed', u'jack', u'jack')])
+
+ @testing.fails_on('mssql', 'FIXME: unknown')
+ def test_values_specific_order_by(self):
+ sess = create_session()
+
+ assert list(sess.query(User).values()) == list()
+
+ sel = users.select(User.id.in_([7, 8])).alias()
+ q = sess.query(User)
+ u2 = aliased(User)
+ q2 = q.select_from(sel).\
+ filter(u2.id>1).\
+ order_by(User.id, sel.c.id, u2.id).\
+ values(User.name, sel.c.name, u2.name)
+ eq_(list(q2), [(u'jack', u'jack', u'jack'), (u'jack', u'jack', u'ed'),
+ (u'jack', u'jack', u'fred'), (u'jack', u'jack', u'chuck'),
+ (u'ed', u'ed', u'jack'), (u'ed', u'ed', u'ed'),
+ (u'ed', u'ed', u'fred'), (u'ed', u'ed', u'chuck')])
+
+ @testing.fails_on('mssql', 'FIXME: unknown')
+ @testing.fails_on('oracle',
+ "Oracle doesn't support boolean expressions as "
+ "columns")
+ @testing.fails_on('postgresql+pg8000',
+ "pg8000 parses the SQL itself before passing on "
+ "to PG, doesn't parse this")
+ @testing.fails_on('postgresql+zxjdbc',
+ "zxjdbc parses the SQL itself before passing on "
+ "to PG, doesn't parse this")
+ def test_values_with_boolean_selects(self):
+ """Tests a values clause that works with select boolean
+ evaluations"""
+ sess = create_session()
+
+ q = sess.query(User)
+ q2 = q.group_by(User.name.like('%j%')).\
+ order_by(desc(User.name.like('%j%'))).\
+ values(User.name.like('%j%'), func.count(User.name.like('%j%')))
+ eq_(list(q2), [(True, 1), (False, 3)])
+
+ q2 = q.order_by(desc(User.name.like('%j%'))).values(User.name.like('%j%'))
+ eq_(list(q2), [(True,), (False,), (False,), (False,)])
+
+
+ def test_correlated_subquery(self):
+ """test that a subquery constructed from ORM attributes doesn't leak out
+ those entities to the outermost query.
+
+ """
+ sess = create_session()
+
+ subq = select([func.count()]).\
+ where(User.id==Address.user_id).\
+ correlate(users).\
+ label('count')
+
+ # we don't want Address to be outside of the subquery here
+ eq_(
+ list(sess.query(User, subq)[0:3]),
+ [(User(id=7,name=u'jack'), 1), (User(id=8,name=u'ed'), 3),
+ (User(id=9,name=u'fred'), 1)]
+ )
+
+ # same thing without the correlate, as it should
+ # not be needed
+ subq = select([func.count()]).\
+ where(User.id==Address.user_id).\
+ label('count')
+
+ # we don't want Address to be outside of the subquery here
+ eq_(
+ list(sess.query(User, subq)[0:3]),
+ [(User(id=7,name=u'jack'), 1), (User(id=8,name=u'ed'), 3),
+ (User(id=9,name=u'fred'), 1)]
+ )
+
+ def test_tuple_labeling(self):
+ sess = create_session()
+
+ # test pickle + all the protocols !
+ for pickled in False, -1, 0, 1, 2:
+ for row in sess.query(User, Address).join(User.addresses).all():
+ if pickled is not False:
+ row = util.pickle.loads(util.pickle.dumps(row, pickled))
+
+ eq_(row.keys(), ['User', 'Address'])
+ eq_(row.User, row[0])
+ eq_(row.Address, row[1])
+
+ for row in sess.query(User.name, User.id.label('foobar')):
+ if pickled is not False:
+ row = util.pickle.loads(util.pickle.dumps(row, pickled))
+ eq_(row.keys(), ['name', 'foobar'])
+ eq_(row.name, row[0])
+ eq_(row.foobar, row[1])
+
+ for row in sess.query(User).values(User.name, User.id.label('foobar')):
+ if pickled is not False:
+ row = util.pickle.loads(util.pickle.dumps(row, pickled))
+ eq_(row.keys(), ['name', 'foobar'])
+ eq_(row.name, row[0])
+ eq_(row.foobar, row[1])
+
+ oalias = aliased(Order)
+ for row in sess.query(User, oalias).join(User.orders).all():
+ if pickled is not False:
+ row = util.pickle.loads(util.pickle.dumps(row, pickled))
+ eq_(row.keys(), ['User'])
+ eq_(row.User, row[0])
+
+ oalias = aliased(Order, name='orders')
+ for row in sess.query(User, oalias).join(User.orders).all():
+ if pickled is not False:
+ row = util.pickle.loads(util.pickle.dumps(row, pickled))
+ eq_(row.keys(), ['User', 'orders'])
+ eq_(row.User, row[0])
+ eq_(row.orders, row[1])
+
+ # test here that first col is not labeled, only
+ # one name in keys, matches correctly
+ for row in sess.query(User.name + 'hoho', User.name):
+ eq_(row.keys(), ['name'])
+ eq_(row[0], row.name + 'hoho')
+
+ if pickled is not False:
+ ret = sess.query(User, Address).join(User.addresses).all()
+ util.pickle.loads(util.pickle.dumps(ret, pickled))
+
+ def test_column_queries(self):
+ sess = create_session()
+
+ eq_(sess.query(User.name).all(), [(u'jack',), (u'ed',), (u'fred',), (u'chuck',)])
+
+ sel = users.select(User.id.in_([7, 8])).alias()
+ q = sess.query(User.name)
+ q2 = q.select_from(sel).all()
+ eq_(list(q2), [(u'jack',), (u'ed',)])
+
+ eq_(sess.query(User.name, Address.email_address).filter(User.id==Address.user_id).all(), [
+ (u'jack', u'jack@bean.com'), (u'ed', u'ed@wood.com'),
+ (u'ed', u'ed@bettyboop.com'), (u'ed', u'ed@lala.com'),
+ (u'fred', u'fred@fred.com')
+ ])
+
+ eq_(sess.query(User.name, func.count(Address.email_address)).\
+ outerjoin(User.addresses).group_by(User.id, User.name).\
+ order_by(User.id).all(),
+ [(u'jack', 1), (u'ed', 3), (u'fred', 1), (u'chuck', 0)]
+ )
+
+ eq_(sess.query(User, func.count(Address.email_address)).\
+ outerjoin(User.addresses).group_by(User).\
+ order_by(User.id).all(),
+ [(User(name='jack',id=7), 1), (User(name='ed',id=8), 3),
+ (User(name='fred',id=9), 1), (User(name='chuck',id=10), 0)]
+ )
+
+ eq_(sess.query(func.count(Address.email_address), User).\
+ outerjoin(User.addresses).group_by(User).\
+ order_by(User.id).all(),
+ [(1, User(name='jack',id=7)), (3, User(name='ed',id=8)),
+ (1, User(name='fred',id=9)), (0, User(name='chuck',id=10))]
+ )
+
+ adalias = aliased(Address)
+ eq_(sess.query(User, func.count(adalias.email_address)).\
+ outerjoin(adalias, 'addresses').group_by(User).\
+ order_by(User.id).all(),
+ [(User(name='jack',id=7), 1), (User(name='ed',id=8), 3),
+ (User(name='fred',id=9), 1), (User(name='chuck',id=10), 0)]
+ )
+
+ eq_(sess.query(func.count(adalias.email_address), User).\
+ outerjoin(adalias, User.addresses).group_by(User).\
+ order_by(User.id).all(),
+ [(1, User(name=u'jack',id=7)), (3, User(name=u'ed',id=8)),
+ (1, User(name=u'fred',id=9)), (0, User(name=u'chuck',id=10))]
+ )
+
+ # select from aliasing + explicit aliasing
+ eq_(
+ sess.query(User, adalias.email_address, adalias.id).\
+ outerjoin(adalias, User.addresses).\
+ from_self(User, adalias.email_address).\
+ order_by(User.id, adalias.id).all(),
+ [
+ (User(name=u'jack',id=7), u'jack@bean.com'),
+ (User(name=u'ed',id=8), u'ed@wood.com'),
+ (User(name=u'ed',id=8), u'ed@bettyboop.com'),
+ (User(name=u'ed',id=8), u'ed@lala.com'),
+ (User(name=u'fred',id=9), u'fred@fred.com'),
+ (User(name=u'chuck',id=10), None)
+ ]
+ )
+
+ # anon + select from aliasing
+ eq_(
+ sess.query(User).join(User.addresses, aliased=True).\
+ filter(Address.email_address.like('%ed%')).\
+ from_self().all(),
+ [
+ User(name=u'ed',id=8),
+ User(name=u'fred',id=9),
+ ]
+ )
+
+ # test eager aliasing, with/without select_from aliasing
+ for q in [
+ sess.query(User, adalias.email_address).\
+ outerjoin(adalias, User.addresses).\
+ options(joinedload(User.addresses)).\
+ order_by(User.id, adalias.id).limit(10),
+ sess.query(User, adalias.email_address, adalias.id).\
+ outerjoin(adalias, User.addresses).\
+ from_self(User, adalias.email_address).\
+ options(joinedload(User.addresses)).\
+ order_by(User.id, adalias.id).limit(10),
+ ]:
+ eq_(
+
+ q.all(),
+ [(User(addresses=[
+ Address(user_id=7,email_address=u'jack@bean.com',id=1)],
+ name=u'jack',id=7), u'jack@bean.com'),
+ (User(addresses=[
+ Address(user_id=8,email_address=u'ed@wood.com',id=2),
+ Address(user_id=8,email_address=u'ed@bettyboop.com',id=3),
+ Address(user_id=8,email_address=u'ed@lala.com',id=4)],
+ name=u'ed',id=8), u'ed@wood.com'),
+ (User(addresses=[
+ Address(user_id=8,email_address=u'ed@wood.com',id=2),
+ Address(user_id=8,email_address=u'ed@bettyboop.com',id=3),
+ Address(user_id=8,email_address=u'ed@lala.com',id=4)],name=u'ed',id=8),
+ u'ed@bettyboop.com'),
+ (User(addresses=[
+ Address(user_id=8,email_address=u'ed@wood.com',id=2),
+ Address(user_id=8,email_address=u'ed@bettyboop.com',id=3),
+ Address(user_id=8,email_address=u'ed@lala.com',id=4)],name=u'ed',id=8),
+ u'ed@lala.com'),
+ (User(addresses=[Address(user_id=9,email_address=u'fred@fred.com',id=5)],name=u'fred',id=9),
+ u'fred@fred.com'),
+
+ (User(addresses=[],name=u'chuck',id=10), None)]
+ )
+
+ def test_column_from_limited_joinedload(self):
+ sess = create_session()
+
+ def go():
+ results = sess.query(User).limit(1).\
+ options(joinedload('addresses')).\
+ add_column(User.name).all()
+ eq_(results, [(User(name='jack'), 'jack')])
+ self.assert_sql_count(testing.db, go, 1)
+
+ @testing.fails_on('postgresql+pg8000', "'type oid 705 not mapped to py type' (due to literal)")
+ def test_self_referential(self):
+
+ sess = create_session()
+ oalias = aliased(Order)
+
+ for q in [
+ sess.query(Order, oalias).\
+ filter(Order.user_id==oalias.user_id).filter(Order.user_id==7).\
+ filter(Order.id>oalias.id).order_by(Order.id, oalias.id),
+ sess.query(Order, oalias).from_self().filter(Order.user_id==oalias.user_id).\
+ filter(Order.user_id==7).filter(Order.id>oalias.id).\
+ order_by(Order.id, oalias.id),
+
+ # same thing, but reversed.
+ sess.query(oalias, Order).from_self().filter(oalias.user_id==Order.user_id).\
+ filter(oalias.user_id==7).filter(Order.id<oalias.id).\
+ order_by(oalias.id, Order.id),
+
+ # here we go....two layers of aliasing
+ sess.query(Order, oalias).filter(Order.user_id==oalias.user_id).\
+ filter(Order.user_id==7).filter(Order.id>oalias.id).\
+ from_self().order_by(Order.id, oalias.id).\
+ limit(10).options(joinedload(Order.items)),
+
+ # gratuitous four layers
+ sess.query(Order, oalias).filter(Order.user_id==oalias.user_id).\
+ filter(Order.user_id==7).filter(Order.id>oalias.id).from_self().\
+ from_self().from_self().order_by(Order.id, oalias.id).\
+ limit(10).options(joinedload(Order.items)),
+
+ ]:
+
+ eq_(
+ q.all(),
+ [
+ (Order(address_id=1,description=u'order 3',isopen=1,user_id=7,id=3),
+ Order(address_id=1,description=u'order 1',isopen=0,user_id=7,id=1)),
+ (Order(address_id=None,description=u'order 5',isopen=0,user_id=7,id=5),
+ Order(address_id=1,description=u'order 1',isopen=0,user_id=7,id=1)),
+ (Order(address_id=None,description=u'order 5',isopen=0,user_id=7,id=5),
+ Order(address_id=1,description=u'order 3',isopen=1,user_id=7,id=3))
+ ]
+ )
+
+
+ # ensure column expressions are taken from inside the subquery, not restated at the top
+ q = sess.query(Order.id, Order.description, literal_column("'q'").label('foo')).\
+ filter(Order.description == u'order 3').from_self()
+ self.assert_compile(q,
+ "SELECT anon_1.orders_id AS "
+ "anon_1_orders_id, anon_1.orders_descriptio"
+ "n AS anon_1_orders_description, "
+ "anon_1.foo AS anon_1_foo FROM (SELECT "
+ "orders.id AS orders_id, "
+ "orders.description AS orders_description, "
+ "'q' AS foo FROM orders WHERE "
+ "orders.description = :description_1) AS "
+ "anon_1", use_default_dialect=True)
+ eq_(
+ q.all(),
+ [(3, u'order 3', 'q')]
+ )
+
+
+ def test_multi_mappers(self):
+
+ test_session = create_session()
+
+ (user7, user8, user9, user10) = test_session.query(User).all()
+ (address1, address2, address3, address4, address5) = \
+ test_session.query(Address).all()
+
+ expected = [(user7, address1),
+ (user8, address2),
+ (user8, address3),
+ (user8, address4),
+ (user9, address5),
+ (user10, None)]
+
+ sess = create_session()
+
+ selectquery = users.outerjoin(addresses).select(use_labels=True, order_by=[users.c.id, addresses.c.id])
+ eq_(list(sess.query(User, Address).instances(selectquery.execute())), expected)
+ sess.expunge_all()
+
+ for address_entity in (Address, aliased(Address)):
+ q = sess.query(User).add_entity(address_entity).\
+ outerjoin(address_entity, 'addresses').\
+ order_by(User.id, address_entity.id)
+ eq_(q.all(), expected)
+ sess.expunge_all()
+
+ q = sess.query(User).add_entity(address_entity)
+ q = q.join(address_entity, 'addresses')
+ q = q.filter_by(email_address='ed@bettyboop.com')
+ eq_(q.all(), [(user8, address3)])
+ sess.expunge_all()
+
+ q = sess.query(User, address_entity).join(address_entity, 'addresses').\
+ filter_by(email_address='ed@bettyboop.com')
+ eq_(q.all(), [(user8, address3)])
+ sess.expunge_all()
+
+ q = sess.query(User, address_entity).join(address_entity, 'addresses').\
+ options(joinedload('addresses')).\
+ filter_by(email_address='ed@bettyboop.com')
+ eq_(list(util.OrderedSet(q.all())), [(user8, address3)])
+ sess.expunge_all()
+
+ def test_aliased_multi_mappers(self):
+ sess = create_session()
+
+ (user7, user8, user9, user10) = sess.query(User).all()
+ (address1, address2, address3, address4, address5) = sess.query(Address).all()
+
+ expected = [(user7, address1),
+ (user8, address2),
+ (user8, address3),
+ (user8, address4),
+ (user9, address5),
+ (user10, None)]
+
+ q = sess.query(User)
+ adalias = addresses.alias('adalias')
+ q = q.add_entity(Address, alias=adalias).select_from(users.outerjoin(adalias))
+ l = q.order_by(User.id, adalias.c.id).all()
+ assert l == expected
+
+ sess.expunge_all()
+
+ q = sess.query(User).add_entity(Address, alias=adalias)
+ l = q.select_from(users.outerjoin(adalias)).filter(adalias.c.email_address=='ed@bettyboop.com').all()
+ assert l == [(user8, address3)]
+
+ def test_with_entities(self):
+ sess = create_session()
+
+ q = sess.query(User).filter(User.id==7).order_by(User.name)
+
+ self.assert_compile(
+ q.with_entities(User.id,Address).\
+ filter(Address.user_id == User.id),
+ 'SELECT users.id AS users_id, addresses.id '
+ 'AS addresses_id, addresses.user_id AS '
+ 'addresses_user_id, addresses.email_address'
+ ' AS addresses_email_address FROM users, '
+ 'addresses WHERE users.id = :id_1 AND '
+ 'addresses.user_id = users.id ORDER BY '
+ 'users.name',
+ use_default_dialect=True)
+
+
+ def test_multi_columns(self):
+ sess = create_session()
+
+ expected = [(u, u.name) for u in sess.query(User).all()]
+
+ for add_col in (User.name, users.c.name):
+ assert sess.query(User).add_column(add_col).all() == expected
+ sess.expunge_all()
+
+ assert_raises(sa_exc.InvalidRequestError, sess.query(User).add_column, object())
+
+ def test_add_multi_columns(self):
+ """test that add_column accepts a FROM clause."""
+
+ sess = create_session()
+
+ eq_(
+ sess.query(User.id).add_column(users).all(),
+ [(7, 7, u'jack'), (8, 8, u'ed'), (9, 9, u'fred'), (10, 10, u'chuck')]
+ )
+
+ def test_multi_columns_2(self):
+ """test aliased/nonalised joins with the usage of add_column()"""
+ sess = create_session()
+
+ (user7, user8, user9, user10) = sess.query(User).all()
+ expected = [(user7, 1),
+ (user8, 3),
+ (user9, 1),
+ (user10, 0)
+ ]
+
+ q = sess.query(User)
+ q = q.group_by(users).order_by(User.id).outerjoin('addresses').\
+ add_column(func.count(Address.id).label('count'))
+ eq_(q.all(), expected)
+ sess.expunge_all()
+
+ adalias = aliased(Address)
+ q = sess.query(User)
+ q = q.group_by(users).order_by(User.id).outerjoin(adalias, 'addresses').\
+ add_column(func.count(adalias.id).label('count'))
+ eq_(q.all(), expected)
+ sess.expunge_all()
+
+ # TODO: figure out why group_by(users) doesn't work here
+ s = select([users, func.count(addresses.c.id).label('count')]).\
+ select_from(users.outerjoin(addresses)).\
+ group_by(*[c for c in users.c]).order_by(User.id)
+ q = sess.query(User)
+ l = q.add_column("count").from_statement(s).all()
+ assert l == expected
+
+
+ def test_raw_columns(self):
+ sess = create_session()
+ (user7, user8, user9, user10) = sess.query(User).all()
+ expected = [
+ (user7, 1, "Name:jack"),
+ (user8, 3, "Name:ed"),
+ (user9, 1, "Name:fred"),
+ (user10, 0, "Name:chuck")]
+
+ adalias = addresses.alias()
+ q = create_session().query(User).add_column(func.count(adalias.c.id))\
+ .add_column(("Name:" + users.c.name)).outerjoin(adalias, 'addresses')\
+ .group_by(users).order_by(users.c.id)
+
+ assert q.all() == expected
+
+ # test with a straight statement
+ s = select([users, func.count(addresses.c.id).label('count'),
+ ("Name:" + users.c.name).label('concat')],
+ from_obj=[users.outerjoin(addresses)],
+ group_by=[c for c in users.c], order_by=[users.c.id])
+ q = create_session().query(User)
+ l = q.add_column("count").add_column("concat").from_statement(s).all()
+ assert l == expected
+
+ sess.expunge_all()
+
+ # test with select_from()
+ q = create_session().query(User).add_column(func.count(addresses.c.id))\
+ .add_column(("Name:" + users.c.name)).select_from(users.outerjoin(addresses))\
+ .group_by(users).order_by(users.c.id)
+
+ assert q.all() == expected
+ sess.expunge_all()
+
+ q = create_session().query(User).add_column(func.count(addresses.c.id))\
+ .add_column(("Name:" + users.c.name)).outerjoin('addresses')\
+ .group_by(users).order_by(users.c.id)
+
+ assert q.all() == expected
+ sess.expunge_all()
+
+ q = create_session().query(User).add_column(func.count(adalias.c.id))\
+ .add_column(("Name:" + users.c.name)).outerjoin(adalias, 'addresses')\
+ .group_by(users).order_by(users.c.id)
+
+ assert q.all() == expected
+ sess.expunge_all()
+
+class SelectFromTest(QueryTest, AssertsCompiledSQL):
+ run_setup_mappers = None
+
+ def test_replace_with_select(self):
+ mapper(User, users, properties = {
+ 'addresses':relationship(Address)
+ })
+ mapper(Address, addresses)
+
+ sel = users.select(users.c.id.in_([7, 8])).alias()
+ sess = create_session()
+
+ eq_(sess.query(User).select_from(sel).all(), [User(id=7), User(id=8)])
+
+ eq_(sess.query(User).select_from(sel).filter(User.id==8).all(), [User(id=8)])
+
+ eq_(sess.query(User).select_from(sel).order_by(desc(User.name)).all(), [
+ User(name='jack',id=7), User(name='ed',id=8)
+ ])
+
+ eq_(sess.query(User).select_from(sel).order_by(asc(User.name)).all(), [
+ User(name='ed',id=8), User(name='jack',id=7)
+ ])
+
+ eq_(sess.query(User).select_from(sel).options(joinedload('addresses')).first(),
+ User(name='jack', addresses=[Address(id=1)])
+ )
+
+ def test_join_mapper_order_by(self):
+ """test that mapper-level order_by is adapted to a selectable."""
+
+ mapper(User, users, order_by=users.c.id)
+
+ sel = users.select(users.c.id.in_([7, 8]))
+ sess = create_session()
+
+ eq_(sess.query(User).select_from(sel).all(),
+ [
+ User(name='jack',id=7), User(name='ed',id=8)
+ ]
+ )
+
+ def test_differentiate_self_external(self):
+ """test some different combinations of joining a table to a subquery of itself."""
+
+ mapper(User, users)
+
+ sess = create_session()
+
+ sel = sess.query(User).filter(User.id.in_([7, 8])).subquery()
+ ualias = aliased(User)
+
+ self.assert_compile(
+ sess.query(User).join(sel, User.id>sel.c.id),
+ "SELECT users.id AS users_id, users.name AS users_name FROM "
+ "users JOIN (SELECT users.id AS id, users.name AS name FROM "
+ "users WHERE users.id IN (:id_1, :id_2)) AS anon_1 ON users.id > anon_1.id",
+ use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(ualias).select_from(sel).filter(ualias.id>sel.c.id),
+ "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM "
+ "users AS users_1, (SELECT users.id AS id, users.name AS name FROM "
+ "users WHERE users.id IN (:id_1, :id_2)) AS anon_1 WHERE users_1.id > anon_1.id",
+ use_default_dialect=True
+ )
+
+ # these two are essentially saying, "join ualias to ualias", so an
+ # error is raised. join() deals with entities, not what's in
+ # select_from().
+ assert_raises(sa_exc.InvalidRequestError,
+ sess.query(ualias).select_from(sel).join, ualias, ualias.id>sel.c.id
+ )
+
+ assert_raises(sa_exc.InvalidRequestError,
+ sess.query(ualias).select_from(sel).join, ualias, ualias.id>User.id
+ )
+
+ salias = aliased(User, sel)
+ self.assert_compile(
+ sess.query(salias).join(ualias, ualias.id>salias.id),
+ "SELECT anon_1.id AS anon_1_id, anon_1.name AS anon_1_name FROM "
+ "(SELECT users.id AS id, users.name AS name FROM users WHERE users.id "
+ "IN (:id_1, :id_2)) AS anon_1 JOIN users AS users_1 ON users_1.id > anon_1.id",
+ use_default_dialect=True
+ )
+
+
+ # this one uses an explicit join(left, right, onclause) so works
+ self.assert_compile(
+ sess.query(ualias).select_from(join(sel, ualias, ualias.id>sel.c.id)),
+ "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM "
+ "(SELECT users.id AS id, users.name AS name FROM users WHERE users.id "
+ "IN (:id_1, :id_2)) AS anon_1 JOIN users AS users_1 ON users_1.id > anon_1.id",
+ use_default_dialect=True
+ )
+
+
+
+ def test_join_no_order_by(self):
+ mapper(User, users)
+
+ sel = users.select(users.c.id.in_([7, 8]))
+ sess = create_session()
+
+ eq_(sess.query(User).select_from(sel).all(),
+ [
+ User(name='jack',id=7), User(name='ed',id=8)
+ ]
+ )
+
+ def test_join(self):
+ mapper(User, users, properties = {
+ 'addresses':relationship(Address)
+ })
+ mapper(Address, addresses)
+
+ sel = users.select(users.c.id.in_([7, 8]))
+ sess = create_session()
+
+ eq_(sess.query(User).select_from(sel).join('addresses').
+ add_entity(Address).order_by(User.id).order_by(Address.id).all(),
+ [
+ (User(name='jack',id=7), Address(user_id=7,email_address='jack@bean.com',id=1)),
+ (User(name='ed',id=8), Address(user_id=8,email_address='ed@wood.com',id=2)),
+ (User(name='ed',id=8), Address(user_id=8,email_address='ed@bettyboop.com',id=3)),
+ (User(name='ed',id=8), Address(user_id=8,email_address='ed@lala.com',id=4))
+ ]
+ )
+
+ adalias = aliased(Address)
+ eq_(sess.query(User).select_from(sel).join(adalias, 'addresses').
+ add_entity(adalias).order_by(User.id).order_by(adalias.id).all(),
+ [
+ (User(name='jack',id=7), Address(user_id=7,email_address='jack@bean.com',id=1)),
+ (User(name='ed',id=8), Address(user_id=8,email_address='ed@wood.com',id=2)),
+ (User(name='ed',id=8), Address(user_id=8,email_address='ed@bettyboop.com',id=3)),
+ (User(name='ed',id=8), Address(user_id=8,email_address='ed@lala.com',id=4))
+ ]
+ )
+
+
+ def test_more_joins(self):
+ mapper(User, users, properties={
+ 'orders':relationship(Order, backref='user'), # o2m, m2o
+ })
+ mapper(Order, orders, properties={
+ 'items':relationship(Item, secondary=order_items,
+ order_by=items.c.id), #m2m
+ })
+ mapper(Item, items, properties={
+ 'keywords':relationship(Keyword, secondary=item_keywords,
+ order_by=keywords.c.id) #m2m
+ })
+ mapper(Keyword, keywords)
+
+ sess = create_session()
+ sel = users.select(users.c.id.in_([7, 8]))
+
+ eq_(sess.query(User).select_from(sel).\
+ join('orders', 'items', 'keywords').\
+ filter(Keyword.name.in_(['red', 'big', 'round'])).\
+ all(),
+ [
+ User(name=u'jack',id=7)
+ ])
+
+ eq_(sess.query(User).select_from(sel).\
+ join('orders', 'items', 'keywords', aliased=True).\
+ filter(Keyword.name.in_(['red', 'big', 'round'])).\
+ all(),
+ [
+ User(name=u'jack',id=7)
+ ])
+
+ def go():
+ eq_(
+ sess.query(User).select_from(sel).
+ options(joinedload_all('orders.items.keywords')).
+ join('orders', 'items', 'keywords', aliased=True).
+ filter(Keyword.name.in_(['red', 'big', 'round'])).\
+ all(),
+ [
+ User(name=u'jack',orders=[
+ Order(description=u'order 1',items=[
+ Item(description=u'item 1',
+ keywords=[
+ Keyword(name=u'red'),
+ Keyword(name=u'big'),
+ Keyword(name=u'round')
+ ]),
+ Item(description=u'item 2',
+ keywords=[
+ Keyword(name=u'red',id=2),
+ Keyword(name=u'small',id=5),
+ Keyword(name=u'square')
+ ]),
+ Item(description=u'item 3',
+ keywords=[
+ Keyword(name=u'green',id=3),
+ Keyword(name=u'big',id=4),
+ Keyword(name=u'round',id=6)])
+ ]),
+ Order(description=u'order 3',items=[
+ Item(description=u'item 3',
+ keywords=[
+ Keyword(name=u'green',id=3),
+ Keyword(name=u'big',id=4),
+ Keyword(name=u'round',id=6)
+ ]),
+ Item(description=u'item 4',keywords=[],id=4),
+ Item(description=u'item 5',keywords=[],id=5)
+ ]),
+ Order(description=u'order 5',
+ items=[
+ Item(description=u'item 5',keywords=[])])
+ ])
+ ])
+ self.assert_sql_count(testing.db, go, 1)
+
+ sess.expunge_all()
+ sel2 = orders.select(orders.c.id.in_([1,2,3]))
+ eq_(sess.query(Order).select_from(sel2).\
+ join('items', 'keywords').\
+ filter(Keyword.name == 'red').\
+ order_by(Order.id).all(), [
+ Order(description=u'order 1',id=1),
+ Order(description=u'order 2',id=2),
+ ])
+ eq_(sess.query(Order).select_from(sel2).\
+ join('items', 'keywords', aliased=True).\
+ filter(Keyword.name == 'red').\
+ order_by(Order.id).all(), [
+ Order(description=u'order 1',id=1),
+ Order(description=u'order 2',id=2),
+ ])
+
+
+ def test_replace_with_eager(self):
+ mapper(User, users, properties = {
+ 'addresses':relationship(Address, order_by=addresses.c.id)
+ })
+ mapper(Address, addresses)
+
+ sel = users.select(users.c.id.in_([7, 8]))
+ sess = create_session()
+
+ def go():
+ eq_(sess.query(User).options(joinedload('addresses')).select_from(sel).order_by(User.id).all(),
+ [
+ User(id=7, addresses=[Address(id=1)]),
+ User(id=8, addresses=[Address(id=2), Address(id=3), Address(id=4)])
+ ]
+ )
+ self.assert_sql_count(testing.db, go, 1)
+ sess.expunge_all()
+
+ def go():
+ eq_(sess.query(User).options(joinedload('addresses')).select_from(sel).filter(User.id==8).order_by(User.id).all(),
+ [User(id=8, addresses=[Address(id=2), Address(id=3), Address(id=4)])]
+ )
+ self.assert_sql_count(testing.db, go, 1)
+ sess.expunge_all()
+
+ def go():
+ eq_(sess.query(User).options(joinedload('addresses')).select_from(sel).order_by(User.id)[1], User(id=8, addresses=[Address(id=2), Address(id=3), Address(id=4)]))
+ self.assert_sql_count(testing.db, go, 1)
+
+class CustomJoinTest(QueryTest):
+ run_setup_mappers = None
+
+ def test_double_same_mappers(self):
+ """test aliasing of joins with a custom join condition"""
+ mapper(Address, addresses)
+ mapper(Order, orders, properties={
+ 'items':relationship(Item, secondary=order_items, lazy='select', order_by=items.c.id),
+ })
+ mapper(Item, items)
+ mapper(User, users, properties = dict(
+ addresses = relationship(Address, lazy='select'),
+ open_orders = relationship(Order, primaryjoin = and_(orders.c.isopen == 1, users.c.id==orders.c.user_id), lazy='select'),
+ closed_orders = relationship(Order, primaryjoin = and_(orders.c.isopen == 0, users.c.id==orders.c.user_id), lazy='select')
+ ))
+ q = create_session().query(User)
+
+ eq_(
+ q.join('open_orders', 'items', aliased=True).filter(Item.id==4).\
+ join('closed_orders', 'items', aliased=True).filter(Item.id==3).all(),
+ [User(id=7)]
+ )
+
+class ExternalColumnsTest(QueryTest):
+ """test mappers with SQL-expressions added as column properties."""
+
+ run_setup_mappers = None
+
+ def test_external_columns_bad(self):
+
+ assert_raises_message(sa_exc.ArgumentError, "not represented in the mapper's table", mapper, User, users, properties={
+ 'concat': (users.c.id * 2),
+ })
+ clear_mappers()
+
+ def test_external_columns(self):
+ """test querying mappings that reference external columns or selectables."""
+
+ mapper(User, users, properties={
+ 'concat': column_property((users.c.id * 2)),
+ 'count': column_property(
+ select([func.count(addresses.c.id)], users.c.id==addresses.c.user_id).\
+ correlate(users).\
+ as_scalar())
+ })
+
+ mapper(Address, addresses, properties={
+ 'user':relationship(User)
+ })
+
+ sess = create_session()
+
+ sess.query(Address).options(joinedload('user')).all()
+
+ eq_(sess.query(User).all(),
+ [
+ User(id=7, concat=14, count=1),
+ User(id=8, concat=16, count=3),
+ User(id=9, concat=18, count=1),
+ User(id=10, concat=20, count=0),
+ ]
+ )
+
+ address_result = [
+ Address(id=1, user=User(id=7, concat=14, count=1)),
+ Address(id=2, user=User(id=8, concat=16, count=3)),
+ Address(id=3, user=User(id=8, concat=16, count=3)),
+ Address(id=4, user=User(id=8, concat=16, count=3)),
+ Address(id=5, user=User(id=9, concat=18, count=1))
+ ]
+ eq_(sess.query(Address).all(), address_result)
+
+ # run the eager version twice to test caching of aliased clauses
+ for x in range(2):
+ sess.expunge_all()
+ def go():
+ eq_(sess.query(Address).\
+ options(joinedload('user')).\
+ order_by(Address.id).all(),
+ address_result)
+ self.assert_sql_count(testing.db, go, 1)
+
+ ualias = aliased(User)
+ eq_(
+ sess.query(Address, ualias).join(ualias, 'user').all(),
+ [(address, address.user) for address in address_result]
+ )
+
+ eq_(
+ sess.query(Address, ualias.count).\
+ join(ualias, 'user').\
+ join('user', aliased=True).\
+ order_by(Address.id).all(),
+ [
+ (Address(id=1), 1),
+ (Address(id=2), 3),
+ (Address(id=3), 3),
+ (Address(id=4), 3),
+ (Address(id=5), 1)
+ ]
+ )
+
+ eq_(sess.query(Address, ualias.concat, ualias.count).
+ join(ualias, 'user').
+ join('user', aliased=True).order_by(Address.id).all(),
+ [
+ (Address(id=1), 14, 1),
+ (Address(id=2), 16, 3),
+ (Address(id=3), 16, 3),
+ (Address(id=4), 16, 3),
+ (Address(id=5), 18, 1)
+ ]
+ )
+
+ ua = aliased(User)
+ eq_(sess.query(Address, ua.concat, ua.count).
+ select_from(join(Address, ua, 'user')).
+ options(joinedload(Address.user)).order_by(Address.id).all(),
+ [
+ (Address(id=1, user=User(id=7, concat=14, count=1)), 14, 1),
+ (Address(id=2, user=User(id=8, concat=16, count=3)), 16, 3),
+ (Address(id=3, user=User(id=8, concat=16, count=3)), 16, 3),
+ (Address(id=4, user=User(id=8, concat=16, count=3)), 16, 3),
+ (Address(id=5, user=User(id=9, concat=18, count=1)), 18, 1)
+ ]
+ )
+
+ eq_(list(sess.query(Address).join('user').values(Address.id, User.id, User.concat, User.count)),
+ [(1, 7, 14, 1), (2, 8, 16, 3), (3, 8, 16, 3), (4, 8, 16, 3), (5, 9, 18, 1)]
+ )
+
+ eq_(list(sess.query(Address, ua).select_from(join(Address,ua, 'user')).values(Address.id, ua.id, ua.concat, ua.count)),
+ [(1, 7, 14, 1), (2, 8, 16, 3), (3, 8, 16, 3), (4, 8, 16, 3), (5, 9, 18, 1)]
+ )
+
+ def test_external_columns_joinedload(self):
+ # in this test, we have a subquery on User that accesses "addresses", underneath
+ # an joinedload for "addresses". So the "addresses" alias adapter needs to *not* hit
+ # the "addresses" table within the "user" subquery, but "user" still needs to be adapted.
+ # therefore the long standing practice of eager adapters being "chained" has been removed
+ # since its unnecessary and breaks this exact condition.
+ mapper(User, users, properties={
+ 'addresses':relationship(Address, backref='user', order_by=addresses.c.id),
+ 'concat': column_property((users.c.id * 2)),
+ 'count': column_property(select([func.count(addresses.c.id)], users.c.id==addresses.c.user_id).correlate(users))
+ })
+ mapper(Address, addresses)
+ mapper(Order, orders, properties={
+ 'address':relationship(Address), # m2o
+ })
+
+ sess = create_session()
+ def go():
+ o1 = sess.query(Order).options(joinedload_all('address.user')).get(1)
+ eq_(o1.address.user.count, 1)
+ self.assert_sql_count(testing.db, go, 1)
+
+ sess = create_session()
+ def go():
+ o1 = sess.query(Order).options(joinedload_all('address.user')).first()
+ eq_(o1.address.user.count, 1)
+ self.assert_sql_count(testing.db, go, 1)
+
+class TestOverlyEagerEquivalentCols(_base.MappedTest):
+ @classmethod
+ def define_tables(cls, metadata):
+ global base, sub1, sub2
+ base = Table('base', metadata,
+ Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('data', String(50))
+ )
+
+ sub1 = Table('sub1', metadata,
+ Column('id', Integer, ForeignKey('base.id'), primary_key=True),
+ Column('data', String(50))
+ )
+
+ sub2 = Table('sub2', metadata,
+ Column('id', Integer, ForeignKey('base.id'), ForeignKey('sub1.id'), primary_key=True),
+ Column('data', String(50))
+ )
+
+ def test_equivs(self):
+ class Base(_base.ComparableEntity):
+ pass
+ class Sub1(_base.ComparableEntity):
+ pass
+ class Sub2(_base.ComparableEntity):
+ pass
+
+ mapper(Base, base, properties={
+ 'sub1':relationship(Sub1),
+ 'sub2':relationship(Sub2)
+ })
+
+ mapper(Sub1, sub1)
+ mapper(Sub2, sub2)
+ sess = create_session()
+
+ s11 = Sub1(data='s11')
+ s12 = Sub1(data='s12')
+ s2 = Sub2(data='s2')
+ b1 = Base(data='b1', sub1=[s11], sub2=[])
+ b2 = Base(data='b1', sub1=[s12], sub2=[])
+ sess.add(b1)
+ sess.add(b2)
+ sess.flush()
+
+ # theres an overlapping ForeignKey here, so not much option except
+ # to artifically control the flush order
+ b2.sub2 = [s2]
+ sess.flush()
+
+ q = sess.query(Base).outerjoin('sub2', aliased=True)
+ assert sub1.c.id not in q._filter_aliases.equivalents
+
+ eq_(
+ sess.query(Base).join('sub1').outerjoin('sub2', aliased=True).\
+ filter(Sub1.id==1).one(),
+ b1
+ )
--- /dev/null
+from test.lib.testing import eq_, assert_raises, assert_raises_message
+import operator
+from sqlalchemy import *
+from sqlalchemy import exc as sa_exc, util
+from sqlalchemy.sql import compiler, table, column
+from sqlalchemy.engine import default
+from sqlalchemy.orm import *
+from sqlalchemy.orm import attributes
+
+from test.lib.testing import eq_
+
+import sqlalchemy as sa
+from test.lib import testing, AssertsCompiledSQL, Column, engines
+
+from test.orm import _fixtures
+from test.orm._fixtures import keywords, addresses, Base, \
+ Keyword, FixtureTest, \
+ Dingaling, item_keywords, dingalings, User, items,\
+ orders, Address, users, nodes, \
+ order_items, Item, Order, Node, \
+ composite_pk_table, CompositePk
+
+from test.orm import _base
+
+from sqlalchemy.orm.util import join, outerjoin, with_parent
+
+class QueryTest(_fixtures.FixtureTest):
+ run_setup_mappers = 'once'
+ run_inserts = 'once'
+ run_deletes = None
+
+
+ @classmethod
+ def setup_mappers(cls):
+ mapper(User, users, properties={
+ 'addresses':relationship(Address, backref='user', order_by=addresses.c.id),
+ 'orders':relationship(Order, backref='user', order_by=orders.c.id), # o2m, m2o
+ })
+ mapper(Address, addresses, properties={
+ 'dingaling':relationship(Dingaling, uselist=False, backref="address") #o2o
+ })
+ mapper(Dingaling, dingalings)
+ mapper(Order, orders, properties={
+ 'items':relationship(Item, secondary=order_items, order_by=items.c.id), #m2m
+ 'address':relationship(Address), # m2o
+ })
+ mapper(Item, items, properties={
+ 'keywords':relationship(Keyword, secondary=item_keywords) #m2m
+ })
+ mapper(Keyword, keywords)
+
+ mapper(Node, nodes, properties={
+ 'children':relationship(Node,
+ backref=backref('parent', remote_side=[nodes.c.id])
+ )
+ })
+
+ mapper(CompositePk, composite_pk_table)
+
+ configure_mappers()
+
+class InheritedJoinTest(_base.MappedTest, AssertsCompiledSQL):
+ run_setup_mappers = 'once'
+
+ @classmethod
+ def define_tables(cls, metadata):
+ Table('companies', metadata,
+ Column('company_id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('name', String(50)))
+
+ Table('people', metadata,
+ Column('person_id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('company_id', Integer, ForeignKey('companies.company_id')),
+ Column('name', String(50)),
+ Column('type', String(30)))
+
+ Table('engineers', metadata,
+ Column('person_id', Integer, ForeignKey('people.person_id'), primary_key=True),
+ Column('status', String(30)),
+ Column('engineer_name', String(50)),
+ Column('primary_language', String(50)),
+ )
+
+ Table('machines', metadata,
+ Column('machine_id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('name', String(50)),
+ Column('engineer_id', Integer, ForeignKey('engineers.person_id')))
+
+ Table('managers', metadata,
+ Column('person_id', Integer, ForeignKey('people.person_id'), primary_key=True),
+ Column('status', String(30)),
+ Column('manager_name', String(50))
+ )
+
+ Table('boss', metadata,
+ Column('boss_id', Integer, ForeignKey('managers.person_id'), primary_key=True),
+ Column('golf_swing', String(30)),
+ )
+
+ Table('paperwork', metadata,
+ Column('paperwork_id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('description', String(50)),
+ Column('person_id', Integer, ForeignKey('people.person_id')))
+
+ @classmethod
+ @testing.resolve_artifact_names
+ def setup_classes(cls):
+ class Company(_fixtures.Base):
+ pass
+ class Person(_fixtures.Base):
+ pass
+ class Engineer(Person):
+ pass
+ class Manager(Person):
+ pass
+ class Boss(Manager):
+ pass
+ class Machine(_fixtures.Base):
+ pass
+ class Paperwork(_fixtures.Base):
+ pass
+
+ mapper(Company, companies, properties={
+ 'employees':relationship(Person, order_by=people.c.person_id)
+ })
+
+ mapper(Machine, machines)
+
+ mapper(Person, people,
+ polymorphic_on=people.c.type,
+ polymorphic_identity='person',
+ order_by=people.c.person_id,
+ properties={
+ 'paperwork':relationship(Paperwork, order_by=paperwork.c.paperwork_id)
+ })
+ mapper(Engineer, engineers, inherits=Person, polymorphic_identity='engineer', properties={
+ 'machines':relationship(Machine, order_by=machines.c.machine_id)
+ })
+ mapper(Manager, managers,
+ inherits=Person, polymorphic_identity='manager')
+ mapper(Boss, boss, inherits=Manager, polymorphic_identity='boss')
+ mapper(Paperwork, paperwork)
+
+ @testing.resolve_artifact_names
+ def test_single_prop(self):
+ sess = create_session()
+
+ self.assert_compile(
+ sess.query(Company).join(Company.employees),
+ "SELECT companies.company_id AS companies_company_id, companies.name AS companies_name "
+ "FROM companies JOIN people ON companies.company_id = people.company_id"
+ , use_default_dialect = True
+ )
+
+ @testing.resolve_artifact_names
+ def test_force_via_select_from(self):
+ sess = create_session()
+
+ self.assert_compile(
+ sess.query(Company).\
+ filter(Company.company_id==Engineer.company_id).\
+ filter(Engineer.primary_language=='java'),
+ "SELECT companies.company_id AS companies_company_id, companies.name AS companies_name "
+ "FROM companies, people, engineers "
+ "WHERE companies.company_id = people.company_id AND engineers.primary_language "
+ "= :primary_language_1",
+ use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(Company).select_from(Company, Engineer).\
+ filter(Company.company_id==Engineer.company_id).\
+ filter(Engineer.primary_language=='java'),
+ "SELECT companies.company_id AS companies_company_id, companies.name AS companies_name "
+ "FROM companies, people JOIN engineers ON people.person_id = engineers.person_id "
+ "WHERE companies.company_id = people.company_id AND engineers.primary_language ="
+ " :primary_language_1",
+ use_default_dialect=True
+
+ )
+
+ @testing.resolve_artifact_names
+ def test_single_prop_of_type(self):
+ sess = create_session()
+
+ self.assert_compile(
+ sess.query(Company).join(Company.employees.of_type(Engineer)),
+ "SELECT companies.company_id AS companies_company_id, companies.name AS companies_name "
+ "FROM companies JOIN (SELECT people.person_id AS people_person_id, "
+ "people.company_id AS people_company_id, people.name AS people_name, "
+ "people.type AS people_type, engineers.person_id AS "
+ "engineers_person_id, engineers.status AS engineers_status, "
+ "engineers.engineer_name AS engineers_engineer_name, "
+ "engineers.primary_language AS engineers_primary_language "
+ "FROM people JOIN engineers ON people.person_id = engineers.person_id) AS "
+ "anon_1 ON companies.company_id = anon_1.people_company_id"
+ , use_default_dialect = True
+ )
+
+ @testing.resolve_artifact_names
+ def test_prop_with_polymorphic(self):
+ sess = create_session()
+
+ self.assert_compile(
+ sess.query(Person).with_polymorphic(Manager).
+ join('paperwork').filter(Paperwork.description.like('%review%')),
+ "SELECT people.person_id AS people_person_id, people.company_id AS"
+ " people_company_id, "
+ "people.name AS people_name, people.type AS people_type, managers.person_id "
+ "AS managers_person_id, "
+ "managers.status AS managers_status, managers.manager_name AS "
+ "managers_manager_name FROM people "
+ "LEFT OUTER JOIN managers ON people.person_id = managers.person_id JOIN "
+ "paperwork ON people.person_id = "
+ "paperwork.person_id WHERE paperwork.description LIKE :description_1 "
+ "ORDER BY people.person_id"
+ , use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(Person).with_polymorphic(Manager).
+ join('paperwork', aliased=True).
+ filter(Paperwork.description.like('%review%')),
+ "SELECT people.person_id AS people_person_id, people.company_id AS people_company_id, "
+ "people.name AS people_name, people.type AS people_type, managers.person_id "
+ "AS managers_person_id, "
+ "managers.status AS managers_status, managers.manager_name AS managers_manager_name "
+ "FROM people LEFT OUTER JOIN managers ON people.person_id = managers.person_id JOIN "
+ "paperwork AS paperwork_1 ON people.person_id = paperwork_1.person_id "
+ "WHERE paperwork_1.description LIKE :description_1 ORDER BY people.person_id"
+ , use_default_dialect=True
+ )
+
+ @testing.resolve_artifact_names
+ def test_explicit_polymorphic_join(self):
+ sess = create_session()
+
+ self.assert_compile(
+ sess.query(Company).join(Engineer).filter(Engineer.engineer_name=='vlad'),
+ "SELECT companies.company_id AS companies_company_id, companies.name AS "
+ "companies_name "
+ "FROM companies JOIN (SELECT people.person_id AS people_person_id, "
+ "people.company_id AS "
+ "people_company_id, people.name AS people_name, people.type AS people_type,"
+ " engineers.person_id AS "
+ "engineers_person_id, engineers.status AS engineers_status, "
+ "engineers.engineer_name AS engineers_engineer_name, "
+ "engineers.primary_language AS engineers_primary_language "
+ "FROM people JOIN engineers ON people.person_id = engineers.person_id) "
+ "AS anon_1 ON "
+ "companies.company_id = anon_1.people_company_id "
+ "WHERE anon_1.engineers_engineer_name = :engineer_name_1"
+ , use_default_dialect=True
+ )
+ self.assert_compile(
+ sess.query(Company).join(Engineer, Company.company_id==Engineer.company_id).
+ filter(Engineer.engineer_name=='vlad'),
+ "SELECT companies.company_id AS companies_company_id, companies.name "
+ "AS companies_name "
+ "FROM companies JOIN (SELECT people.person_id AS people_person_id, "
+ "people.company_id AS "
+ "people_company_id, people.name AS people_name, people.type AS "
+ "people_type, engineers.person_id AS "
+ "engineers_person_id, engineers.status AS engineers_status, "
+ "engineers.engineer_name AS engineers_engineer_name, "
+ "engineers.primary_language AS engineers_primary_language "
+ "FROM people JOIN engineers ON people.person_id = engineers.person_id) AS "
+ "anon_1 ON "
+ "companies.company_id = anon_1.people_company_id "
+ "WHERE anon_1.engineers_engineer_name = :engineer_name_1"
+ , use_default_dialect=True
+ )
+
+ @testing.resolve_artifact_names
+ def test_multiple_adaption(self):
+ """test that multiple filter() adapters get chained together "
+ and work correctly within a multiple-entry join()."""
+
+ sess = create_session()
+
+ self.assert_compile(
+ sess.query(Company).join(people.join(engineers), Company.employees).
+ filter(Engineer.name=='dilbert'),
+ "SELECT companies.company_id AS companies_company_id, companies.name AS "
+ "companies_name "
+ "FROM companies JOIN (SELECT people.person_id AS people_person_id, "
+ "people.company_id AS "
+ "people_company_id, people.name AS people_name, people.type AS "
+ "people_type, engineers.person_id "
+ "AS engineers_person_id, engineers.status AS engineers_status, "
+ "engineers.engineer_name AS engineers_engineer_name, "
+ "engineers.primary_language AS engineers_primary_language FROM people "
+ "JOIN engineers ON people.person_id = "
+ "engineers.person_id) AS anon_1 ON companies.company_id = "
+ "anon_1.people_company_id WHERE anon_1.people_name = :name_1"
+ , use_default_dialect = True
+ )
+
+ mach_alias = machines.select()
+ self.assert_compile(
+ sess.query(Company).join(people.join(engineers), Company.employees).
+ join(mach_alias, Engineer.machines, from_joinpoint=True).
+ filter(Engineer.name=='dilbert').filter(Machine.name=='foo'),
+ "SELECT companies.company_id AS companies_company_id, companies.name AS "
+ "companies_name "
+ "FROM companies JOIN (SELECT people.person_id AS people_person_id, "
+ "people.company_id AS "
+ "people_company_id, people.name AS people_name, people.type AS people_type,"
+ " engineers.person_id "
+ "AS engineers_person_id, engineers.status AS engineers_status, "
+ "engineers.engineer_name AS engineers_engineer_name, "
+ "engineers.primary_language AS engineers_primary_language FROM people "
+ "JOIN engineers ON people.person_id = "
+ "engineers.person_id) AS anon_1 ON companies.company_id = "
+ "anon_1.people_company_id JOIN "
+ "(SELECT machines.machine_id AS machine_id, machines.name AS name, "
+ "machines.engineer_id AS engineer_id "
+ "FROM machines) AS anon_2 ON anon_1.engineers_person_id = anon_2.engineer_id "
+ "WHERE anon_1.people_name = :name_1 AND anon_2.name = :name_2"
+ , use_default_dialect = True
+ )
+
+
+
+
+class JoinTest(QueryTest, AssertsCompiledSQL):
+
+ def test_single_name(self):
+ sess = create_session()
+
+ self.assert_compile(
+ sess.query(User).join("orders"),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users JOIN orders ON users.id = orders.user_id"
+ , use_default_dialect = True
+ )
+
+ assert_raises(
+ sa_exc.InvalidRequestError,
+ sess.query(User).join, "user",
+ )
+
+ self.assert_compile(
+ sess.query(User).join("orders", "items"),
+ "SELECT users.id AS users_id, users.name AS users_name FROM users "
+ "JOIN orders ON users.id = orders.user_id JOIN order_items AS order_items_1 "
+ "ON orders.id = order_items_1.order_id JOIN items ON items.id = order_items_1.item_id"
+ , use_default_dialect=True
+ )
+
+ # test overlapping paths. User->orders is used by both joins, but rendered once.
+ self.assert_compile(
+ sess.query(User).join("orders", "items").join("orders", "address"),
+ "SELECT users.id AS users_id, users.name AS users_name FROM users JOIN orders "
+ "ON users.id = orders.user_id JOIN order_items AS order_items_1 ON orders.id = "
+ "order_items_1.order_id JOIN items ON items.id = order_items_1.item_id JOIN addresses "
+ "ON addresses.id = orders.address_id"
+ , use_default_dialect=True
+ )
+
+ def test_multi_tuple_form(self):
+ """test the 'tuple' form of join, now superceded by the two-element join() form.
+
+ Not deprecating this style as of yet.
+
+ """
+
+ sess = create_session()
+
+ #assert_raises(
+ # sa.exc.SADeprecationWarning,
+ # sess.query(User).join, (Order, User.id==Order.user_id)
+ #)
+
+ self.assert_compile(
+ sess.query(User).join((Order, User.id==Order.user_id)),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users JOIN orders ON users.id = orders.user_id",
+ use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(User).join(
+ (Order, User.id==Order.user_id),
+ (Item, Order.items)),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users JOIN orders ON users.id = orders.user_id "
+ "JOIN order_items AS order_items_1 ON orders.id = "
+ "order_items_1.order_id JOIN items ON items.id = "
+ "order_items_1.item_id",
+ use_default_dialect=True
+ )
+
+ # the old "backwards" form
+ self.assert_compile(
+ sess.query(User).join(("orders", Order)),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users JOIN orders ON users.id = orders.user_id",
+ use_default_dialect=True
+ )
+
+ def test_single_prop(self):
+ sess = create_session()
+ self.assert_compile(
+ sess.query(User).join(User.orders),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users JOIN orders ON users.id = orders.user_id"
+ , use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(User).join(Order.user),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM orders JOIN users ON users.id = orders.user_id"
+ , use_default_dialect=True
+ )
+
+ oalias1 = aliased(Order)
+ oalias2 = aliased(Order)
+
+ self.assert_compile(
+ sess.query(User).join(oalias1.user),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM orders AS orders_1 JOIN users ON users.id = orders_1.user_id"
+ , use_default_dialect=True
+ )
+
+ # another nonsensical query. (from [ticket:1537]).
+ # in this case, the contract of "left to right" is honored
+ self.assert_compile(
+ sess.query(User).join(oalias1.user).join(oalias2.user),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM orders AS orders_1 JOIN users ON users.id = orders_1.user_id, "
+ "orders AS orders_2 JOIN users ON users.id = orders_2.user_id"
+ , use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(User).join(User.orders, Order.items),
+ "SELECT users.id AS users_id, users.name AS users_name FROM users "
+ "JOIN orders ON users.id = orders.user_id JOIN order_items AS order_items_1 "
+ "ON orders.id = order_items_1.order_id JOIN items ON items.id = order_items_1.item_id"
+ , use_default_dialect=True
+ )
+
+ ualias = aliased(User)
+ self.assert_compile(
+ sess.query(ualias).join(ualias.orders),
+ "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name "
+ "FROM users AS users_1 JOIN orders ON users_1.id = orders.user_id"
+ , use_default_dialect=True
+ )
+
+ # this query is somewhat nonsensical. the old system didn't render a correct
+ # query for this. In this case its the most faithful to what was asked -
+ # there's no linkage between User.orders and "oalias", so two FROM elements
+ # are generated.
+ oalias = aliased(Order)
+ self.assert_compile(
+ sess.query(User).join(User.orders, oalias.items),
+ "SELECT users.id AS users_id, users.name AS users_name FROM users "
+ "JOIN orders ON users.id = orders.user_id, "
+ "orders AS orders_1 JOIN order_items AS order_items_1 ON orders_1.id = order_items_1.order_id "
+ "JOIN items ON items.id = order_items_1.item_id"
+ , use_default_dialect=True
+ )
+
+ # same as before using an aliased() for User as well
+ ualias = aliased(User)
+ self.assert_compile(
+ sess.query(ualias).join(ualias.orders, oalias.items),
+ "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM users AS users_1 "
+ "JOIN orders ON users_1.id = orders.user_id, "
+ "orders AS orders_1 JOIN order_items AS order_items_1 ON orders_1.id = order_items_1.order_id "
+ "JOIN items ON items.id = order_items_1.item_id"
+ , use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(User).filter(User.name=='ed').from_self().join(User.orders),
+ "SELECT anon_1.users_id AS anon_1_users_id, anon_1.users_name AS anon_1_users_name "
+ "FROM (SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users "
+ "WHERE users.name = :name_1) AS anon_1 JOIN orders ON anon_1.users_id = orders.user_id"
+ , use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(User).join(User.addresses, aliased=True).filter(Address.email_address=='foo'),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users JOIN addresses AS addresses_1 ON users.id = addresses_1.user_id "
+ "WHERE addresses_1.email_address = :email_address_1"
+ , use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(User).join(User.orders, Order.items, aliased=True).filter(Item.id==10),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users JOIN orders AS orders_1 ON users.id = orders_1.user_id "
+ "JOIN order_items AS order_items_1 ON orders_1.id = order_items_1.order_id "
+ "JOIN items AS items_1 ON items_1.id = order_items_1.item_id "
+ "WHERE items_1.id = :id_1"
+ , use_default_dialect=True
+ )
+
+ # test #1 for [ticket:1706]
+ ualias = aliased(User)
+ self.assert_compile(
+ sess.query(ualias).
+ join(oalias1, ualias.orders).\
+ join(Address, ualias.addresses),
+ "SELECT users_1.id AS users_1_id, users_1.name AS "
+ "users_1_name FROM users AS users_1 JOIN orders AS orders_1 "
+ "ON users_1.id = orders_1.user_id JOIN addresses ON users_1.id "
+ "= addresses.user_id"
+ , use_default_dialect=True
+ )
+
+ # test #2 for [ticket:1706]
+ ualias2 = aliased(User)
+ self.assert_compile(
+ sess.query(ualias).
+ join(Address, ualias.addresses).
+ join(ualias2, Address.user).
+ join(Order, ualias.orders),
+ "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM users "
+ "AS users_1 JOIN addresses ON users_1.id = addresses.user_id JOIN users AS users_2 "
+ "ON users_2.id = addresses.user_id JOIN orders ON users_1.id = orders.user_id"
+ , use_default_dialect=True
+ )
+
+ def test_overlapping_paths(self):
+ for aliased in (True,False):
+ # load a user who has an order that contains item id 3 and address id 1 (order 3, owned by jack)
+ result = create_session().query(User).join('orders', 'items', aliased=aliased).\
+ filter_by(id=3).join('orders','address', aliased=aliased).filter_by(id=1).all()
+ assert [User(id=7, name='jack')] == result
+
+ def test_overlapping_paths_outerjoin(self):
+ result = create_session().query(User).outerjoin('orders', 'items').\
+ filter_by(id=3).outerjoin('orders','address').filter_by(id=1).all()
+ assert [User(id=7, name='jack')] == result
+
+ def test_from_joinpoint(self):
+ sess = create_session()
+
+ for oalias,ialias in [(True, True), (False, False), (True, False), (False, True)]:
+ eq_(
+ sess.query(User).join('orders', aliased=oalias).\
+ join('items',
+ from_joinpoint=True,
+ aliased=ialias).\
+ filter(Item.description == 'item 4').all(),
+ [User(name='jack')]
+ )
+
+ # use middle criterion
+ eq_(
+ sess.query(User).join('orders', aliased=oalias).\
+ filter(Order.user_id==9).\
+ join('items', from_joinpoint=True,
+ aliased=ialias).\
+ filter(Item.description=='item 4').all(),
+ []
+ )
+
+ orderalias = aliased(Order)
+ itemalias = aliased(Item)
+ eq_(
+ sess.query(User).join(orderalias, 'orders').
+ join(itemalias, 'items', from_joinpoint=True).
+ filter(itemalias.description == 'item 4').all(),
+ [User(name='jack')]
+ )
+ eq_(
+ sess.query(User).join(orderalias, 'orders').
+ join(itemalias, 'items', from_joinpoint=True).
+ filter(orderalias.user_id==9).\
+ filter(itemalias.description=='item 4').all(),
+ []
+ )
+
+ def test_join_nonmapped_column(self):
+ """test that the search for a 'left' doesn't trip on non-mapped cols"""
+ sess = create_session()
+
+ # intentionally join() with a non-existent "left" side
+ self.assert_compile(
+ sess.query(User.id, literal_column('foo')).join(Order.user),
+ "SELECT users.id AS users_id, foo FROM "
+ "orders JOIN users ON users.id = orders.user_id"
+ , use_default_dialect=True
+ )
+
+
+
+ def test_backwards_join(self):
+ # a more controversial feature. join from
+ # User->Address, but the onclause is Address.user.
+
+ sess = create_session()
+
+ eq_(
+ sess.query(User).join(Address.user).\
+ filter(Address.email_address=='ed@wood.com').all(),
+ [User(id=8,name=u'ed')]
+ )
+
+ # its actually not so controversial if you view it in terms
+ # of multiple entities.
+ eq_(
+ sess.query(User, Address).join(Address.user).filter(Address.email_address=='ed@wood.com').all(),
+ [(User(id=8,name=u'ed'), Address(email_address='ed@wood.com'))]
+ )
+
+ # this was the controversial part. now, raise an error if the feature is abused.
+ # before the error raise was added, this would silently work.....
+ assert_raises(
+ sa_exc.InvalidRequestError,
+ sess.query(User).join, Address, Address.user,
+ )
+
+ # but this one would silently fail
+ adalias = aliased(Address)
+ assert_raises(
+ sa_exc.InvalidRequestError,
+ sess.query(User).join, adalias, Address.user,
+ )
+
+ def test_multiple_with_aliases(self):
+ sess = create_session()
+
+ ualias = aliased(User)
+ oalias1 = aliased(Order)
+ oalias2 = aliased(Order)
+ self.assert_compile(
+ sess.query(ualias).join(oalias1, ualias.orders).
+ join(oalias2, ualias.orders).
+ filter(or_(oalias1.user_id==9, oalias2.user_id==7)),
+ "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM users AS users_1 "
+ "JOIN orders AS orders_1 ON users_1.id = orders_1.user_id JOIN orders AS orders_2 ON "
+ "users_1.id = orders_2.user_id WHERE orders_1.user_id = :user_id_1 OR orders_2.user_id = :user_id_2",
+ use_default_dialect=True
+ )
+
+ def test_select_from_orm_joins(self):
+ sess = create_session()
+
+ ualias = aliased(User)
+ oalias1 = aliased(Order)
+ oalias2 = aliased(Order)
+
+ self.assert_compile(
+ join(User, oalias2, User.id==oalias2.user_id),
+ "users JOIN orders AS orders_1 ON users.id = orders_1.user_id",
+ use_default_dialect=True
+ )
+
+ self.assert_compile(
+ join(ualias, oalias1, ualias.orders),
+ "users AS users_1 JOIN orders AS orders_1 ON users_1.id = orders_1.user_id",
+ use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(ualias).select_from(join(ualias, oalias1, ualias.orders)),
+ "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM users AS users_1 "
+ "JOIN orders AS orders_1 ON users_1.id = orders_1.user_id",
+ use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(User, ualias).select_from(join(ualias, oalias1, ualias.orders)),
+ "SELECT users.id AS users_id, users.name AS users_name, users_1.id AS users_1_id, "
+ "users_1.name AS users_1_name FROM users, users AS users_1 JOIN orders AS orders_1 ON users_1.id = orders_1.user_id",
+ use_default_dialect=True
+ )
+
+ # this fails (and we cant quite fix right now).
+ if False:
+ self.assert_compile(
+ sess.query(User, ualias).\
+ join(oalias1, ualias.orders).\
+ join(oalias2, User.id==oalias2.user_id).\
+ filter(or_(oalias1.user_id==9, oalias2.user_id==7)),
+ "SELECT users.id AS users_id, users.name AS users_name, users_1.id AS users_1_id, users_1.name AS "
+ "users_1_name FROM users JOIN orders AS orders_2 ON users.id = orders_2.user_id, "
+ "users AS users_1 JOIN orders AS orders_1 ON users_1.id = orders_1.user_id "
+ "WHERE orders_1.user_id = :user_id_1 OR orders_2.user_id = :user_id_2",
+ use_default_dialect=True
+ )
+
+ # this is the same thing using explicit orm.join() (which now offers multiple again)
+ self.assert_compile(
+ sess.query(User, ualias).\
+ select_from(
+ join(ualias, oalias1, ualias.orders),
+ join(User, oalias2, User.id==oalias2.user_id),
+ ).\
+ filter(or_(oalias1.user_id==9, oalias2.user_id==7)),
+ "SELECT users.id AS users_id, users.name AS users_name, users_1.id AS users_1_id, users_1.name AS "
+ "users_1_name FROM users AS users_1 JOIN orders AS orders_1 ON users_1.id = orders_1.user_id, "
+ "users JOIN orders AS orders_2 ON users.id = orders_2.user_id "
+ "WHERE orders_1.user_id = :user_id_1 OR orders_2.user_id = :user_id_2",
+
+ use_default_dialect=True
+ )
+
+
+ def test_overlapping_backwards_joins(self):
+ sess = create_session()
+
+ oalias1 = aliased(Order)
+ oalias2 = aliased(Order)
+
+ # this is invalid SQL - joins from orders_1/orders_2 to User twice.
+ # but that is what was asked for so they get it !
+ self.assert_compile(
+ sess.query(User).join(oalias1.user).join(oalias2.user),
+ "SELECT users.id AS users_id, users.name AS users_name FROM orders AS orders_1 "
+ "JOIN users ON users.id = orders_1.user_id, orders AS orders_2 JOIN users ON users.id = orders_2.user_id",
+ use_default_dialect=True,
+ )
+
+ def test_replace_multiple_from_clause(self):
+ """test adding joins onto multiple FROM clauses"""
+
+ sess = create_session()
+
+ self.assert_compile(
+ sess.query(Address, User).join(Address.dingaling).join(User.orders, Order.items),
+ "SELECT addresses.id AS addresses_id, addresses.user_id AS addresses_user_id, "
+ "addresses.email_address AS addresses_email_address, users.id AS users_id, "
+ "users.name AS users_name FROM addresses JOIN dingalings ON addresses.id = dingalings.address_id, "
+ "users JOIN orders ON users.id = orders.user_id JOIN order_items AS order_items_1 "
+ "ON orders.id = order_items_1.order_id JOIN items ON items.id = order_items_1.item_id",
+ use_default_dialect = True
+ )
+
+ def test_multiple_adaption(self):
+ sess = create_session()
+
+ self.assert_compile(
+ sess.query(User).join(User.orders, Order.items, aliased=True).filter(Order.id==7).filter(Item.id==8),
+ "SELECT users.id AS users_id, users.name AS users_name FROM users JOIN orders AS orders_1 "
+ "ON users.id = orders_1.user_id JOIN order_items AS order_items_1 ON orders_1.id = order_items_1.order_id "
+ "JOIN items AS items_1 ON items_1.id = order_items_1.item_id WHERE orders_1.id = :id_1 AND items_1.id = :id_2",
+ use_default_dialect=True
+ )
+
+ def test_onclause_conditional_adaption(self):
+ sess = create_session()
+
+ # this is now a very weird test, nobody should really
+ # be using the aliased flag in this way.
+ self.assert_compile(
+ sess.query(User).join(User.orders, aliased=True).
+ join(Item,
+ and_(Order.id==order_items.c.order_id, order_items.c.item_id==Item.id),
+ from_joinpoint=True, aliased=True
+ ),
+ "SELECT users.id AS users_id, users.name AS users_name FROM users JOIN "
+ "orders AS orders_1 ON users.id = orders_1.user_id JOIN items AS items_1 "
+ "ON orders_1.id = order_items.order_id AND order_items.item_id = items_1.id",
+ use_default_dialect=True
+ )
+
+
+ oalias = orders.select()
+ self.assert_compile(
+ sess.query(User).join(oalias, User.orders).
+ join(Item,
+ and_(Order.id==order_items.c.order_id, order_items.c.item_id==Item.id),
+ from_joinpoint=True
+ ),
+ "SELECT users.id AS users_id, users.name AS users_name FROM users JOIN "
+ "(SELECT orders.id AS id, orders.user_id AS user_id, orders.address_id AS address_id, orders.description "
+ "AS description, orders.isopen AS isopen FROM orders) AS anon_1 ON users.id = anon_1.user_id JOIN items "
+ "ON anon_1.id = order_items.order_id AND order_items.item_id = items.id",
+ use_default_dialect=True
+ )
+
+ # query.join(<stuff>, aliased=True).join(target, sql_expression)
+ # or: query.join(path_to_some_joined_table_mapper).join(target, sql_expression)
+
+ def test_pure_expression_error(self):
+ sess = create_session()
+
+ assert_raises_message(sa.exc.InvalidRequestError, "Could not find a FROM clause to join from", sess.query(users).join, addresses)
+
+
+ def test_orderby_arg_bug(self):
+ sess = create_session()
+ # no arg error
+ result = sess.query(User).join('orders', aliased=True).order_by(Order.id).reset_joinpoint().order_by(users.c.id).all()
+
+ def test_no_onclause(self):
+ sess = create_session()
+
+ eq_(
+ sess.query(User).select_from(join(User, Order).join(Item, Order.items)).filter(Item.description == 'item 4').all(),
+ [User(name='jack')]
+ )
+
+ eq_(
+ sess.query(User.name).select_from(join(User, Order).join(Item, Order.items)).filter(Item.description == 'item 4').all(),
+ [('jack',)]
+ )
+
+ eq_(
+ sess.query(User).join(Order).join(Item, Order.items)
+ .filter(Item.description == 'item 4').all(),
+ [User(name='jack')]
+ )
+
+ def test_clause_onclause(self):
+ sess = create_session()
+
+ eq_(
+ sess.query(User).join(Order, User.id==Order.user_id).
+ join(order_items, Order.id==order_items.c.order_id).
+ join(Item, order_items.c.item_id==Item.id).
+ filter(Item.description == 'item 4').all(),
+ [User(name='jack')]
+ )
+
+ eq_(
+ sess.query(User.name).join(Order, User.id==Order.user_id).
+ join(order_items, Order.id==order_items.c.order_id).
+ join(Item, order_items.c.item_id==Item.id).
+ filter(Item.description == 'item 4').all(),
+ [('jack',)]
+ )
+
+ ualias = aliased(User)
+ eq_(
+ sess.query(ualias.name).join(Order, ualias.id==Order.user_id).
+ join(order_items, Order.id==order_items.c.order_id).
+ join(Item, order_items.c.item_id==Item.id).
+ filter(Item.description == 'item 4').all(),
+ [('jack',)]
+ )
+
+ # explicit onclause with from_self(), means
+ # the onclause must be aliased against the query's custom
+ # FROM object
+ eq_(
+ sess.query(User).order_by(User.id).offset(2).
+ from_self().
+ join(Order, User.id==Order.user_id).
+ all(),
+ [User(name='fred')]
+ )
+
+ # same with an explicit select_from()
+ eq_(
+ sess.query(User).select_from(select([users]).
+ order_by(User.id).offset(2).alias()).
+ join(Order, User.id==Order.user_id).
+ all(),
+ [User(name='fred')]
+ )
+
+
+ def test_aliased_classes(self):
+ sess = create_session()
+
+ (user7, user8, user9, user10) = sess.query(User).all()
+ (address1, address2, address3, address4, address5) = sess.query(Address).all()
+ expected = [(user7, address1),
+ (user8, address2),
+ (user8, address3),
+ (user8, address4),
+ (user9, address5),
+ (user10, None)]
+
+ q = sess.query(User)
+ AdAlias = aliased(Address)
+ q = q.add_entity(AdAlias).select_from(outerjoin(User, AdAlias))
+ l = q.order_by(User.id, AdAlias.id).all()
+ eq_(l, expected)
+
+ sess.expunge_all()
+
+ q = sess.query(User).add_entity(AdAlias)
+ l = q.select_from(outerjoin(User, AdAlias)).filter(AdAlias.email_address=='ed@bettyboop.com').all()
+ eq_(l, [(user8, address3)])
+
+ l = q.select_from(outerjoin(User, AdAlias, 'addresses')).filter(AdAlias.email_address=='ed@bettyboop.com').all()
+ eq_(l, [(user8, address3)])
+
+ l = q.select_from(outerjoin(User, AdAlias, User.id==AdAlias.user_id)).filter(AdAlias.email_address=='ed@bettyboop.com').all()
+ eq_(l, [(user8, address3)])
+
+ # this is the first test where we are joining "backwards" - from AdAlias to User even though
+ # the query is against User
+ q = sess.query(User, AdAlias)
+ l = q.join(AdAlias.user).filter(User.name=='ed')
+ eq_(l.all(), [(user8, address2),(user8, address3),(user8, address4),])
+
+ q = sess.query(User, AdAlias).select_from(join(AdAlias, User, AdAlias.user)).filter(User.name=='ed')
+ eq_(l.all(), [(user8, address2),(user8, address3),(user8, address4),])
+
+ def test_expression_onclauses(self):
+ sess = create_session()
+
+ subq = sess.query(User).subquery()
+
+ self.assert_compile(
+ sess.query(User).join(subq, User.name==subq.c.name),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users JOIN (SELECT users.id AS id, users.name "
+ "AS name FROM users) AS anon_1 ON users.name = anon_1.name",
+ use_default_dialect=True
+ )
+
+
+ subq = sess.query(Order).subquery()
+ self.assert_compile(
+ sess.query(User).join(subq, User.id==subq.c.user_id),
+ "SELECT users.id AS users_id, users.name AS users_name FROM "
+ "users JOIN (SELECT orders.id AS id, orders.user_id AS user_id, "
+ "orders.address_id AS address_id, orders.description AS "
+ "description, orders.isopen AS isopen FROM orders) AS "
+ "anon_1 ON users.id = anon_1.user_id",
+ use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(User).join(Order, User.id==Order.user_id),
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users JOIN orders ON users.id = orders.user_id",
+ use_default_dialect=True
+ )
+
+
+ def test_implicit_joins_from_aliases(self):
+ sess = create_session()
+ OrderAlias = aliased(Order)
+
+ eq_(
+ sess.query(OrderAlias).join('items').filter_by(description='item 3').\
+ order_by(OrderAlias.id).all(),
+ [
+ Order(address_id=1,description=u'order 1',isopen=0,user_id=7,id=1),
+ Order(address_id=4,description=u'order 2',isopen=0,user_id=9,id=2),
+ Order(address_id=1,description=u'order 3',isopen=1,user_id=7,id=3)
+ ]
+ )
+
+ eq_(
+ sess.query(User, OrderAlias, Item.description).
+ join(OrderAlias, 'orders').
+ join('items', from_joinpoint=True).
+ filter_by(description='item 3').\
+ order_by(User.id, OrderAlias.id).all(),
+ [
+ (User(name=u'jack',id=7), Order(address_id=1,description=u'order 1',isopen=0,user_id=7,id=1), u'item 3'),
+ (User(name=u'jack',id=7), Order(address_id=1,description=u'order 3',isopen=1,user_id=7,id=3), u'item 3'),
+ (User(name=u'fred',id=9), Order(address_id=4,description=u'order 2',isopen=0,user_id=9,id=2), u'item 3')
+ ]
+ )
+
+ def test_aliased_classes_m2m(self):
+ sess = create_session()
+
+ (order1, order2, order3, order4, order5) = sess.query(Order).all()
+ (item1, item2, item3, item4, item5) = sess.query(Item).all()
+ expected = [
+ (order1, item1),
+ (order1, item2),
+ (order1, item3),
+ (order2, item1),
+ (order2, item2),
+ (order2, item3),
+ (order3, item3),
+ (order3, item4),
+ (order3, item5),
+ (order4, item1),
+ (order4, item5),
+ (order5, item5),
+ ]
+
+ q = sess.query(Order)
+ q = q.add_entity(Item).select_from(join(Order, Item, 'items')).order_by(Order.id, Item.id)
+ l = q.all()
+ eq_(l, expected)
+
+ IAlias = aliased(Item)
+ q = sess.query(Order, IAlias).select_from(join(Order, IAlias, 'items')).filter(IAlias.description=='item 3')
+ l = q.all()
+ eq_(l,
+ [
+ (order1, item3),
+ (order2, item3),
+ (order3, item3),
+ ]
+ )
+
+ def test_joins_from_adapted_entities(self):
+
+ # test for #1853
+
+ session = create_session()
+ first = session.query(User)
+ second = session.query(User)
+ unioned = first.union(second)
+ subquery = session.query(User.id).subquery()
+ join = subquery, subquery.c.id == User.id
+ joined = unioned.outerjoin(*join)
+ self.assert_compile(joined,
+ 'SELECT anon_1.users_id AS '
+ 'anon_1_users_id, anon_1.users_name AS '
+ 'anon_1_users_name FROM (SELECT users.id '
+ 'AS users_id, users.name AS users_name '
+ 'FROM users UNION SELECT users.id AS '
+ 'users_id, users.name AS users_name FROM '
+ 'users) AS anon_1 LEFT OUTER JOIN (SELECT '
+ 'users.id AS id FROM users) AS anon_2 ON '
+ 'anon_2.id = anon_1.users_id',
+ use_default_dialect=True)
+
+ first = session.query(User.id)
+ second = session.query(User.id)
+ unioned = first.union(second)
+ subquery = session.query(User.id).subquery()
+ join = subquery, subquery.c.id == User.id
+ joined = unioned.outerjoin(*join)
+ self.assert_compile(joined,
+ 'SELECT anon_1.users_id AS anon_1_users_id '
+ 'FROM (SELECT users.id AS users_id FROM '
+ 'users UNION SELECT users.id AS users_id '
+ 'FROM users) AS anon_1 LEFT OUTER JOIN '
+ '(SELECT users.id AS id FROM users) AS '
+ 'anon_2 ON anon_2.id = anon_1.users_id',
+ use_default_dialect=True)
+
+ def test_reset_joinpoint(self):
+ for aliased in (True, False):
+ # load a user who has an order that contains item id 3 and address id 1 (order 3, owned by jack)
+ result = create_session().query(User).join('orders', 'items', aliased=aliased).filter_by(id=3).reset_joinpoint().join('orders','address', aliased=aliased).filter_by(id=1).all()
+ assert [User(id=7, name='jack')] == result
+
+ result = create_session().query(User).outerjoin('orders', 'items', aliased=aliased).filter_by(id=3).reset_joinpoint().outerjoin('orders','address', aliased=aliased).filter_by(id=1).all()
+ assert [User(id=7, name='jack')] == result
+
+ def test_overlap_with_aliases(self):
+ oalias = orders.alias('oalias')
+
+ result = create_session().query(User).select_from(users.join(oalias)).filter(oalias.c.description.in_(["order 1", "order 2", "order 3"])).join('orders', 'items').order_by(User.id).all()
+ assert [User(id=7, name='jack'), User(id=9, name='fred')] == result
+
+ result = create_session().query(User).select_from(users.join(oalias)).filter(oalias.c.description.in_(["order 1", "order 2", "order 3"])).join('orders', 'items').filter_by(id=4).all()
+ assert [User(id=7, name='jack')] == result
+
+ def test_aliased(self):
+ """test automatic generation of aliased joins."""
+
+ sess = create_session()
+
+ # test a basic aliasized path
+ q = sess.query(User).join('addresses', aliased=True).filter_by(email_address='jack@bean.com')
+ assert [User(id=7)] == q.all()
+
+ q = sess.query(User).join('addresses', aliased=True).filter(Address.email_address=='jack@bean.com')
+ assert [User(id=7)] == q.all()
+
+ q = sess.query(User).join('addresses', aliased=True).filter(or_(Address.email_address=='jack@bean.com', Address.email_address=='fred@fred.com'))
+ assert [User(id=7), User(id=9)] == q.all()
+
+ # test two aliasized paths, one to 'orders' and the other to 'orders','items'.
+ # one row is returned because user 7 has order 3 and also has order 1 which has item 1
+ # this tests a o2m join and a m2m join.
+ q = sess.query(User).join('orders', aliased=True).filter(Order.description=="order 3").join('orders', 'items', aliased=True).filter(Item.description=="item 1")
+ assert q.count() == 1
+ assert [User(id=7)] == q.all()
+
+ # test the control version - same joins but not aliased. rows are not returned because order 3 does not have item 1
+ q = sess.query(User).join('orders').filter(Order.description=="order 3").join('orders', 'items').filter(Item.description=="item 1")
+ assert [] == q.all()
+ assert q.count() == 0
+
+ # the left half of the join condition of the any() is aliased.
+ q = sess.query(User).join('orders', aliased=True).filter(Order.items.any(Item.description=='item 4'))
+ assert [User(id=7)] == q.all()
+
+ # test that aliasing gets reset when join() is called
+ q = sess.query(User).join('orders', aliased=True).filter(Order.description=="order 3").join('orders', aliased=True).filter(Order.description=="order 5")
+ assert q.count() == 1
+ assert [User(id=7)] == q.all()
+
+ def test_aliased_order_by(self):
+ sess = create_session()
+
+ ualias = aliased(User)
+ eq_(
+ sess.query(User, ualias).filter(User.id > ualias.id).order_by(desc(ualias.id), User.name).all(),
+ [
+ (User(id=10,name=u'chuck'), User(id=9,name=u'fred')),
+ (User(id=10,name=u'chuck'), User(id=8,name=u'ed')),
+ (User(id=9,name=u'fred'), User(id=8,name=u'ed')),
+ (User(id=10,name=u'chuck'), User(id=7,name=u'jack')),
+ (User(id=8,name=u'ed'), User(id=7,name=u'jack')),
+ (User(id=9,name=u'fred'), User(id=7,name=u'jack'))
+ ]
+ )
+
+ def test_plain_table(self):
+
+ sess = create_session()
+
+ eq_(
+ sess.query(User.name).join(addresses, User.id==addresses.c.user_id).order_by(User.id).all(),
+ [(u'jack',), (u'ed',), (u'ed',), (u'ed',), (u'fred',)]
+ )
+
+ def test_no_joinpoint_expr(self):
+ sess = create_session()
+
+ # these are consistent regardless of
+ # select_from() being present.
+
+ assert_raises_message(
+ sa_exc.InvalidRequestError,
+ "Could not find a FROM",
+ sess.query(users.c.id).join, User
+ )
+
+ assert_raises_message(
+ sa_exc.InvalidRequestError,
+ "Could not find a FROM",
+ sess.query(users.c.id).select_from(users).join, User
+ )
+
+ def test_select_from(self):
+ """Test that the left edge of the join can be set reliably with select_from()."""
+
+ sess = create_session()
+ self.assert_compile(
+ sess.query(Item.id).select_from(User).join(User.orders).join(Order.items),
+ "SELECT items.id AS items_id FROM users JOIN orders ON "
+ "users.id = orders.user_id JOIN order_items AS order_items_1 "
+ "ON orders.id = order_items_1.order_id JOIN items ON items.id = "
+ "order_items_1.item_id",
+ use_default_dialect=True
+ )
+
+ # here, the join really wants to add a second FROM clause
+ # for "Item". but select_from disallows that
+ self.assert_compile(
+ sess.query(Item.id).select_from(User).join(Item, User.id==Item.id),
+ "SELECT items.id AS items_id FROM users JOIN items ON users.id = items.id",
+ use_default_dialect=True
+ )
+
+
+
+
+ def test_from_self_resets_joinpaths(self):
+ """test a join from from_self() doesn't confuse joins inside the subquery
+ with the outside.
+ """
+ sess = create_session()
+
+ self.assert_compile(
+ sess.query(Item).join(Item.keywords).from_self(Keyword).join(Item.keywords),
+ "SELECT keywords.id AS keywords_id, keywords.name AS keywords_name FROM "
+ "(SELECT items.id AS items_id, items.description AS items_description "
+ "FROM items JOIN item_keywords AS item_keywords_1 ON items.id = "
+ "item_keywords_1.item_id JOIN keywords ON keywords.id = item_keywords_1.keyword_id) "
+ "AS anon_1 JOIN item_keywords AS item_keywords_2 ON "
+ "anon_1.items_id = item_keywords_2.item_id "
+ "JOIN keywords ON "
+ "keywords.id = item_keywords_2.keyword_id",
+ use_default_dialect=True
+ )
+
+
+class MultiplePathTest(_base.MappedTest, AssertsCompiledSQL):
+ @classmethod
+ def define_tables(cls, metadata):
+ global t1, t2, t1t2_1, t1t2_2
+ t1 = Table('t1', metadata,
+ Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('data', String(30))
+ )
+ t2 = Table('t2', metadata,
+ Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('data', String(30))
+ )
+
+ t1t2_1 = Table('t1t2_1', metadata,
+ Column('t1id', Integer, ForeignKey('t1.id')),
+ Column('t2id', Integer, ForeignKey('t2.id'))
+ )
+
+ t1t2_2 = Table('t1t2_2', metadata,
+ Column('t1id', Integer, ForeignKey('t1.id')),
+ Column('t2id', Integer, ForeignKey('t2.id'))
+ )
+
+ def test_basic(self):
+ class T1(object):pass
+ class T2(object):pass
+
+ mapper(T1, t1, properties={
+ 't2s_1':relationship(T2, secondary=t1t2_1),
+ 't2s_2':relationship(T2, secondary=t1t2_2),
+ })
+ mapper(T2, t2)
+
+ q = create_session().query(T1).join('t2s_1').filter(t2.c.id==5).reset_joinpoint().join('t2s_2')
+ self.assert_compile(
+ q,
+ "SELECT t1.id AS t1_id, t1.data AS t1_data FROM t1 JOIN t1t2_1 AS t1t2_1_1 "
+ "ON t1.id = t1t2_1_1.t1id JOIN t2 ON t2.id = t1t2_1_1.t2id JOIN t1t2_2 AS t1t2_2_1 "
+ "ON t1.id = t1t2_2_1.t1id JOIN t2 ON t2.id = t1t2_2_1.t2id WHERE t2.id = :id_1"
+ , use_default_dialect=True
+ )
+
+
+class SelfRefMixedTest(_base.MappedTest, AssertsCompiledSQL):
+ run_setup_mappers = 'once'
+ __dialect__ = default.DefaultDialect()
+
+ @classmethod
+ def define_tables(cls, metadata):
+ nodes = Table('nodes', metadata,
+ Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('parent_id', Integer, ForeignKey('nodes.id'))
+ )
+
+ sub_table = Table('sub_table', metadata,
+ Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('node_id', Integer, ForeignKey('nodes.id')),
+ )
+
+ assoc_table = Table('assoc_table', metadata,
+ Column('left_id', Integer, ForeignKey('nodes.id')),
+ Column('right_id', Integer, ForeignKey('nodes.id'))
+ )
+
+ @classmethod
+ @testing.resolve_artifact_names
+ def setup_classes(cls):
+ class Node(Base):
+ pass
+
+ class Sub(Base):
+ pass
+
+ mapper(Node, nodes, properties={
+ 'children':relationship(Node, lazy='select', join_depth=3,
+ backref=backref('parent', remote_side=[nodes.c.id])
+ ),
+ 'subs' : relationship(Sub),
+ 'assoc':relationship(Node,
+ secondary=assoc_table,
+ primaryjoin=nodes.c.id==assoc_table.c.left_id,
+ secondaryjoin=nodes.c.id==assoc_table.c.right_id)
+ })
+ mapper(Sub, sub_table)
+
+ @testing.resolve_artifact_names
+ def test_o2m_aliased_plus_o2m(self):
+ sess = create_session()
+ n1 = aliased(Node)
+
+ self.assert_compile(
+ sess.query(Node).join(n1, Node.children).join(Sub, n1.subs),
+ "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id "
+ "FROM nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id "
+ "JOIN sub_table ON nodes_1.id = sub_table.node_id"
+ )
+
+ self.assert_compile(
+ sess.query(Node).join(n1, Node.children).join(Sub, Node.subs),
+ "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id "
+ "FROM nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id "
+ "JOIN sub_table ON nodes.id = sub_table.node_id"
+ )
+
+ @testing.resolve_artifact_names
+ def test_m2m_aliased_plus_o2m(self):
+ sess = create_session()
+ n1 = aliased(Node)
+
+ self.assert_compile(
+ sess.query(Node).join(n1, Node.assoc).join(Sub, n1.subs),
+ "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id "
+ "FROM nodes JOIN assoc_table AS assoc_table_1 ON nodes.id = "
+ "assoc_table_1.left_id JOIN nodes AS nodes_1 ON nodes_1.id = "
+ "assoc_table_1.right_id JOIN sub_table ON nodes_1.id = sub_table.node_id",
+ )
+
+ self.assert_compile(
+ sess.query(Node).join(n1, Node.assoc).join(Sub, Node.subs),
+ "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id "
+ "FROM nodes JOIN assoc_table AS assoc_table_1 ON nodes.id = "
+ "assoc_table_1.left_id JOIN nodes AS nodes_1 ON nodes_1.id = "
+ "assoc_table_1.right_id JOIN sub_table ON nodes.id = sub_table.node_id",
+ )
+
+
+class SelfReferentialTest(_base.MappedTest, AssertsCompiledSQL):
+ run_setup_mappers = 'once'
+ run_inserts = 'once'
+ run_deletes = None
+
+ @classmethod
+ def define_tables(cls, metadata):
+ global nodes
+ nodes = Table('nodes', metadata,
+ Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('parent_id', Integer, ForeignKey('nodes.id')),
+ Column('data', String(30)))
+
+ @classmethod
+ def insert_data(cls):
+ # TODO: somehow using setup_classes()
+ # here normally is screwing up the other tests.
+
+ global Node, Sub
+ class Node(Base):
+ def append(self, node):
+ self.children.append(node)
+
+ mapper(Node, nodes, properties={
+ 'children':relationship(Node, lazy='select', join_depth=3,
+ backref=backref('parent', remote_side=[nodes.c.id])
+ ),
+ })
+
+ sess = create_session()
+ n1 = Node(data='n1')
+ n1.append(Node(data='n11'))
+ n1.append(Node(data='n12'))
+ n1.append(Node(data='n13'))
+ n1.children[1].append(Node(data='n121'))
+ n1.children[1].append(Node(data='n122'))
+ n1.children[1].append(Node(data='n123'))
+ sess.add(n1)
+ sess.flush()
+ sess.close()
+
+ @testing.resolve_artifact_names
+ def test_join(self):
+ sess = create_session()
+
+ node = sess.query(Node).join('children', aliased=True).filter_by(data='n122').first()
+ assert node.data=='n12'
+
+ ret = sess.query(Node.data).join(Node.children, aliased=True).filter_by(data='n122').all()
+ assert ret == [('n12',)]
+
+
+ node = sess.query(Node).join('children', 'children', aliased=True).filter_by(data='n122').first()
+ assert node.data=='n1'
+
+ node = sess.query(Node).filter_by(data='n122').join('parent', aliased=True).filter_by(data='n12').\
+ join('parent', aliased=True, from_joinpoint=True).filter_by(data='n1').first()
+ assert node.data == 'n122'
+
+ @testing.resolve_artifact_names
+ def test_string_or_prop_aliased(self):
+ """test that join('foo') behaves the same as join(Cls.foo) in a self
+ referential scenario.
+
+ """
+
+ sess = create_session()
+ nalias = aliased(Node, sess.query(Node).filter_by(data='n1').subquery())
+
+ q1 = sess.query(nalias).join(nalias.children, aliased=True).\
+ join(Node.children, from_joinpoint=True)
+
+ q2 = sess.query(nalias).join(nalias.children, aliased=True).\
+ join("children", from_joinpoint=True)
+
+ for q in (q1, q2):
+ self.assert_compile(
+ q,
+ "SELECT anon_1.id AS anon_1_id, anon_1.parent_id AS "
+ "anon_1_parent_id, anon_1.data AS anon_1_data FROM "
+ "(SELECT nodes.id AS id, nodes.parent_id AS parent_id, "
+ "nodes.data AS data FROM nodes WHERE nodes.data = :data_1) "
+ "AS anon_1 JOIN nodes AS nodes_1 ON anon_1.id = "
+ "nodes_1.parent_id JOIN nodes ON nodes_1.id = nodes.parent_id",
+ use_default_dialect=True
+ )
+
+ q1 = sess.query(Node).join(nalias.children, aliased=True).\
+ join(Node.children, aliased=True, from_joinpoint=True).\
+ join(Node.children, from_joinpoint=True)
+
+ q2 = sess.query(Node).join(nalias.children, aliased=True).\
+ join("children", aliased=True, from_joinpoint=True).\
+ join("children", from_joinpoint=True)
+
+ for q in (q1, q2):
+ self.assert_compile(
+ q,
+ "SELECT nodes.id AS nodes_id, nodes.parent_id AS "
+ "nodes_parent_id, nodes.data AS nodes_data FROM (SELECT "
+ "nodes.id AS id, nodes.parent_id AS parent_id, nodes.data "
+ "AS data FROM nodes WHERE nodes.data = :data_1) AS anon_1 "
+ "JOIN nodes AS nodes_1 ON anon_1.id = nodes_1.parent_id "
+ "JOIN nodes AS nodes_2 ON nodes_1.id = nodes_2.parent_id "
+ "JOIN nodes ON nodes_2.id = nodes.parent_id",
+ use_default_dialect=True
+ )
+
+ @testing.resolve_artifact_names
+ def test_from_self_inside_excludes_outside(self):
+ """test the propagation of aliased() from inside to outside
+ on a from_self()..
+ """
+ sess = create_session()
+
+ n1 = aliased(Node)
+
+ # n1 is not inside the from_self(), so all cols must be maintained
+ # on the outside
+ self.assert_compile(
+ sess.query(Node).filter(Node.data=='n122').from_self(n1, Node.id),
+ "SELECT nodes_1.id AS nodes_1_id, nodes_1.parent_id AS nodes_1_parent_id, "
+ "nodes_1.data AS nodes_1_data, anon_1.nodes_id AS anon_1_nodes_id "
+ "FROM nodes AS nodes_1, (SELECT nodes.id AS nodes_id, "
+ "nodes.parent_id AS nodes_parent_id, nodes.data AS nodes_data FROM "
+ "nodes WHERE nodes.data = :data_1) AS anon_1",
+ use_default_dialect=True
+ )
+
+ parent = aliased(Node)
+ grandparent = aliased(Node)
+ q = sess.query(Node, parent, grandparent).\
+ join(parent, Node.parent).\
+ join(grandparent, parent.parent).\
+ filter(Node.data=='n122').filter(parent.data=='n12').\
+ filter(grandparent.data=='n1').from_self().limit(1)
+
+ # parent, grandparent *are* inside the from_self(), so they
+ # should get aliased to the outside.
+ self.assert_compile(
+ q,
+ "SELECT anon_1.nodes_id AS anon_1_nodes_id, "
+ "anon_1.nodes_parent_id AS anon_1_nodes_parent_id, "
+ "anon_1.nodes_data AS anon_1_nodes_data, "
+ "anon_1.nodes_1_id AS anon_1_nodes_1_id, "
+ "anon_1.nodes_1_parent_id AS anon_1_nodes_1_parent_id, "
+ "anon_1.nodes_1_data AS anon_1_nodes_1_data, "
+ "anon_1.nodes_2_id AS anon_1_nodes_2_id, "
+ "anon_1.nodes_2_parent_id AS anon_1_nodes_2_parent_id, "
+ "anon_1.nodes_2_data AS anon_1_nodes_2_data "
+ "FROM (SELECT nodes.id AS nodes_id, nodes.parent_id "
+ "AS nodes_parent_id, nodes.data AS nodes_data, "
+ "nodes_1.id AS nodes_1_id, nodes_1.parent_id AS nodes_1_parent_id, "
+ "nodes_1.data AS nodes_1_data, nodes_2.id AS nodes_2_id, "
+ "nodes_2.parent_id AS nodes_2_parent_id, nodes_2.data AS "
+ "nodes_2_data FROM nodes JOIN nodes AS nodes_1 ON "
+ "nodes_1.id = nodes.parent_id JOIN nodes AS nodes_2 "
+ "ON nodes_2.id = nodes_1.parent_id "
+ "WHERE nodes.data = :data_1 AND nodes_1.data = :data_2 AND "
+ "nodes_2.data = :data_3) AS anon_1 LIMIT :param_1",
+ {'param_1':1},
+ use_default_dialect=True
+ )
+
+ @testing.resolve_artifact_names
+ def test_explicit_join(self):
+ sess = create_session()
+
+ n1 = aliased(Node)
+ n2 = aliased(Node)
+
+ self.assert_compile(
+ join(Node, n1, 'children').join(n2, 'children'),
+ "nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id JOIN nodes AS nodes_2 ON nodes_1.id = nodes_2.parent_id",
+ use_default_dialect=True
+ )
+
+ self.assert_compile(
+ join(Node, n1, Node.children).join(n2, n1.children),
+ "nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id JOIN nodes AS nodes_2 ON nodes_1.id = nodes_2.parent_id",
+ use_default_dialect=True
+ )
+
+ # the join_to_left=False here is unfortunate. the default on this flag should
+ # be False.
+ self.assert_compile(
+ join(Node, n1, Node.children).join(n2, Node.children, join_to_left=False),
+ "nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id JOIN nodes AS nodes_2 ON nodes.id = nodes_2.parent_id",
+ use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(Node).join(n1, Node.children).join(n2, n1.children),
+ "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id, nodes.data AS "
+ "nodes_data FROM nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id "
+ "JOIN nodes AS nodes_2 ON nodes_1.id = nodes_2.parent_id",
+ use_default_dialect=True
+ )
+
+ self.assert_compile(
+ sess.query(Node).join(n1, Node.children).join(n2, Node.children),
+ "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id, nodes.data AS "
+ "nodes_data FROM nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id "
+ "JOIN nodes AS nodes_2 ON nodes.id = nodes_2.parent_id",
+ use_default_dialect=True
+ )
+
+ node = sess.query(Node).select_from(join(Node, n1, 'children')).filter(n1.data=='n122').first()
+ assert node.data=='n12'
+
+ node = sess.query(Node).select_from(join(Node, n1, 'children').join(n2, 'children')).\
+ filter(n2.data=='n122').first()
+ assert node.data=='n1'
+
+ # mix explicit and named onclauses
+ node = sess.query(Node).select_from(join(Node, n1, Node.id==n1.parent_id).join(n2, 'children')).\
+ filter(n2.data=='n122').first()
+ assert node.data=='n1'
+
+ node = sess.query(Node).select_from(join(Node, n1, 'parent').join(n2, 'parent')).\
+ filter(and_(Node.data=='n122', n1.data=='n12', n2.data=='n1')).first()
+ assert node.data == 'n122'
+
+ eq_(
+ list(sess.query(Node).select_from(join(Node, n1, 'parent').join(n2, 'parent')).\
+ filter(and_(Node.data=='n122', n1.data=='n12', n2.data=='n1')).values(Node.data, n1.data, n2.data)),
+ [('n122', 'n12', 'n1')])
+
+ @testing.resolve_artifact_names
+ def test_join_to_nonaliased(self):
+ sess = create_session()
+
+ n1 = aliased(Node)
+
+ # using 'n1.parent' implicitly joins to unaliased Node
+ eq_(
+ sess.query(n1).join(n1.parent).filter(Node.data=='n1').all(),
+ [Node(parent_id=1,data=u'n11',id=2), Node(parent_id=1,data=u'n12',id=3), Node(parent_id=1,data=u'n13',id=4)]
+ )
+
+ # explicit (new syntax)
+ eq_(
+ sess.query(n1).join(Node, n1.parent).filter(Node.data=='n1').all(),
+ [Node(parent_id=1,data=u'n11',id=2), Node(parent_id=1,data=u'n12',id=3), Node(parent_id=1,data=u'n13',id=4)]
+ )
+
+
+ @testing.resolve_artifact_names
+ def test_multiple_explicit_entities(self):
+ sess = create_session()
+
+ parent = aliased(Node)
+ grandparent = aliased(Node)
+ eq_(
+ sess.query(Node, parent, grandparent).\
+ join(parent, Node.parent).\
+ join(grandparent, parent.parent).\
+ filter(Node.data=='n122').filter(parent.data=='n12').\
+ filter(grandparent.data=='n1').first(),
+ (Node(data='n122'), Node(data='n12'), Node(data='n1'))
+ )
+
+ eq_(
+ sess.query(Node, parent, grandparent).\
+ join(parent, Node.parent).\
+ join(grandparent, parent.parent).\
+ filter(Node.data=='n122').filter(parent.data=='n12').\
+ filter(grandparent.data=='n1').from_self().first(),
+ (Node(data='n122'), Node(data='n12'), Node(data='n1'))
+ )
+
+ # same, change order around
+ eq_(
+ sess.query(parent, grandparent, Node).\
+ join(parent, Node.parent).\
+ join(grandparent, parent.parent).\
+ filter(Node.data=='n122').filter(parent.data=='n12').\
+ filter(grandparent.data=='n1').from_self().first(),
+ (Node(data='n12'), Node(data='n1'), Node(data='n122'))
+ )
+
+ eq_(
+ sess.query(Node, parent, grandparent).\
+ join(parent, Node.parent).\
+ join(grandparent, parent.parent).\
+ filter(Node.data=='n122').filter(parent.data=='n12').\
+ filter(grandparent.data=='n1').\
+ options(joinedload(Node.children)).first(),
+ (Node(data='n122'), Node(data='n12'), Node(data='n1'))
+ )
+
+ eq_(
+ sess.query(Node, parent, grandparent).\
+ join(parent, Node.parent).\
+ join(grandparent, parent.parent).\
+ filter(Node.data=='n122').filter(parent.data=='n12').\
+ filter(grandparent.data=='n1').from_self().\
+ options(joinedload(Node.children)).first(),
+ (Node(data='n122'), Node(data='n12'), Node(data='n1'))
+ )
+
+
+ @testing.resolve_artifact_names
+ def test_any(self):
+ sess = create_session()
+ eq_(sess.query(Node).filter(Node.children.any(Node.data=='n1')).all(), [])
+ eq_(sess.query(Node).filter(Node.children.any(Node.data=='n12')).all(), [Node(data='n1')])
+ eq_(sess.query(Node).filter(~Node.children.any()).order_by(Node.id).all(),
+ [Node(data='n11'), Node(data='n13'),Node(data='n121'),Node(data='n122'),Node(data='n123'),])
+
+ @testing.resolve_artifact_names
+ def test_has(self):
+ sess = create_session()
+
+ eq_(sess.query(Node).filter(Node.parent.has(Node.data=='n12')).order_by(Node.id).all(),
+ [Node(data='n121'),Node(data='n122'),Node(data='n123')])
+ eq_(sess.query(Node).filter(Node.parent.has(Node.data=='n122')).all(), [])
+ eq_(sess.query(Node).filter(~Node.parent.has()).all(), [Node(data='n1')])
+
+ @testing.resolve_artifact_names
+ def test_contains(self):
+ sess = create_session()
+
+ n122 = sess.query(Node).filter(Node.data=='n122').one()
+ eq_(sess.query(Node).filter(Node.children.contains(n122)).all(), [Node(data='n12')])
+
+ n13 = sess.query(Node).filter(Node.data=='n13').one()
+ eq_(sess.query(Node).filter(Node.children.contains(n13)).all(), [Node(data='n1')])
+
+ @testing.resolve_artifact_names
+ def test_eq_ne(self):
+ sess = create_session()
+
+ n12 = sess.query(Node).filter(Node.data=='n12').one()
+ eq_(sess.query(Node).filter(Node.parent==n12).all(), [Node(data='n121'),Node(data='n122'),Node(data='n123')])
+
+ eq_(sess.query(Node).filter(Node.parent != n12).all(), [Node(data='n1'), Node(data='n11'), Node(data='n12'), Node(data='n13')])
+
+class SelfReferentialM2MTest(_base.MappedTest):
+ run_setup_mappers = 'once'
+ run_inserts = 'once'
+ run_deletes = None
+
+ @classmethod
+ def define_tables(cls, metadata):
+ global nodes, node_to_nodes
+ nodes = Table('nodes', metadata,
+ Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
+ Column('data', String(30)))
+
+ node_to_nodes =Table('node_to_nodes', metadata,
+ Column('left_node_id', Integer, ForeignKey('nodes.id'),primary_key=True),
+ Column('right_node_id', Integer, ForeignKey('nodes.id'),primary_key=True),
+ )
+
+ @classmethod
+ def insert_data(cls):
+ global Node
+
+ class Node(Base):
+ pass
+
+ mapper(Node, nodes, properties={
+ 'children':relationship(Node, lazy='select', secondary=node_to_nodes,
+ primaryjoin=nodes.c.id==node_to_nodes.c.left_node_id,
+ secondaryjoin=nodes.c.id==node_to_nodes.c.right_node_id,
+ )
+ })
+ sess = create_session()
+ n1 = Node(data='n1')
+ n2 = Node(data='n2')
+ n3 = Node(data='n3')
+ n4 = Node(data='n4')
+ n5 = Node(data='n5')
+ n6 = Node(data='n6')
+ n7 = Node(data='n7')
+
+ n1.children = [n2, n3, n4]
+ n2.children = [n3, n6, n7]
+ n3.children = [n5, n4]
+
+ sess.add(n1)
+ sess.add(n2)
+ sess.add(n3)
+ sess.add(n4)
+ sess.flush()
+ sess.close()
+
+ def test_any(self):
+ sess = create_session()
+ eq_(sess.query(Node).filter(Node.children.any(Node.data=='n3')).all(), [Node(data='n1'), Node(data='n2')])
+
+ def test_contains(self):
+ sess = create_session()
+ n4 = sess.query(Node).filter_by(data='n4').one()
+
+ eq_(sess.query(Node).filter(Node.children.contains(n4)).order_by(Node.data).all(), [Node(data='n1'), Node(data='n3')])
+ eq_(sess.query(Node).filter(not_(Node.children.contains(n4))).order_by(Node.data).all(), [Node(data='n2'), Node(data='n4'), Node(data='n5'), Node(data='n6'), Node(data='n7')])
+
+ def test_explicit_join(self):
+ sess = create_session()
+
+ n1 = aliased(Node)
+ eq_(
+ sess.query(Node).select_from(join(Node, n1, 'children')).filter(n1.data.in_(['n3', 'n7'])).order_by(Node.id).all(),
+ [Node(data='n1'), Node(data='n2')]
+ )
asserted
)
-
class GetTest(QueryTest):
def test_get(self):
s = create_session()
assert str(c) == compare, "%s != %s" % (str(c), compare)
-class RawSelectTest(QueryTest, AssertsCompiledSQL):
- """compare a bunch of select() tests with the equivalent Query using straight table/columns.
-
- Results should be the same as Query should act as a select() pass-thru for ClauseElement entities.
-
- """
- def test_select(self):
- sess = create_session()
-
- self.assert_compile(sess.query(users).select_from(users.select()).with_labels().statement,
- "SELECT users.id AS users_id, users.name AS users_name FROM users, "
- "(SELECT users.id AS id, users.name AS name FROM users) AS anon_1",
- dialect=default.DefaultDialect()
- )
-
- self.assert_compile(sess.query(users, exists([1], from_obj=addresses)).with_labels().statement,
- "SELECT users.id AS users_id, users.name AS users_name, EXISTS "
- "(SELECT 1 FROM addresses) AS anon_1 FROM users",
- dialect=default.DefaultDialect()
- )
-
- # a little tedious here, adding labels to work around Query's auto-labelling.
- # also correlate needed explicitly. hmmm.....
- # TODO: can we detect only one table in the "froms" and then turn off use_labels ?
- s = sess.query(addresses.c.id.label('id'), addresses.c.email_address.label('email')).\
- filter(addresses.c.user_id==users.c.id).correlate(users).statement.alias()
-
- self.assert_compile(sess.query(users, s.c.email).select_from(users.join(s, s.c.id==users.c.id)).with_labels().statement,
- "SELECT users.id AS users_id, users.name AS users_name, anon_1.email AS anon_1_email "
- "FROM users JOIN (SELECT addresses.id AS id, addresses.email_address AS email FROM addresses "
- "WHERE addresses.user_id = users.id) AS anon_1 ON anon_1.id = users.id",
- dialect=default.DefaultDialect()
- )
-
- x = func.lala(users.c.id).label('foo')
- self.assert_compile(sess.query(x).filter(x==5).statement,
- "SELECT lala(users.id) AS foo FROM users WHERE lala(users.id) = :param_1", dialect=default.DefaultDialect())
-
- self.assert_compile(sess.query(func.sum(x).label('bar')).statement,
- "SELECT sum(lala(users.id)) AS bar FROM users", dialect=default.DefaultDialect())
-
class ExpressionTest(QueryTest, AssertsCompiledSQL):
def test_deferred_instances(self):
)
-class FromSelfTest(QueryTest, AssertsCompiledSQL):
- def test_filter(self):
-
- assert [User(id=8), User(id=9)] == create_session().query(User).filter(User.id.in_([8,9])).from_self().all()
-
- assert [User(id=8), User(id=9)] == create_session().query(User).order_by(User.id).slice(1,3).from_self().all()
- assert [User(id=8)] == list(create_session().query(User).filter(User.id.in_([8,9])).from_self().order_by(User.id)[0:1])
-
- def test_join(self):
- assert [
- (User(id=8), Address(id=2)),
- (User(id=8), Address(id=3)),
- (User(id=8), Address(id=4)),
- (User(id=9), Address(id=5))
- ] == create_session().query(User).filter(User.id.in_([8,9])).from_self().\
- join('addresses').add_entity(Address).order_by(User.id, Address.id).all()
-
- def test_group_by(self):
- eq_(
- create_session().query(Address.user_id, func.count(Address.id).label('count')).\
- group_by(Address.user_id).order_by(Address.user_id).all(),
- [(7, 1), (8, 3), (9, 1)]
- )
-
- eq_(
- create_session().query(Address.user_id, Address.id).\
- from_self(Address.user_id, func.count(Address.id)).\
- group_by(Address.user_id).order_by(Address.user_id).all(),
- [(7, 1), (8, 3), (9, 1)]
- )
-
- def test_no_joinedload(self):
- """test that joinedloads are pushed outwards and not rendered in subqueries."""
-
- s = create_session()
-
- oracle_as = not testing.against('oracle') and "AS " or ""
-
- self.assert_compile(
- s.query(User).options(joinedload(User.addresses)).from_self().statement,
- "SELECT anon_1.users_id, anon_1.users_name, addresses_1.id, addresses_1.user_id, "\
- "addresses_1.email_address FROM (SELECT users.id AS users_id, users.name AS users_name FROM users) %(oracle_as)sanon_1 "\
- "LEFT OUTER JOIN addresses %(oracle_as)saddresses_1 ON anon_1.users_id = addresses_1.user_id ORDER BY addresses_1.id" % {
- 'oracle_as':oracle_as
- }
- )
-
- def test_aliases(self):
- """test that aliased objects are accessible externally to a from_self() call."""
-
- s = create_session()
-
- ualias = aliased(User)
- eq_(
- s.query(User, ualias).filter(User.id > ualias.id).from_self(User.name, ualias.name).
- order_by(User.name, ualias.name).all(),
- [
- (u'chuck', u'ed'),
- (u'chuck', u'fred'),
- (u'chuck', u'jack'),
- (u'ed', u'jack'),
- (u'fred', u'ed'),
- (u'fred', u'jack')
- ]
- )
-
- eq_(
- s.query(User, ualias).filter(User.id > ualias.id).from_self(User.name, ualias.name).filter(ualias.name=='ed')\
- .order_by(User.name, ualias.name).all(),
- [(u'chuck', u'ed'), (u'fred', u'ed')]
- )
-
- eq_(
- s.query(User, ualias).filter(User.id > ualias.id).from_self(ualias.name, Address.email_address).
- join(ualias.addresses).order_by(ualias.name, Address.email_address).all(),
- [
- (u'ed', u'fred@fred.com'),
- (u'jack', u'ed@bettyboop.com'),
- (u'jack', u'ed@lala.com'),
- (u'jack', u'ed@wood.com'),
- (u'jack', u'fred@fred.com')]
- )
-
-
- def test_multiple_entities(self):
- sess = create_session()
-
- eq_(
- sess.query(User, Address).filter(User.id==Address.user_id).filter(Address.id.in_([2, 5])).from_self().all(),
- [
- (User(id=8), Address(id=2)),
- (User(id=9), Address(id=5))
- ]
- )
-
- eq_(
- sess.query(User, Address).filter(User.id==Address.user_id).filter(Address.id.in_([2, 5])).from_self().options(joinedload('addresses')).first(),
-
- # order_by(User.id, Address.id).first(),
- (User(id=8, addresses=[Address(), Address(), Address()]), Address(id=2)),
- )
-
- def test_multiple_with_column_entities(self):
- sess = create_session()
-
- eq_(
- sess.query(User.id).from_self().\
- add_column(func.count().label('foo')).\
- group_by(User.id).\
- order_by(User.id).\
- from_self().all(),
- [
- (7,1), (8, 1), (9, 1), (10, 1)
- ]
-
- )
-
class SetOpsTest(QueryTest, AssertsCompiledSQL):
User(id=o1.user_id)
)
-class InheritedJoinTest(_base.MappedTest, AssertsCompiledSQL):
- run_setup_mappers = 'once'
-
- @classmethod
- def define_tables(cls, metadata):
- Table('companies', metadata,
- Column('company_id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('name', String(50)))
-
- Table('people', metadata,
- Column('person_id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('company_id', Integer, ForeignKey('companies.company_id')),
- Column('name', String(50)),
- Column('type', String(30)))
-
- Table('engineers', metadata,
- Column('person_id', Integer, ForeignKey('people.person_id'), primary_key=True),
- Column('status', String(30)),
- Column('engineer_name', String(50)),
- Column('primary_language', String(50)),
- )
-
- Table('machines', metadata,
- Column('machine_id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('name', String(50)),
- Column('engineer_id', Integer, ForeignKey('engineers.person_id')))
+
- Table('managers', metadata,
- Column('person_id', Integer, ForeignKey('people.person_id'), primary_key=True),
- Column('status', String(30)),
- Column('manager_name', String(50))
- )
-
- Table('boss', metadata,
- Column('boss_id', Integer, ForeignKey('managers.person_id'), primary_key=True),
- Column('golf_swing', String(30)),
- )
- Table('paperwork', metadata,
- Column('paperwork_id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('description', String(50)),
- Column('person_id', Integer, ForeignKey('people.person_id')))
-
- @classmethod
- @testing.resolve_artifact_names
- def setup_classes(cls):
- class Company(_fixtures.Base):
- pass
- class Person(_fixtures.Base):
- pass
- class Engineer(Person):
- pass
- class Manager(Person):
- pass
- class Boss(Manager):
- pass
- class Machine(_fixtures.Base):
- pass
- class Paperwork(_fixtures.Base):
- pass
+class SynonymTest(QueryTest):
- mapper(Company, companies, properties={
- 'employees':relationship(Person, order_by=people.c.person_id)
+ @classmethod
+ def setup_mappers(cls):
+ mapper(User, users, properties={
+ 'name_syn':synonym('name'),
+ 'addresses':relationship(Address),
+ 'orders':relationship(Order, backref='user'), # o2m, m2o
+ 'orders_syn':synonym('orders')
})
+ mapper(Address, addresses)
+ mapper(Order, orders, properties={
+ 'items':relationship(Item, secondary=order_items), #m2m
+ 'address':relationship(Address), # m2o
+ 'items_syn':synonym('items')
+ })
+ mapper(Item, items, properties={
+ 'keywords':relationship(Keyword, secondary=item_keywords) #m2m
+ })
+ mapper(Keyword, keywords)
- mapper(Machine, machines)
-
- mapper(Person, people,
- polymorphic_on=people.c.type,
- polymorphic_identity='person',
- order_by=people.c.person_id,
- properties={
- 'paperwork':relationship(Paperwork, order_by=paperwork.c.paperwork_id)
- })
- mapper(Engineer, engineers, inherits=Person, polymorphic_identity='engineer', properties={
- 'machines':relationship(Machine, order_by=machines.c.machine_id)
- })
- mapper(Manager, managers,
- inherits=Person, polymorphic_identity='manager')
- mapper(Boss, boss, inherits=Manager, polymorphic_identity='boss')
- mapper(Paperwork, paperwork)
-
- @testing.resolve_artifact_names
- def test_single_prop(self):
- sess = create_session()
-
- self.assert_compile(
- sess.query(Company).join(Company.employees),
- "SELECT companies.company_id AS companies_company_id, companies.name AS companies_name "
- "FROM companies JOIN people ON companies.company_id = people.company_id"
- , use_default_dialect = True
- )
+ def test_joins(self):
+ for j in (
+ ['orders', 'items'],
+ ['orders_syn', 'items'],
+ ['orders', 'items_syn'],
+ ['orders_syn', 'items_syn'],
+ ):
+ result = create_session().query(User).join(*j).filter_by(id=3).all()
+ assert [User(id=7, name='jack'), User(id=9, name='fred')] == result
- @testing.resolve_artifact_names
- def test_force_via_select_from(self):
- sess = create_session()
+ def test_with_parent(self):
+ for nameprop, orderprop in (
+ ('name', 'orders'),
+ ('name_syn', 'orders'),
+ ('name', 'orders_syn'),
+ ('name_syn', 'orders_syn'),
+ ):
+ sess = create_session()
+ q = sess.query(User)
- self.assert_compile(
- sess.query(Company).\
- filter(Company.company_id==Engineer.company_id).\
- filter(Engineer.primary_language=='java'),
- "SELECT companies.company_id AS companies_company_id, companies.name AS companies_name "
- "FROM companies, people, engineers "
- "WHERE companies.company_id = people.company_id AND engineers.primary_language "
- "= :primary_language_1",
- use_default_dialect=True
- )
+ u1 = q.filter_by(**{nameprop:'jack'}).one()
- self.assert_compile(
- sess.query(Company).select_from(Company, Engineer).\
- filter(Company.company_id==Engineer.company_id).\
- filter(Engineer.primary_language=='java'),
- "SELECT companies.company_id AS companies_company_id, companies.name AS companies_name "
- "FROM companies, people JOIN engineers ON people.person_id = engineers.person_id "
- "WHERE companies.company_id = people.company_id AND engineers.primary_language ="
- " :primary_language_1",
- use_default_dialect=True
-
- )
-
- @testing.resolve_artifact_names
- def test_single_prop_of_type(self):
- sess = create_session()
+ o = sess.query(Order).with_parent(u1, property=orderprop).all()
+ assert [Order(description="order 1"), Order(description="order 3"), Order(description="order 5")] == o
- self.assert_compile(
- sess.query(Company).join(Company.employees.of_type(Engineer)),
- "SELECT companies.company_id AS companies_company_id, companies.name AS companies_name "
- "FROM companies JOIN (SELECT people.person_id AS people_person_id, "
- "people.company_id AS people_company_id, people.name AS people_name, "
- "people.type AS people_type, engineers.person_id AS "
- "engineers_person_id, engineers.status AS engineers_status, "
- "engineers.engineer_name AS engineers_engineer_name, "
- "engineers.primary_language AS engineers_primary_language "
- "FROM people JOIN engineers ON people.person_id = engineers.person_id) AS "
- "anon_1 ON companies.company_id = anon_1.people_company_id"
- , use_default_dialect = True
- )
- @testing.resolve_artifact_names
- def test_prop_with_polymorphic(self):
- sess = create_session()
-
- self.assert_compile(
- sess.query(Person).with_polymorphic(Manager).
- join('paperwork').filter(Paperwork.description.like('%review%')),
- "SELECT people.person_id AS people_person_id, people.company_id AS"
- " people_company_id, "
- "people.name AS people_name, people.type AS people_type, managers.person_id "
- "AS managers_person_id, "
- "managers.status AS managers_status, managers.manager_name AS "
- "managers_manager_name FROM people "
- "LEFT OUTER JOIN managers ON people.person_id = managers.person_id JOIN "
- "paperwork ON people.person_id = "
- "paperwork.person_id WHERE paperwork.description LIKE :description_1 "
- "ORDER BY people.person_id"
- , use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(Person).with_polymorphic(Manager).
- join('paperwork', aliased=True).
- filter(Paperwork.description.like('%review%')),
- "SELECT people.person_id AS people_person_id, people.company_id AS people_company_id, "
- "people.name AS people_name, people.type AS people_type, managers.person_id "
- "AS managers_person_id, "
- "managers.status AS managers_status, managers.manager_name AS managers_manager_name "
- "FROM people LEFT OUTER JOIN managers ON people.person_id = managers.person_id JOIN "
- "paperwork AS paperwork_1 ON people.person_id = paperwork_1.person_id "
- "WHERE paperwork_1.description LIKE :description_1 ORDER BY people.person_id"
- , use_default_dialect=True
- )
+class ImmediateTest(_fixtures.FixtureTest):
+ run_inserts = 'once'
+ run_deletes = None
+ @classmethod
@testing.resolve_artifact_names
- def test_explicit_polymorphic_join(self):
- sess = create_session()
-
- self.assert_compile(
- sess.query(Company).join(Engineer).filter(Engineer.engineer_name=='vlad'),
- "SELECT companies.company_id AS companies_company_id, companies.name AS "
- "companies_name "
- "FROM companies JOIN (SELECT people.person_id AS people_person_id, "
- "people.company_id AS "
- "people_company_id, people.name AS people_name, people.type AS people_type,"
- " engineers.person_id AS "
- "engineers_person_id, engineers.status AS engineers_status, "
- "engineers.engineer_name AS engineers_engineer_name, "
- "engineers.primary_language AS engineers_primary_language "
- "FROM people JOIN engineers ON people.person_id = engineers.person_id) "
- "AS anon_1 ON "
- "companies.company_id = anon_1.people_company_id "
- "WHERE anon_1.engineers_engineer_name = :engineer_name_1"
- , use_default_dialect=True
- )
- self.assert_compile(
- sess.query(Company).join(Engineer, Company.company_id==Engineer.company_id).
- filter(Engineer.engineer_name=='vlad'),
- "SELECT companies.company_id AS companies_company_id, companies.name "
- "AS companies_name "
- "FROM companies JOIN (SELECT people.person_id AS people_person_id, "
- "people.company_id AS "
- "people_company_id, people.name AS people_name, people.type AS "
- "people_type, engineers.person_id AS "
- "engineers_person_id, engineers.status AS engineers_status, "
- "engineers.engineer_name AS engineers_engineer_name, "
- "engineers.primary_language AS engineers_primary_language "
- "FROM people JOIN engineers ON people.person_id = engineers.person_id) AS "
- "anon_1 ON "
- "companies.company_id = anon_1.people_company_id "
- "WHERE anon_1.engineers_engineer_name = :engineer_name_1"
- , use_default_dialect=True
- )
+ def setup_mappers(cls):
+ mapper(Address, addresses)
+
+ mapper(User, users, properties=dict(
+ addresses=relationship(Address)))
@testing.resolve_artifact_names
- def test_multiple_adaption(self):
- """test that multiple filter() adapters get chained together "
- and work correctly within a multiple-entry join()."""
-
+ def test_one(self):
sess = create_session()
- self.assert_compile(
- sess.query(Company).join(people.join(engineers), Company.employees).
- filter(Engineer.name=='dilbert'),
- "SELECT companies.company_id AS companies_company_id, companies.name AS "
- "companies_name "
- "FROM companies JOIN (SELECT people.person_id AS people_person_id, "
- "people.company_id AS "
- "people_company_id, people.name AS people_name, people.type AS "
- "people_type, engineers.person_id "
- "AS engineers_person_id, engineers.status AS engineers_status, "
- "engineers.engineer_name AS engineers_engineer_name, "
- "engineers.primary_language AS engineers_primary_language FROM people "
- "JOIN engineers ON people.person_id = "
- "engineers.person_id) AS anon_1 ON companies.company_id = "
- "anon_1.people_company_id WHERE anon_1.people_name = :name_1"
- , use_default_dialect = True
- )
-
- mach_alias = machines.select()
- self.assert_compile(
- sess.query(Company).join(people.join(engineers), Company.employees).
- join(mach_alias, Engineer.machines, from_joinpoint=True).
- filter(Engineer.name=='dilbert').filter(Machine.name=='foo'),
- "SELECT companies.company_id AS companies_company_id, companies.name AS "
- "companies_name "
- "FROM companies JOIN (SELECT people.person_id AS people_person_id, "
- "people.company_id AS "
- "people_company_id, people.name AS people_name, people.type AS people_type,"
- " engineers.person_id "
- "AS engineers_person_id, engineers.status AS engineers_status, "
- "engineers.engineer_name AS engineers_engineer_name, "
- "engineers.primary_language AS engineers_primary_language FROM people "
- "JOIN engineers ON people.person_id = "
- "engineers.person_id) AS anon_1 ON companies.company_id = "
- "anon_1.people_company_id JOIN "
- "(SELECT machines.machine_id AS machine_id, machines.name AS name, "
- "machines.engineer_id AS engineer_id "
- "FROM machines) AS anon_2 ON anon_1.engineers_person_id = anon_2.engineer_id "
- "WHERE anon_1.people_name = :name_1 AND anon_2.name = :name_2"
- , use_default_dialect = True
- )
-
-class AddEntityEquivalenceTest(_base.MappedTest, AssertsCompiledSQL):
- run_setup_mappers = 'once'
-
- @classmethod
- def define_tables(cls, metadata):
- Table('a', metadata,
- Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('name', String(50)),
- Column('type', String(20)),
- Column('bid', Integer, ForeignKey('b.id'))
- )
+ assert_raises(sa.orm.exc.NoResultFound,
+ sess.query(User).filter(User.id == 99).one)
- Table('b', metadata,
- Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('name', String(50)),
- Column('type', String(20))
- )
+ eq_(sess.query(User).filter(User.id == 7).one().id, 7)
- Table('c', metadata,
- Column('id', Integer, ForeignKey('b.id'), primary_key=True),
- Column('age', Integer)
- )
+ assert_raises(sa.orm.exc.MultipleResultsFound,
+ sess.query(User).one)
- Table('d', metadata,
- Column('id', Integer, ForeignKey('a.id'), primary_key=True),
- Column('dede', Integer)
- )
+ assert_raises(
+ sa.orm.exc.NoResultFound,
+ sess.query(User.id, User.name).filter(User.id == 99).one)
- @classmethod
- @testing.resolve_artifact_names
- def setup_classes(cls):
- class A(_fixtures.Base):
- pass
-
- class B(_fixtures.Base):
- pass
-
- class C(B):
- pass
-
- class D(A):
- pass
-
- mapper(A, a,
- polymorphic_identity='a',
- polymorphic_on=a.c.type,
- with_polymorphic= ('*', None),
- properties={
- 'link':relation( B, uselist=False, backref='back')
- })
- mapper(B, b,
- polymorphic_identity='b',
- polymorphic_on=b.c.type,
- with_polymorphic= ('*', None)
- )
- mapper(C, c, inherits=B, polymorphic_identity='c')
- mapper(D, d, inherits=A, polymorphic_identity='d')
-
- @classmethod
- @testing.resolve_artifact_names
- def insert_data(cls):
- sess = create_session()
- sess.add_all([
- B(name='b1'),
- A(name='a1', link= C(name='c1',age=3)),
- C(name='c2',age=6),
- A(name='a2')
- ])
- sess.flush()
-
- @testing.resolve_artifact_names
- def test_add_entity_equivalence(self):
- sess = create_session()
-
- for q in [
- sess.query( A,B).join( A.link),
- sess.query( A).join( A.link).add_entity(B),
- ]:
- eq_(
- q.all(),
- [(
- A(bid=2, id=1, name=u'a1', type=u'a'),
- C(age=3, id=2, name=u'c1', type=u'c')
- )]
- )
+ eq_(sess.query(User.id, User.name).filter(User.id == 7).one(),
+ (7, 'jack'))
- for q in [
- sess.query( B,A).join( B.back),
- sess.query( B).join( B.back).add_entity(A),
- sess.query( B).add_entity(A).join( B.back)
- ]:
- eq_(
- q.all(),
- [(
- C(age=3, id=2, name=u'c1', type=u'c'),
- A(bid=2, id=1, name=u'a1', type=u'a')
- )]
- )
-
-class JoinTest(QueryTest, AssertsCompiledSQL):
-
- def test_single_name(self):
- sess = create_session()
+ assert_raises(sa.orm.exc.MultipleResultsFound,
+ sess.query(User.id, User.name).one)
- self.assert_compile(
- sess.query(User).join("orders"),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM users JOIN orders ON users.id = orders.user_id"
- , use_default_dialect = True
- )
+ assert_raises(sa.orm.exc.NoResultFound,
+ (sess.query(User, Address).
+ join(User.addresses).
+ filter(Address.id == 99)).one)
- assert_raises(
- sa_exc.InvalidRequestError,
- sess.query(User).join, "user",
- )
+ eq_((sess.query(User, Address).
+ join(User.addresses).
+ filter(Address.id == 4)).one(),
+ (User(id=8), Address(id=4)))
- self.assert_compile(
- sess.query(User).join("orders", "items"),
- "SELECT users.id AS users_id, users.name AS users_name FROM users "
- "JOIN orders ON users.id = orders.user_id JOIN order_items AS order_items_1 "
- "ON orders.id = order_items_1.order_id JOIN items ON items.id = order_items_1.item_id"
- , use_default_dialect=True
- )
+ assert_raises(sa.orm.exc.MultipleResultsFound,
+ sess.query(User, Address).join(User.addresses).one)
- # test overlapping paths. User->orders is used by both joins, but rendered once.
- self.assert_compile(
- sess.query(User).join("orders", "items").join("orders", "address"),
- "SELECT users.id AS users_id, users.name AS users_name FROM users JOIN orders "
- "ON users.id = orders.user_id JOIN order_items AS order_items_1 ON orders.id = "
- "order_items_1.order_id JOIN items ON items.id = order_items_1.item_id JOIN addresses "
- "ON addresses.id = orders.address_id"
- , use_default_dialect=True
- )
-
- def test_multi_tuple_form(self):
- """test the 'tuple' form of join, now superceded by the two-element join() form.
-
- Not deprecating this style as of yet.
-
- """
-
- sess = create_session()
-
- #assert_raises(
- # sa.exc.SADeprecationWarning,
- # sess.query(User).join, (Order, User.id==Order.user_id)
- #)
-
- self.assert_compile(
- sess.query(User).join((Order, User.id==Order.user_id)),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM users JOIN orders ON users.id = orders.user_id",
- use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(User).join(
- (Order, User.id==Order.user_id),
- (Item, Order.items)),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM users JOIN orders ON users.id = orders.user_id "
- "JOIN order_items AS order_items_1 ON orders.id = "
- "order_items_1.order_id JOIN items ON items.id = "
- "order_items_1.item_id",
- use_default_dialect=True
- )
-
- # the old "backwards" form
- self.assert_compile(
- sess.query(User).join(("orders", Order)),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM users JOIN orders ON users.id = orders.user_id",
- use_default_dialect=True
- )
-
- def test_single_prop(self):
- sess = create_session()
- self.assert_compile(
- sess.query(User).join(User.orders),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM users JOIN orders ON users.id = orders.user_id"
- , use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(User).join(Order.user),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM orders JOIN users ON users.id = orders.user_id"
- , use_default_dialect=True
- )
-
- oalias1 = aliased(Order)
- oalias2 = aliased(Order)
-
- self.assert_compile(
- sess.query(User).join(oalias1.user),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM orders AS orders_1 JOIN users ON users.id = orders_1.user_id"
- , use_default_dialect=True
- )
-
- # another nonsensical query. (from [ticket:1537]).
- # in this case, the contract of "left to right" is honored
- self.assert_compile(
- sess.query(User).join(oalias1.user).join(oalias2.user),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM orders AS orders_1 JOIN users ON users.id = orders_1.user_id, "
- "orders AS orders_2 JOIN users ON users.id = orders_2.user_id"
- , use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(User).join(User.orders, Order.items),
- "SELECT users.id AS users_id, users.name AS users_name FROM users "
- "JOIN orders ON users.id = orders.user_id JOIN order_items AS order_items_1 "
- "ON orders.id = order_items_1.order_id JOIN items ON items.id = order_items_1.item_id"
- , use_default_dialect=True
- )
-
- ualias = aliased(User)
- self.assert_compile(
- sess.query(ualias).join(ualias.orders),
- "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name "
- "FROM users AS users_1 JOIN orders ON users_1.id = orders.user_id"
- , use_default_dialect=True
- )
-
- # this query is somewhat nonsensical. the old system didn't render a correct
- # query for this. In this case its the most faithful to what was asked -
- # there's no linkage between User.orders and "oalias", so two FROM elements
- # are generated.
- oalias = aliased(Order)
- self.assert_compile(
- sess.query(User).join(User.orders, oalias.items),
- "SELECT users.id AS users_id, users.name AS users_name FROM users "
- "JOIN orders ON users.id = orders.user_id, "
- "orders AS orders_1 JOIN order_items AS order_items_1 ON orders_1.id = order_items_1.order_id "
- "JOIN items ON items.id = order_items_1.item_id"
- , use_default_dialect=True
- )
-
- # same as before using an aliased() for User as well
- ualias = aliased(User)
- self.assert_compile(
- sess.query(ualias).join(ualias.orders, oalias.items),
- "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM users AS users_1 "
- "JOIN orders ON users_1.id = orders.user_id, "
- "orders AS orders_1 JOIN order_items AS order_items_1 ON orders_1.id = order_items_1.order_id "
- "JOIN items ON items.id = order_items_1.item_id"
- , use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(User).filter(User.name=='ed').from_self().join(User.orders),
- "SELECT anon_1.users_id AS anon_1_users_id, anon_1.users_name AS anon_1_users_name "
- "FROM (SELECT users.id AS users_id, users.name AS users_name "
- "FROM users "
- "WHERE users.name = :name_1) AS anon_1 JOIN orders ON anon_1.users_id = orders.user_id"
- , use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(User).join(User.addresses, aliased=True).filter(Address.email_address=='foo'),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM users JOIN addresses AS addresses_1 ON users.id = addresses_1.user_id "
- "WHERE addresses_1.email_address = :email_address_1"
- , use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(User).join(User.orders, Order.items, aliased=True).filter(Item.id==10),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM users JOIN orders AS orders_1 ON users.id = orders_1.user_id "
- "JOIN order_items AS order_items_1 ON orders_1.id = order_items_1.order_id "
- "JOIN items AS items_1 ON items_1.id = order_items_1.item_id "
- "WHERE items_1.id = :id_1"
- , use_default_dialect=True
- )
-
- # test #1 for [ticket:1706]
- ualias = aliased(User)
- self.assert_compile(
- sess.query(ualias).
- join(oalias1, ualias.orders).\
- join(Address, ualias.addresses),
- "SELECT users_1.id AS users_1_id, users_1.name AS "
- "users_1_name FROM users AS users_1 JOIN orders AS orders_1 "
- "ON users_1.id = orders_1.user_id JOIN addresses ON users_1.id "
- "= addresses.user_id"
- , use_default_dialect=True
- )
-
- # test #2 for [ticket:1706]
- ualias2 = aliased(User)
- self.assert_compile(
- sess.query(ualias).
- join(Address, ualias.addresses).
- join(ualias2, Address.user).
- join(Order, ualias.orders),
- "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM users "
- "AS users_1 JOIN addresses ON users_1.id = addresses.user_id JOIN users AS users_2 "
- "ON users_2.id = addresses.user_id JOIN orders ON users_1.id = orders.user_id"
- , use_default_dialect=True
- )
-
- def test_overlapping_paths(self):
- for aliased in (True,False):
- # load a user who has an order that contains item id 3 and address id 1 (order 3, owned by jack)
- result = create_session().query(User).join('orders', 'items', aliased=aliased).\
- filter_by(id=3).join('orders','address', aliased=aliased).filter_by(id=1).all()
- assert [User(id=7, name='jack')] == result
-
- def test_overlapping_paths_outerjoin(self):
- result = create_session().query(User).outerjoin('orders', 'items').\
- filter_by(id=3).outerjoin('orders','address').filter_by(id=1).all()
- assert [User(id=7, name='jack')] == result
-
- def test_from_joinpoint(self):
- sess = create_session()
-
- for oalias,ialias in [(True, True), (False, False), (True, False), (False, True)]:
- eq_(
- sess.query(User).join('orders', aliased=oalias).\
- join('items',
- from_joinpoint=True,
- aliased=ialias).\
- filter(Item.description == 'item 4').all(),
- [User(name='jack')]
- )
-
- # use middle criterion
- eq_(
- sess.query(User).join('orders', aliased=oalias).\
- filter(Order.user_id==9).\
- join('items', from_joinpoint=True,
- aliased=ialias).\
- filter(Item.description=='item 4').all(),
- []
- )
-
- orderalias = aliased(Order)
- itemalias = aliased(Item)
- eq_(
- sess.query(User).join(orderalias, 'orders').
- join(itemalias, 'items', from_joinpoint=True).
- filter(itemalias.description == 'item 4').all(),
- [User(name='jack')]
- )
- eq_(
- sess.query(User).join(orderalias, 'orders').
- join(itemalias, 'items', from_joinpoint=True).
- filter(orderalias.user_id==9).\
- filter(itemalias.description=='item 4').all(),
- []
- )
-
- def test_join_nonmapped_column(self):
- """test that the search for a 'left' doesn't trip on non-mapped cols"""
- sess = create_session()
-
- # intentionally join() with a non-existent "left" side
- self.assert_compile(
- sess.query(User.id, literal_column('foo')).join(Order.user),
- "SELECT users.id AS users_id, foo FROM "
- "orders JOIN users ON users.id = orders.user_id"
- , use_default_dialect=True
- )
-
-
-
- def test_backwards_join(self):
- # a more controversial feature. join from
- # User->Address, but the onclause is Address.user.
-
- sess = create_session()
-
- eq_(
- sess.query(User).join(Address.user).\
- filter(Address.email_address=='ed@wood.com').all(),
- [User(id=8,name=u'ed')]
- )
-
- # its actually not so controversial if you view it in terms
- # of multiple entities.
- eq_(
- sess.query(User, Address).join(Address.user).filter(Address.email_address=='ed@wood.com').all(),
- [(User(id=8,name=u'ed'), Address(email_address='ed@wood.com'))]
- )
-
- # this was the controversial part. now, raise an error if the feature is abused.
- # before the error raise was added, this would silently work.....
- assert_raises(
- sa_exc.InvalidRequestError,
- sess.query(User).join, Address, Address.user,
- )
-
- # but this one would silently fail
- adalias = aliased(Address)
- assert_raises(
- sa_exc.InvalidRequestError,
- sess.query(User).join, adalias, Address.user,
- )
-
- def test_multiple_with_aliases(self):
- sess = create_session()
-
- ualias = aliased(User)
- oalias1 = aliased(Order)
- oalias2 = aliased(Order)
- self.assert_compile(
- sess.query(ualias).join(oalias1, ualias.orders).
- join(oalias2, ualias.orders).
- filter(or_(oalias1.user_id==9, oalias2.user_id==7)),
- "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM users AS users_1 "
- "JOIN orders AS orders_1 ON users_1.id = orders_1.user_id JOIN orders AS orders_2 ON "
- "users_1.id = orders_2.user_id WHERE orders_1.user_id = :user_id_1 OR orders_2.user_id = :user_id_2",
- use_default_dialect=True
- )
-
- def test_select_from_orm_joins(self):
- sess = create_session()
-
- ualias = aliased(User)
- oalias1 = aliased(Order)
- oalias2 = aliased(Order)
-
- self.assert_compile(
- join(User, oalias2, User.id==oalias2.user_id),
- "users JOIN orders AS orders_1 ON users.id = orders_1.user_id",
- use_default_dialect=True
- )
-
- self.assert_compile(
- join(ualias, oalias1, ualias.orders),
- "users AS users_1 JOIN orders AS orders_1 ON users_1.id = orders_1.user_id",
- use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(ualias).select_from(join(ualias, oalias1, ualias.orders)),
- "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM users AS users_1 "
- "JOIN orders AS orders_1 ON users_1.id = orders_1.user_id",
- use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(User, ualias).select_from(join(ualias, oalias1, ualias.orders)),
- "SELECT users.id AS users_id, users.name AS users_name, users_1.id AS users_1_id, "
- "users_1.name AS users_1_name FROM users, users AS users_1 JOIN orders AS orders_1 ON users_1.id = orders_1.user_id",
- use_default_dialect=True
- )
-
- # this fails (and we cant quite fix right now).
- if False:
- self.assert_compile(
- sess.query(User, ualias).\
- join(oalias1, ualias.orders).\
- join(oalias2, User.id==oalias2.user_id).\
- filter(or_(oalias1.user_id==9, oalias2.user_id==7)),
- "SELECT users.id AS users_id, users.name AS users_name, users_1.id AS users_1_id, users_1.name AS "
- "users_1_name FROM users JOIN orders AS orders_2 ON users.id = orders_2.user_id, "
- "users AS users_1 JOIN orders AS orders_1 ON users_1.id = orders_1.user_id "
- "WHERE orders_1.user_id = :user_id_1 OR orders_2.user_id = :user_id_2",
- use_default_dialect=True
- )
-
- # this is the same thing using explicit orm.join() (which now offers multiple again)
- self.assert_compile(
- sess.query(User, ualias).\
- select_from(
- join(ualias, oalias1, ualias.orders),
- join(User, oalias2, User.id==oalias2.user_id),
- ).\
- filter(or_(oalias1.user_id==9, oalias2.user_id==7)),
- "SELECT users.id AS users_id, users.name AS users_name, users_1.id AS users_1_id, users_1.name AS "
- "users_1_name FROM users AS users_1 JOIN orders AS orders_1 ON users_1.id = orders_1.user_id, "
- "users JOIN orders AS orders_2 ON users.id = orders_2.user_id "
- "WHERE orders_1.user_id = :user_id_1 OR orders_2.user_id = :user_id_2",
-
- use_default_dialect=True
- )
-
-
- def test_overlapping_backwards_joins(self):
- sess = create_session()
-
- oalias1 = aliased(Order)
- oalias2 = aliased(Order)
-
- # this is invalid SQL - joins from orders_1/orders_2 to User twice.
- # but that is what was asked for so they get it !
- self.assert_compile(
- sess.query(User).join(oalias1.user).join(oalias2.user),
- "SELECT users.id AS users_id, users.name AS users_name FROM orders AS orders_1 "
- "JOIN users ON users.id = orders_1.user_id, orders AS orders_2 JOIN users ON users.id = orders_2.user_id",
- use_default_dialect=True,
- )
-
- def test_replace_multiple_from_clause(self):
- """test adding joins onto multiple FROM clauses"""
-
- sess = create_session()
-
- self.assert_compile(
- sess.query(Address, User).join(Address.dingaling).join(User.orders, Order.items),
- "SELECT addresses.id AS addresses_id, addresses.user_id AS addresses_user_id, "
- "addresses.email_address AS addresses_email_address, users.id AS users_id, "
- "users.name AS users_name FROM addresses JOIN dingalings ON addresses.id = dingalings.address_id, "
- "users JOIN orders ON users.id = orders.user_id JOIN order_items AS order_items_1 "
- "ON orders.id = order_items_1.order_id JOIN items ON items.id = order_items_1.item_id",
- use_default_dialect = True
- )
-
- def test_multiple_adaption(self):
- sess = create_session()
-
- self.assert_compile(
- sess.query(User).join(User.orders, Order.items, aliased=True).filter(Order.id==7).filter(Item.id==8),
- "SELECT users.id AS users_id, users.name AS users_name FROM users JOIN orders AS orders_1 "
- "ON users.id = orders_1.user_id JOIN order_items AS order_items_1 ON orders_1.id = order_items_1.order_id "
- "JOIN items AS items_1 ON items_1.id = order_items_1.item_id WHERE orders_1.id = :id_1 AND items_1.id = :id_2",
- use_default_dialect=True
- )
-
- def test_onclause_conditional_adaption(self):
- sess = create_session()
-
- # this is now a very weird test, nobody should really
- # be using the aliased flag in this way.
- self.assert_compile(
- sess.query(User).join(User.orders, aliased=True).
- join(Item,
- and_(Order.id==order_items.c.order_id, order_items.c.item_id==Item.id),
- from_joinpoint=True, aliased=True
- ),
- "SELECT users.id AS users_id, users.name AS users_name FROM users JOIN "
- "orders AS orders_1 ON users.id = orders_1.user_id JOIN items AS items_1 "
- "ON orders_1.id = order_items.order_id AND order_items.item_id = items_1.id",
- use_default_dialect=True
- )
-
-
- oalias = orders.select()
- self.assert_compile(
- sess.query(User).join(oalias, User.orders).
- join(Item,
- and_(Order.id==order_items.c.order_id, order_items.c.item_id==Item.id),
- from_joinpoint=True
- ),
- "SELECT users.id AS users_id, users.name AS users_name FROM users JOIN "
- "(SELECT orders.id AS id, orders.user_id AS user_id, orders.address_id AS address_id, orders.description "
- "AS description, orders.isopen AS isopen FROM orders) AS anon_1 ON users.id = anon_1.user_id JOIN items "
- "ON anon_1.id = order_items.order_id AND order_items.item_id = items.id",
- use_default_dialect=True
- )
-
- # query.join(<stuff>, aliased=True).join(target, sql_expression)
- # or: query.join(path_to_some_joined_table_mapper).join(target, sql_expression)
-
- def test_pure_expression_error(self):
- sess = create_session()
-
- assert_raises_message(sa.exc.InvalidRequestError, "Could not find a FROM clause to join from", sess.query(users).join, addresses)
-
-
- def test_orderby_arg_bug(self):
- sess = create_session()
- # no arg error
- result = sess.query(User).join('orders', aliased=True).order_by(Order.id).reset_joinpoint().order_by(users.c.id).all()
-
- def test_no_onclause(self):
- sess = create_session()
-
- eq_(
- sess.query(User).select_from(join(User, Order).join(Item, Order.items)).filter(Item.description == 'item 4').all(),
- [User(name='jack')]
- )
-
- eq_(
- sess.query(User.name).select_from(join(User, Order).join(Item, Order.items)).filter(Item.description == 'item 4').all(),
- [('jack',)]
- )
-
- eq_(
- sess.query(User).join(Order).join(Item, Order.items)
- .filter(Item.description == 'item 4').all(),
- [User(name='jack')]
- )
-
- def test_clause_onclause(self):
- sess = create_session()
-
- eq_(
- sess.query(User).join(Order, User.id==Order.user_id).
- join(order_items, Order.id==order_items.c.order_id).
- join(Item, order_items.c.item_id==Item.id).
- filter(Item.description == 'item 4').all(),
- [User(name='jack')]
- )
-
- eq_(
- sess.query(User.name).join(Order, User.id==Order.user_id).
- join(order_items, Order.id==order_items.c.order_id).
- join(Item, order_items.c.item_id==Item.id).
- filter(Item.description == 'item 4').all(),
- [('jack',)]
- )
-
- ualias = aliased(User)
- eq_(
- sess.query(ualias.name).join(Order, ualias.id==Order.user_id).
- join(order_items, Order.id==order_items.c.order_id).
- join(Item, order_items.c.item_id==Item.id).
- filter(Item.description == 'item 4').all(),
- [('jack',)]
- )
-
- # explicit onclause with from_self(), means
- # the onclause must be aliased against the query's custom
- # FROM object
- eq_(
- sess.query(User).order_by(User.id).offset(2).
- from_self().
- join(Order, User.id==Order.user_id).
- all(),
- [User(name='fred')]
- )
-
- # same with an explicit select_from()
- eq_(
- sess.query(User).select_from(select([users]).
- order_by(User.id).offset(2).alias()).
- join(Order, User.id==Order.user_id).
- all(),
- [User(name='fred')]
- )
-
-
- def test_aliased_classes(self):
- sess = create_session()
-
- (user7, user8, user9, user10) = sess.query(User).all()
- (address1, address2, address3, address4, address5) = sess.query(Address).all()
- expected = [(user7, address1),
- (user8, address2),
- (user8, address3),
- (user8, address4),
- (user9, address5),
- (user10, None)]
-
- q = sess.query(User)
- AdAlias = aliased(Address)
- q = q.add_entity(AdAlias).select_from(outerjoin(User, AdAlias))
- l = q.order_by(User.id, AdAlias.id).all()
- eq_(l, expected)
-
- sess.expunge_all()
-
- q = sess.query(User).add_entity(AdAlias)
- l = q.select_from(outerjoin(User, AdAlias)).filter(AdAlias.email_address=='ed@bettyboop.com').all()
- eq_(l, [(user8, address3)])
-
- l = q.select_from(outerjoin(User, AdAlias, 'addresses')).filter(AdAlias.email_address=='ed@bettyboop.com').all()
- eq_(l, [(user8, address3)])
-
- l = q.select_from(outerjoin(User, AdAlias, User.id==AdAlias.user_id)).filter(AdAlias.email_address=='ed@bettyboop.com').all()
- eq_(l, [(user8, address3)])
-
- # this is the first test where we are joining "backwards" - from AdAlias to User even though
- # the query is against User
- q = sess.query(User, AdAlias)
- l = q.join(AdAlias.user).filter(User.name=='ed')
- eq_(l.all(), [(user8, address2),(user8, address3),(user8, address4),])
-
- q = sess.query(User, AdAlias).select_from(join(AdAlias, User, AdAlias.user)).filter(User.name=='ed')
- eq_(l.all(), [(user8, address2),(user8, address3),(user8, address4),])
-
- def test_expression_onclauses(self):
- sess = create_session()
-
- subq = sess.query(User).subquery()
-
- self.assert_compile(
- sess.query(User).join(subq, User.name==subq.c.name),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM users JOIN (SELECT users.id AS id, users.name "
- "AS name FROM users) AS anon_1 ON users.name = anon_1.name",
- use_default_dialect=True
- )
-
-
- subq = sess.query(Order).subquery()
- self.assert_compile(
- sess.query(User).join(subq, User.id==subq.c.user_id),
- "SELECT users.id AS users_id, users.name AS users_name FROM "
- "users JOIN (SELECT orders.id AS id, orders.user_id AS user_id, "
- "orders.address_id AS address_id, orders.description AS "
- "description, orders.isopen AS isopen FROM orders) AS "
- "anon_1 ON users.id = anon_1.user_id",
- use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(User).join(Order, User.id==Order.user_id),
- "SELECT users.id AS users_id, users.name AS users_name "
- "FROM users JOIN orders ON users.id = orders.user_id",
- use_default_dialect=True
- )
-
-
- def test_implicit_joins_from_aliases(self):
- sess = create_session()
- OrderAlias = aliased(Order)
-
- eq_(
- sess.query(OrderAlias).join('items').filter_by(description='item 3').\
- order_by(OrderAlias.id).all(),
- [
- Order(address_id=1,description=u'order 1',isopen=0,user_id=7,id=1),
- Order(address_id=4,description=u'order 2',isopen=0,user_id=9,id=2),
- Order(address_id=1,description=u'order 3',isopen=1,user_id=7,id=3)
- ]
- )
-
- eq_(
- sess.query(User, OrderAlias, Item.description).
- join(OrderAlias, 'orders').
- join('items', from_joinpoint=True).
- filter_by(description='item 3').\
- order_by(User.id, OrderAlias.id).all(),
- [
- (User(name=u'jack',id=7), Order(address_id=1,description=u'order 1',isopen=0,user_id=7,id=1), u'item 3'),
- (User(name=u'jack',id=7), Order(address_id=1,description=u'order 3',isopen=1,user_id=7,id=3), u'item 3'),
- (User(name=u'fred',id=9), Order(address_id=4,description=u'order 2',isopen=0,user_id=9,id=2), u'item 3')
- ]
- )
-
- def test_aliased_classes_m2m(self):
- sess = create_session()
-
- (order1, order2, order3, order4, order5) = sess.query(Order).all()
- (item1, item2, item3, item4, item5) = sess.query(Item).all()
- expected = [
- (order1, item1),
- (order1, item2),
- (order1, item3),
- (order2, item1),
- (order2, item2),
- (order2, item3),
- (order3, item3),
- (order3, item4),
- (order3, item5),
- (order4, item1),
- (order4, item5),
- (order5, item5),
- ]
-
- q = sess.query(Order)
- q = q.add_entity(Item).select_from(join(Order, Item, 'items')).order_by(Order.id, Item.id)
- l = q.all()
- eq_(l, expected)
-
- IAlias = aliased(Item)
- q = sess.query(Order, IAlias).select_from(join(Order, IAlias, 'items')).filter(IAlias.description=='item 3')
- l = q.all()
- eq_(l,
- [
- (order1, item3),
- (order2, item3),
- (order3, item3),
- ]
- )
-
- def test_joins_from_adapted_entities(self):
-
- # test for #1853
-
- session = create_session()
- first = session.query(User)
- second = session.query(User)
- unioned = first.union(second)
- subquery = session.query(User.id).subquery()
- join = subquery, subquery.c.id == User.id
- joined = unioned.outerjoin(*join)
- self.assert_compile(joined,
- 'SELECT anon_1.users_id AS '
- 'anon_1_users_id, anon_1.users_name AS '
- 'anon_1_users_name FROM (SELECT users.id '
- 'AS users_id, users.name AS users_name '
- 'FROM users UNION SELECT users.id AS '
- 'users_id, users.name AS users_name FROM '
- 'users) AS anon_1 LEFT OUTER JOIN (SELECT '
- 'users.id AS id FROM users) AS anon_2 ON '
- 'anon_2.id = anon_1.users_id',
- use_default_dialect=True)
-
- first = session.query(User.id)
- second = session.query(User.id)
- unioned = first.union(second)
- subquery = session.query(User.id).subquery()
- join = subquery, subquery.c.id == User.id
- joined = unioned.outerjoin(*join)
- self.assert_compile(joined,
- 'SELECT anon_1.users_id AS anon_1_users_id '
- 'FROM (SELECT users.id AS users_id FROM '
- 'users UNION SELECT users.id AS users_id '
- 'FROM users) AS anon_1 LEFT OUTER JOIN '
- '(SELECT users.id AS id FROM users) AS '
- 'anon_2 ON anon_2.id = anon_1.users_id',
- use_default_dialect=True)
-
- def test_reset_joinpoint(self):
- for aliased in (True, False):
- # load a user who has an order that contains item id 3 and address id 1 (order 3, owned by jack)
- result = create_session().query(User).join('orders', 'items', aliased=aliased).filter_by(id=3).reset_joinpoint().join('orders','address', aliased=aliased).filter_by(id=1).all()
- assert [User(id=7, name='jack')] == result
-
- result = create_session().query(User).outerjoin('orders', 'items', aliased=aliased).filter_by(id=3).reset_joinpoint().outerjoin('orders','address', aliased=aliased).filter_by(id=1).all()
- assert [User(id=7, name='jack')] == result
-
- def test_overlap_with_aliases(self):
- oalias = orders.alias('oalias')
-
- result = create_session().query(User).select_from(users.join(oalias)).filter(oalias.c.description.in_(["order 1", "order 2", "order 3"])).join('orders', 'items').order_by(User.id).all()
- assert [User(id=7, name='jack'), User(id=9, name='fred')] == result
-
- result = create_session().query(User).select_from(users.join(oalias)).filter(oalias.c.description.in_(["order 1", "order 2", "order 3"])).join('orders', 'items').filter_by(id=4).all()
- assert [User(id=7, name='jack')] == result
-
- def test_aliased(self):
- """test automatic generation of aliased joins."""
-
- sess = create_session()
-
- # test a basic aliasized path
- q = sess.query(User).join('addresses', aliased=True).filter_by(email_address='jack@bean.com')
- assert [User(id=7)] == q.all()
-
- q = sess.query(User).join('addresses', aliased=True).filter(Address.email_address=='jack@bean.com')
- assert [User(id=7)] == q.all()
-
- q = sess.query(User).join('addresses', aliased=True).filter(or_(Address.email_address=='jack@bean.com', Address.email_address=='fred@fred.com'))
- assert [User(id=7), User(id=9)] == q.all()
-
- # test two aliasized paths, one to 'orders' and the other to 'orders','items'.
- # one row is returned because user 7 has order 3 and also has order 1 which has item 1
- # this tests a o2m join and a m2m join.
- q = sess.query(User).join('orders', aliased=True).filter(Order.description=="order 3").join('orders', 'items', aliased=True).filter(Item.description=="item 1")
- assert q.count() == 1
- assert [User(id=7)] == q.all()
-
- # test the control version - same joins but not aliased. rows are not returned because order 3 does not have item 1
- q = sess.query(User).join('orders').filter(Order.description=="order 3").join('orders', 'items').filter(Item.description=="item 1")
- assert [] == q.all()
- assert q.count() == 0
-
- # the left half of the join condition of the any() is aliased.
- q = sess.query(User).join('orders', aliased=True).filter(Order.items.any(Item.description=='item 4'))
- assert [User(id=7)] == q.all()
-
- # test that aliasing gets reset when join() is called
- q = sess.query(User).join('orders', aliased=True).filter(Order.description=="order 3").join('orders', aliased=True).filter(Order.description=="order 5")
- assert q.count() == 1
- assert [User(id=7)] == q.all()
-
- def test_aliased_order_by(self):
- sess = create_session()
-
- ualias = aliased(User)
- eq_(
- sess.query(User, ualias).filter(User.id > ualias.id).order_by(desc(ualias.id), User.name).all(),
- [
- (User(id=10,name=u'chuck'), User(id=9,name=u'fred')),
- (User(id=10,name=u'chuck'), User(id=8,name=u'ed')),
- (User(id=9,name=u'fred'), User(id=8,name=u'ed')),
- (User(id=10,name=u'chuck'), User(id=7,name=u'jack')),
- (User(id=8,name=u'ed'), User(id=7,name=u'jack')),
- (User(id=9,name=u'fred'), User(id=7,name=u'jack'))
- ]
- )
-
- def test_plain_table(self):
-
- sess = create_session()
-
- eq_(
- sess.query(User.name).join(addresses, User.id==addresses.c.user_id).order_by(User.id).all(),
- [(u'jack',), (u'ed',), (u'ed',), (u'ed',), (u'fred',)]
- )
-
- def test_no_joinpoint_expr(self):
- sess = create_session()
-
- # these are consistent regardless of
- # select_from() being present.
-
- assert_raises_message(
- sa_exc.InvalidRequestError,
- "Could not find a FROM",
- sess.query(users.c.id).join, User
- )
-
- assert_raises_message(
- sa_exc.InvalidRequestError,
- "Could not find a FROM",
- sess.query(users.c.id).select_from(users).join, User
- )
-
- def test_select_from(self):
- """Test that the left edge of the join can be set reliably with select_from()."""
-
- sess = create_session()
- self.assert_compile(
- sess.query(Item.id).select_from(User).join(User.orders).join(Order.items),
- "SELECT items.id AS items_id FROM users JOIN orders ON "
- "users.id = orders.user_id JOIN order_items AS order_items_1 "
- "ON orders.id = order_items_1.order_id JOIN items ON items.id = "
- "order_items_1.item_id",
- use_default_dialect=True
- )
-
- # here, the join really wants to add a second FROM clause
- # for "Item". but select_from disallows that
- self.assert_compile(
- sess.query(Item.id).select_from(User).join(Item, User.id==Item.id),
- "SELECT items.id AS items_id FROM users JOIN items ON users.id = items.id",
- use_default_dialect=True
- )
-
-
-
-
- def test_from_self_resets_joinpaths(self):
- """test a join from from_self() doesn't confuse joins inside the subquery
- with the outside.
- """
- sess = create_session()
-
- self.assert_compile(
- sess.query(Item).join(Item.keywords).from_self(Keyword).join(Item.keywords),
- "SELECT keywords.id AS keywords_id, keywords.name AS keywords_name FROM "
- "(SELECT items.id AS items_id, items.description AS items_description "
- "FROM items JOIN item_keywords AS item_keywords_1 ON items.id = "
- "item_keywords_1.item_id JOIN keywords ON keywords.id = item_keywords_1.keyword_id) "
- "AS anon_1 JOIN item_keywords AS item_keywords_2 ON "
- "anon_1.items_id = item_keywords_2.item_id "
- "JOIN keywords ON "
- "keywords.id = item_keywords_2.keyword_id",
- use_default_dialect=True
- )
-
-
-class MultiplePathTest(_base.MappedTest, AssertsCompiledSQL):
- @classmethod
- def define_tables(cls, metadata):
- global t1, t2, t1t2_1, t1t2_2
- t1 = Table('t1', metadata,
- Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('data', String(30))
- )
- t2 = Table('t2', metadata,
- Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('data', String(30))
- )
-
- t1t2_1 = Table('t1t2_1', metadata,
- Column('t1id', Integer, ForeignKey('t1.id')),
- Column('t2id', Integer, ForeignKey('t2.id'))
- )
-
- t1t2_2 = Table('t1t2_2', metadata,
- Column('t1id', Integer, ForeignKey('t1.id')),
- Column('t2id', Integer, ForeignKey('t2.id'))
- )
-
- def test_basic(self):
- class T1(object):pass
- class T2(object):pass
-
- mapper(T1, t1, properties={
- 't2s_1':relationship(T2, secondary=t1t2_1),
- 't2s_2':relationship(T2, secondary=t1t2_2),
- })
- mapper(T2, t2)
-
- q = create_session().query(T1).join('t2s_1').filter(t2.c.id==5).reset_joinpoint().join('t2s_2')
- self.assert_compile(
- q,
- "SELECT t1.id AS t1_id, t1.data AS t1_data FROM t1 JOIN t1t2_1 AS t1t2_1_1 "
- "ON t1.id = t1t2_1_1.t1id JOIN t2 ON t2.id = t1t2_1_1.t2id JOIN t1t2_2 AS t1t2_2_1 "
- "ON t1.id = t1t2_2_1.t1id JOIN t2 ON t2.id = t1t2_2_1.t2id WHERE t2.id = :id_1"
- , use_default_dialect=True
- )
-
-
-class SynonymTest(QueryTest):
-
- @classmethod
- def setup_mappers(cls):
- mapper(User, users, properties={
- 'name_syn':synonym('name'),
- 'addresses':relationship(Address),
- 'orders':relationship(Order, backref='user'), # o2m, m2o
- 'orders_syn':synonym('orders')
- })
- mapper(Address, addresses)
- mapper(Order, orders, properties={
- 'items':relationship(Item, secondary=order_items), #m2m
- 'address':relationship(Address), # m2o
- 'items_syn':synonym('items')
- })
- mapper(Item, items, properties={
- 'keywords':relationship(Keyword, secondary=item_keywords) #m2m
- })
- mapper(Keyword, keywords)
-
- def test_joins(self):
- for j in (
- ['orders', 'items'],
- ['orders_syn', 'items'],
- ['orders', 'items_syn'],
- ['orders_syn', 'items_syn'],
- ):
- result = create_session().query(User).join(*j).filter_by(id=3).all()
- assert [User(id=7, name='jack'), User(id=9, name='fred')] == result
-
- def test_with_parent(self):
- for nameprop, orderprop in (
- ('name', 'orders'),
- ('name_syn', 'orders'),
- ('name', 'orders_syn'),
- ('name_syn', 'orders_syn'),
- ):
- sess = create_session()
- q = sess.query(User)
-
- u1 = q.filter_by(**{nameprop:'jack'}).one()
-
- o = sess.query(Order).with_parent(u1, property=orderprop).all()
- assert [Order(description="order 1"), Order(description="order 3"), Order(description="order 5")] == o
-
-class InstancesTest(QueryTest, AssertsCompiledSQL):
-
- def test_from_alias(self):
-
- query = users.select(users.c.id==7).\
- union(users.select(users.c.id>7)).\
- alias('ulist').\
- outerjoin(addresses).\
- select(use_labels=True,
- order_by=['ulist.id', addresses.c.id])
- sess =create_session()
- q = sess.query(User)
-
- def go():
- l = list(q.options(contains_alias('ulist'),
- contains_eager('addresses')).\
- instances(query.execute()))
- assert self.static.user_address_result == l
- self.assert_sql_count(testing.db, go, 1)
-
- sess.expunge_all()
-
- def go():
- l = q.options(contains_alias('ulist'),
- contains_eager('addresses')).\
- from_statement(query).all()
- assert self.static.user_address_result == l
- self.assert_sql_count(testing.db, go, 1)
-
- # better way. use select_from()
- def go():
- l = sess.query(User).select_from(query).\
- options(contains_eager('addresses')).all()
- assert self.static.user_address_result == l
- self.assert_sql_count(testing.db, go, 1)
-
- # same thing, but alias addresses, so that the adapter
- # generated by select_from() is wrapped within
- # the adapter created by contains_eager()
- adalias = addresses.alias()
- query = users.select(users.c.id==7).\
- union(users.select(users.c.id>7)).\
- alias('ulist').\
- outerjoin(adalias).\
- select(use_labels=True,
- order_by=['ulist.id', adalias.c.id])
- def go():
- l = sess.query(User).select_from(query).\
- options(contains_eager('addresses', alias=adalias)).all()
- assert self.static.user_address_result == l
- self.assert_sql_count(testing.db, go, 1)
-
- def test_contains_eager(self):
- sess = create_session()
-
- # test that contains_eager suppresses the normal outer join rendering
- q = sess.query(User).outerjoin(User.addresses).\
- options(contains_eager(User.addresses)).\
- order_by(User.id, addresses.c.id)
- self.assert_compile(q.with_labels().statement,
- 'SELECT addresses.id AS addresses_id, '
- 'addresses.user_id AS addresses_user_id, '
- 'addresses.email_address AS '
- 'addresses_email_address, users.id AS '
- 'users_id, users.name AS users_name FROM '
- 'users LEFT OUTER JOIN addresses ON '
- 'users.id = addresses.user_id ORDER BY '
- 'users.id, addresses.id',
- dialect=default.DefaultDialect())
-
- def go():
- assert self.static.user_address_result == q.all()
- self.assert_sql_count(testing.db, go, 1)
- sess.expunge_all()
-
- adalias = addresses.alias()
- q = sess.query(User).select_from(users.outerjoin(adalias)).options(contains_eager(User.addresses, alias=adalias)).order_by(User.id, adalias.c.id)
- def go():
- eq_(self.static.user_address_result, q.order_by(User.id).all())
- self.assert_sql_count(testing.db, go, 1)
- sess.expunge_all()
-
- selectquery = users.outerjoin(addresses).select(users.c.id<10, use_labels=True, order_by=[users.c.id, addresses.c.id])
- q = sess.query(User)
-
- def go():
- l = list(q.options(contains_eager('addresses')).instances(selectquery.execute()))
- assert self.static.user_address_result[0:3] == l
- self.assert_sql_count(testing.db, go, 1)
-
- sess.expunge_all()
-
- def go():
- l = list(q.options(contains_eager(User.addresses)).instances(selectquery.execute()))
- assert self.static.user_address_result[0:3] == l
- self.assert_sql_count(testing.db, go, 1)
- sess.expunge_all()
-
- def go():
- l = q.options(contains_eager('addresses')).from_statement(selectquery).all()
- assert self.static.user_address_result[0:3] == l
- self.assert_sql_count(testing.db, go, 1)
-
- def test_contains_eager_alias(self):
- adalias = addresses.alias('adalias')
- selectquery = users.outerjoin(adalias).select(use_labels=True, order_by=[users.c.id, adalias.c.id])
- sess = create_session()
- q = sess.query(User)
-
- # string alias name
- def go():
- l = list(q.options(contains_eager('addresses', alias="adalias")).instances(selectquery.execute()))
- assert self.static.user_address_result == l
- self.assert_sql_count(testing.db, go, 1)
- sess.expunge_all()
-
- # expression.Alias object
- def go():
- l = list(q.options(contains_eager('addresses', alias=adalias)).instances(selectquery.execute()))
- assert self.static.user_address_result == l
- self.assert_sql_count(testing.db, go, 1)
-
- sess.expunge_all()
-
- # Aliased object
- adalias = aliased(Address)
- def go():
- l = q.options(contains_eager('addresses', alias=adalias)).outerjoin(adalias, User.addresses).order_by(User.id, adalias.id)
- assert self.static.user_address_result == l.all()
- self.assert_sql_count(testing.db, go, 1)
- sess.expunge_all()
-
- oalias = orders.alias('o1')
- ialias = items.alias('i1')
- query = users.outerjoin(oalias).outerjoin(order_items).outerjoin(ialias).select(use_labels=True).order_by(users.c.id, oalias.c.id, ialias.c.id)
- q = create_session().query(User)
- # test using string alias with more than one level deep
- def go():
- l = list(q.options(contains_eager('orders', alias='o1'), contains_eager('orders.items', alias='i1')).instances(query.execute()))
- assert self.static.user_order_result == l
- self.assert_sql_count(testing.db, go, 1)
-
- sess.expunge_all()
-
- # test using Alias with more than one level deep
- def go():
- l = list(q.options(contains_eager('orders', alias=oalias), contains_eager('orders.items', alias=ialias)).instances(query.execute()))
- assert self.static.user_order_result == l
- self.assert_sql_count(testing.db, go, 1)
- sess.expunge_all()
-
- # test using Aliased with more than one level deep
- oalias = aliased(Order)
- ialias = aliased(Item)
- def go():
- l = q.options(contains_eager(User.orders, alias=oalias),
- contains_eager(User.orders, Order.items, alias=ialias)).\
- outerjoin(oalias, User.orders).\
- outerjoin(ialias, oalias.items).order_by(User.id, oalias.id, ialias.id)
- assert self.static.user_order_result == l.all()
- self.assert_sql_count(testing.db, go, 1)
- sess.expunge_all()
-
- def test_mixed_eager_contains_with_limit(self):
- sess = create_session()
-
- q = sess.query(User)
- def go():
- # outerjoin to User.orders, offset 1/limit 2 so we get user
- # 7 + second two orders. then joinedload the addresses.
- # User + Order columns go into the subquery, address left
- # outer joins to the subquery, joinedloader for User.orders
- # applies context.adapter to result rows. This was
- # [ticket:1180].
-
- l = \
- q.outerjoin(User.orders).options(joinedload(User.addresses),
- contains_eager(User.orders)).order_by(User.id,
- Order.id).offset(1).limit(2).all()
- eq_(l, [User(id=7,
- addresses=[Address(email_address=u'jack@bean.com',
- user_id=7, id=1)], name=u'jack',
- orders=[Order(address_id=1, user_id=7,
- description=u'order 3', isopen=1, id=3),
- Order(address_id=None, user_id=7, description=u'order 5'
- , isopen=0, id=5)])])
-
- self.assert_sql_count(testing.db, go, 1)
- sess.expunge_all()
-
- def go():
-
- # same as above, except Order is aliased, so two adapters
- # are applied by the eager loader
-
- oalias = aliased(Order)
- l = q.outerjoin(oalias, User.orders).\
- options(joinedload(User.addresses),
- contains_eager(User.orders, alias=oalias)).\
- order_by(User.id, oalias.id).\
- offset(1).limit(2).all()
- eq_(l, [User(id=7,
- addresses=[Address(email_address=u'jack@bean.com',
- user_id=7, id=1)], name=u'jack',
- orders=[Order(address_id=1, user_id=7,
- description=u'order 3', isopen=1, id=3),
- Order(address_id=None, user_id=7, description=u'order 5'
- , isopen=0, id=5)])])
-
- self.assert_sql_count(testing.db, go, 1)
-
-
-class MixedEntitiesTest(QueryTest, AssertsCompiledSQL):
-
- def test_values(self):
- sess = create_session()
-
- assert list(sess.query(User).values()) == list()
-
- sel = users.select(User.id.in_([7, 8])).alias()
- q = sess.query(User)
- q2 = q.select_from(sel).values(User.name)
- eq_(list(q2), [(u'jack',), (u'ed',)])
-
- q = sess.query(User)
- q2 = q.order_by(User.id).\
- values(User.name, User.name + " " + cast(User.id, String(50)))
- eq_(
- list(q2),
- [(u'jack', u'jack 7'), (u'ed', u'ed 8'),
- (u'fred', u'fred 9'), (u'chuck', u'chuck 10')]
- )
-
- q2 = q.join('addresses').\
- filter(User.name.like('%e%')).\
- order_by(User.id, Address.id).\
- values(User.name, Address.email_address)
- eq_(list(q2),
- [(u'ed', u'ed@wood.com'), (u'ed', u'ed@bettyboop.com'),
- (u'ed', u'ed@lala.com'), (u'fred', u'fred@fred.com')])
-
- q2 = q.join('addresses').\
- filter(User.name.like('%e%')).\
- order_by(desc(Address.email_address)).\
- slice(1, 3).values(User.name, Address.email_address)
- eq_(list(q2), [(u'ed', u'ed@wood.com'), (u'ed', u'ed@lala.com')])
-
- adalias = aliased(Address)
- q2 = q.join(adalias, 'addresses').\
- filter(User.name.like('%e%')).\
- values(User.name, adalias.email_address)
- eq_(list(q2), [(u'ed', u'ed@wood.com'), (u'ed', u'ed@bettyboop.com'),
- (u'ed', u'ed@lala.com'), (u'fred', u'fred@fred.com')])
-
- q2 = q.values(func.count(User.name))
- assert q2.next() == (4,)
-
- q2 = q.select_from(sel).filter(User.id==8).values(User.name, sel.c.name, User.name)
- eq_(list(q2), [(u'ed', u'ed', u'ed')])
-
- # using User.xxx is alised against "sel", so this query returns nothing
- q2 = q.select_from(sel).\
- filter(User.id==8).\
- filter(User.id>sel.c.id).values(User.name, sel.c.name, User.name)
- eq_(list(q2), [])
-
- # whereas this uses users.c.xxx, is not aliased and creates a new join
- q2 = q.select_from(sel).\
- filter(users.c.id==8).\
- filter(users.c.id>sel.c.id).values(users.c.name, sel.c.name, User.name)
- eq_(list(q2), [(u'ed', u'jack', u'jack')])
-
- @testing.fails_on('mssql', 'FIXME: unknown')
- def test_values_specific_order_by(self):
- sess = create_session()
-
- assert list(sess.query(User).values()) == list()
-
- sel = users.select(User.id.in_([7, 8])).alias()
- q = sess.query(User)
- u2 = aliased(User)
- q2 = q.select_from(sel).\
- filter(u2.id>1).\
- order_by(User.id, sel.c.id, u2.id).\
- values(User.name, sel.c.name, u2.name)
- eq_(list(q2), [(u'jack', u'jack', u'jack'), (u'jack', u'jack', u'ed'),
- (u'jack', u'jack', u'fred'), (u'jack', u'jack', u'chuck'),
- (u'ed', u'ed', u'jack'), (u'ed', u'ed', u'ed'),
- (u'ed', u'ed', u'fred'), (u'ed', u'ed', u'chuck')])
-
- @testing.fails_on('mssql', 'FIXME: unknown')
- @testing.fails_on('oracle',
- "Oracle doesn't support boolean expressions as "
- "columns")
- @testing.fails_on('postgresql+pg8000',
- "pg8000 parses the SQL itself before passing on "
- "to PG, doesn't parse this")
- @testing.fails_on('postgresql+zxjdbc',
- "zxjdbc parses the SQL itself before passing on "
- "to PG, doesn't parse this")
- def test_values_with_boolean_selects(self):
- """Tests a values clause that works with select boolean
- evaluations"""
- sess = create_session()
-
- q = sess.query(User)
- q2 = q.group_by(User.name.like('%j%')).\
- order_by(desc(User.name.like('%j%'))).\
- values(User.name.like('%j%'), func.count(User.name.like('%j%')))
- eq_(list(q2), [(True, 1), (False, 3)])
-
- q2 = q.order_by(desc(User.name.like('%j%'))).values(User.name.like('%j%'))
- eq_(list(q2), [(True,), (False,), (False,), (False,)])
-
-
- def test_correlated_subquery(self):
- """test that a subquery constructed from ORM attributes doesn't leak out
- those entities to the outermost query.
-
- """
- sess = create_session()
-
- subq = select([func.count()]).\
- where(User.id==Address.user_id).\
- correlate(users).\
- label('count')
-
- # we don't want Address to be outside of the subquery here
- eq_(
- list(sess.query(User, subq)[0:3]),
- [(User(id=7,name=u'jack'), 1), (User(id=8,name=u'ed'), 3),
- (User(id=9,name=u'fred'), 1)]
- )
-
- # same thing without the correlate, as it should
- # not be needed
- subq = select([func.count()]).\
- where(User.id==Address.user_id).\
- label('count')
-
- # we don't want Address to be outside of the subquery here
- eq_(
- list(sess.query(User, subq)[0:3]),
- [(User(id=7,name=u'jack'), 1), (User(id=8,name=u'ed'), 3),
- (User(id=9,name=u'fred'), 1)]
- )
-
- def test_tuple_labeling(self):
- sess = create_session()
-
- # test pickle + all the protocols !
- for pickled in False, -1, 0, 1, 2:
- for row in sess.query(User, Address).join(User.addresses).all():
- if pickled is not False:
- row = util.pickle.loads(util.pickle.dumps(row, pickled))
-
- eq_(row.keys(), ['User', 'Address'])
- eq_(row.User, row[0])
- eq_(row.Address, row[1])
-
- for row in sess.query(User.name, User.id.label('foobar')):
- if pickled is not False:
- row = util.pickle.loads(util.pickle.dumps(row, pickled))
- eq_(row.keys(), ['name', 'foobar'])
- eq_(row.name, row[0])
- eq_(row.foobar, row[1])
-
- for row in sess.query(User).values(User.name, User.id.label('foobar')):
- if pickled is not False:
- row = util.pickle.loads(util.pickle.dumps(row, pickled))
- eq_(row.keys(), ['name', 'foobar'])
- eq_(row.name, row[0])
- eq_(row.foobar, row[1])
-
- oalias = aliased(Order)
- for row in sess.query(User, oalias).join(User.orders).all():
- if pickled is not False:
- row = util.pickle.loads(util.pickle.dumps(row, pickled))
- eq_(row.keys(), ['User'])
- eq_(row.User, row[0])
-
- oalias = aliased(Order, name='orders')
- for row in sess.query(User, oalias).join(User.orders).all():
- if pickled is not False:
- row = util.pickle.loads(util.pickle.dumps(row, pickled))
- eq_(row.keys(), ['User', 'orders'])
- eq_(row.User, row[0])
- eq_(row.orders, row[1])
-
- # test here that first col is not labeled, only
- # one name in keys, matches correctly
- for row in sess.query(User.name + 'hoho', User.name):
- eq_(row.keys(), ['name'])
- eq_(row[0], row.name + 'hoho')
-
- if pickled is not False:
- ret = sess.query(User, Address).join(User.addresses).all()
- util.pickle.loads(util.pickle.dumps(ret, pickled))
-
- def test_column_queries(self):
- sess = create_session()
-
- eq_(sess.query(User.name).all(), [(u'jack',), (u'ed',), (u'fred',), (u'chuck',)])
-
- sel = users.select(User.id.in_([7, 8])).alias()
- q = sess.query(User.name)
- q2 = q.select_from(sel).all()
- eq_(list(q2), [(u'jack',), (u'ed',)])
-
- eq_(sess.query(User.name, Address.email_address).filter(User.id==Address.user_id).all(), [
- (u'jack', u'jack@bean.com'), (u'ed', u'ed@wood.com'),
- (u'ed', u'ed@bettyboop.com'), (u'ed', u'ed@lala.com'),
- (u'fred', u'fred@fred.com')
- ])
-
- eq_(sess.query(User.name, func.count(Address.email_address)).\
- outerjoin(User.addresses).group_by(User.id, User.name).\
- order_by(User.id).all(),
- [(u'jack', 1), (u'ed', 3), (u'fred', 1), (u'chuck', 0)]
- )
-
- eq_(sess.query(User, func.count(Address.email_address)).\
- outerjoin(User.addresses).group_by(User).\
- order_by(User.id).all(),
- [(User(name='jack',id=7), 1), (User(name='ed',id=8), 3),
- (User(name='fred',id=9), 1), (User(name='chuck',id=10), 0)]
- )
-
- eq_(sess.query(func.count(Address.email_address), User).\
- outerjoin(User.addresses).group_by(User).\
- order_by(User.id).all(),
- [(1, User(name='jack',id=7)), (3, User(name='ed',id=8)),
- (1, User(name='fred',id=9)), (0, User(name='chuck',id=10))]
- )
-
- adalias = aliased(Address)
- eq_(sess.query(User, func.count(adalias.email_address)).\
- outerjoin(adalias, 'addresses').group_by(User).\
- order_by(User.id).all(),
- [(User(name='jack',id=7), 1), (User(name='ed',id=8), 3),
- (User(name='fred',id=9), 1), (User(name='chuck',id=10), 0)]
- )
-
- eq_(sess.query(func.count(adalias.email_address), User).\
- outerjoin(adalias, User.addresses).group_by(User).\
- order_by(User.id).all(),
- [(1, User(name=u'jack',id=7)), (3, User(name=u'ed',id=8)),
- (1, User(name=u'fred',id=9)), (0, User(name=u'chuck',id=10))]
- )
-
- # select from aliasing + explicit aliasing
- eq_(
- sess.query(User, adalias.email_address, adalias.id).\
- outerjoin(adalias, User.addresses).\
- from_self(User, adalias.email_address).\
- order_by(User.id, adalias.id).all(),
- [
- (User(name=u'jack',id=7), u'jack@bean.com'),
- (User(name=u'ed',id=8), u'ed@wood.com'),
- (User(name=u'ed',id=8), u'ed@bettyboop.com'),
- (User(name=u'ed',id=8), u'ed@lala.com'),
- (User(name=u'fred',id=9), u'fred@fred.com'),
- (User(name=u'chuck',id=10), None)
- ]
- )
-
- # anon + select from aliasing
- eq_(
- sess.query(User).join(User.addresses, aliased=True).\
- filter(Address.email_address.like('%ed%')).\
- from_self().all(),
- [
- User(name=u'ed',id=8),
- User(name=u'fred',id=9),
- ]
- )
-
- # test eager aliasing, with/without select_from aliasing
- for q in [
- sess.query(User, adalias.email_address).\
- outerjoin(adalias, User.addresses).\
- options(joinedload(User.addresses)).\
- order_by(User.id, adalias.id).limit(10),
- sess.query(User, adalias.email_address, adalias.id).\
- outerjoin(adalias, User.addresses).\
- from_self(User, adalias.email_address).\
- options(joinedload(User.addresses)).\
- order_by(User.id, adalias.id).limit(10),
- ]:
- eq_(
-
- q.all(),
- [(User(addresses=[
- Address(user_id=7,email_address=u'jack@bean.com',id=1)],
- name=u'jack',id=7), u'jack@bean.com'),
- (User(addresses=[
- Address(user_id=8,email_address=u'ed@wood.com',id=2),
- Address(user_id=8,email_address=u'ed@bettyboop.com',id=3),
- Address(user_id=8,email_address=u'ed@lala.com',id=4)],
- name=u'ed',id=8), u'ed@wood.com'),
- (User(addresses=[
- Address(user_id=8,email_address=u'ed@wood.com',id=2),
- Address(user_id=8,email_address=u'ed@bettyboop.com',id=3),
- Address(user_id=8,email_address=u'ed@lala.com',id=4)],name=u'ed',id=8),
- u'ed@bettyboop.com'),
- (User(addresses=[
- Address(user_id=8,email_address=u'ed@wood.com',id=2),
- Address(user_id=8,email_address=u'ed@bettyboop.com',id=3),
- Address(user_id=8,email_address=u'ed@lala.com',id=4)],name=u'ed',id=8),
- u'ed@lala.com'),
- (User(addresses=[Address(user_id=9,email_address=u'fred@fred.com',id=5)],name=u'fred',id=9),
- u'fred@fred.com'),
-
- (User(addresses=[],name=u'chuck',id=10), None)]
- )
-
- def test_column_from_limited_joinedload(self):
- sess = create_session()
-
- def go():
- results = sess.query(User).limit(1).\
- options(joinedload('addresses')).\
- add_column(User.name).all()
- eq_(results, [(User(name='jack'), 'jack')])
- self.assert_sql_count(testing.db, go, 1)
-
- @testing.fails_on('postgresql+pg8000', "'type oid 705 not mapped to py type' (due to literal)")
- def test_self_referential(self):
-
- sess = create_session()
- oalias = aliased(Order)
-
- for q in [
- sess.query(Order, oalias).\
- filter(Order.user_id==oalias.user_id).filter(Order.user_id==7).\
- filter(Order.id>oalias.id).order_by(Order.id, oalias.id),
- sess.query(Order, oalias).from_self().filter(Order.user_id==oalias.user_id).\
- filter(Order.user_id==7).filter(Order.id>oalias.id).\
- order_by(Order.id, oalias.id),
-
- # same thing, but reversed.
- sess.query(oalias, Order).from_self().filter(oalias.user_id==Order.user_id).\
- filter(oalias.user_id==7).filter(Order.id<oalias.id).\
- order_by(oalias.id, Order.id),
-
- # here we go....two layers of aliasing
- sess.query(Order, oalias).filter(Order.user_id==oalias.user_id).\
- filter(Order.user_id==7).filter(Order.id>oalias.id).\
- from_self().order_by(Order.id, oalias.id).\
- limit(10).options(joinedload(Order.items)),
-
- # gratuitous four layers
- sess.query(Order, oalias).filter(Order.user_id==oalias.user_id).\
- filter(Order.user_id==7).filter(Order.id>oalias.id).from_self().\
- from_self().from_self().order_by(Order.id, oalias.id).\
- limit(10).options(joinedload(Order.items)),
-
- ]:
-
- eq_(
- q.all(),
- [
- (Order(address_id=1,description=u'order 3',isopen=1,user_id=7,id=3),
- Order(address_id=1,description=u'order 1',isopen=0,user_id=7,id=1)),
- (Order(address_id=None,description=u'order 5',isopen=0,user_id=7,id=5),
- Order(address_id=1,description=u'order 1',isopen=0,user_id=7,id=1)),
- (Order(address_id=None,description=u'order 5',isopen=0,user_id=7,id=5),
- Order(address_id=1,description=u'order 3',isopen=1,user_id=7,id=3))
- ]
- )
-
-
- # ensure column expressions are taken from inside the subquery, not restated at the top
- q = sess.query(Order.id, Order.description, literal_column("'q'").label('foo')).\
- filter(Order.description == u'order 3').from_self()
- self.assert_compile(q,
- "SELECT anon_1.orders_id AS "
- "anon_1_orders_id, anon_1.orders_descriptio"
- "n AS anon_1_orders_description, "
- "anon_1.foo AS anon_1_foo FROM (SELECT "
- "orders.id AS orders_id, "
- "orders.description AS orders_description, "
- "'q' AS foo FROM orders WHERE "
- "orders.description = :description_1) AS "
- "anon_1", use_default_dialect=True)
- eq_(
- q.all(),
- [(3, u'order 3', 'q')]
- )
-
-
- def test_multi_mappers(self):
-
- test_session = create_session()
-
- (user7, user8, user9, user10) = test_session.query(User).all()
- (address1, address2, address3, address4, address5) = \
- test_session.query(Address).all()
-
- expected = [(user7, address1),
- (user8, address2),
- (user8, address3),
- (user8, address4),
- (user9, address5),
- (user10, None)]
-
- sess = create_session()
-
- selectquery = users.outerjoin(addresses).select(use_labels=True, order_by=[users.c.id, addresses.c.id])
- eq_(list(sess.query(User, Address).instances(selectquery.execute())), expected)
- sess.expunge_all()
-
- for address_entity in (Address, aliased(Address)):
- q = sess.query(User).add_entity(address_entity).\
- outerjoin(address_entity, 'addresses').\
- order_by(User.id, address_entity.id)
- eq_(q.all(), expected)
- sess.expunge_all()
-
- q = sess.query(User).add_entity(address_entity)
- q = q.join(address_entity, 'addresses')
- q = q.filter_by(email_address='ed@bettyboop.com')
- eq_(q.all(), [(user8, address3)])
- sess.expunge_all()
-
- q = sess.query(User, address_entity).join(address_entity, 'addresses').\
- filter_by(email_address='ed@bettyboop.com')
- eq_(q.all(), [(user8, address3)])
- sess.expunge_all()
-
- q = sess.query(User, address_entity).join(address_entity, 'addresses').\
- options(joinedload('addresses')).\
- filter_by(email_address='ed@bettyboop.com')
- eq_(list(util.OrderedSet(q.all())), [(user8, address3)])
- sess.expunge_all()
-
- def test_aliased_multi_mappers(self):
- sess = create_session()
-
- (user7, user8, user9, user10) = sess.query(User).all()
- (address1, address2, address3, address4, address5) = sess.query(Address).all()
-
- expected = [(user7, address1),
- (user8, address2),
- (user8, address3),
- (user8, address4),
- (user9, address5),
- (user10, None)]
-
- q = sess.query(User)
- adalias = addresses.alias('adalias')
- q = q.add_entity(Address, alias=adalias).select_from(users.outerjoin(adalias))
- l = q.order_by(User.id, adalias.c.id).all()
- assert l == expected
-
- sess.expunge_all()
-
- q = sess.query(User).add_entity(Address, alias=adalias)
- l = q.select_from(users.outerjoin(adalias)).filter(adalias.c.email_address=='ed@bettyboop.com').all()
- assert l == [(user8, address3)]
-
- def test_with_entities(self):
- sess = create_session()
-
- q = sess.query(User).filter(User.id==7).order_by(User.name)
-
- self.assert_compile(
- q.with_entities(User.id,Address).\
- filter(Address.user_id == User.id),
- 'SELECT users.id AS users_id, addresses.id '
- 'AS addresses_id, addresses.user_id AS '
- 'addresses_user_id, addresses.email_address'
- ' AS addresses_email_address FROM users, '
- 'addresses WHERE users.id = :id_1 AND '
- 'addresses.user_id = users.id ORDER BY '
- 'users.name',
- use_default_dialect=True)
-
-
- def test_multi_columns(self):
- sess = create_session()
-
- expected = [(u, u.name) for u in sess.query(User).all()]
-
- for add_col in (User.name, users.c.name):
- assert sess.query(User).add_column(add_col).all() == expected
- sess.expunge_all()
-
- assert_raises(sa_exc.InvalidRequestError, sess.query(User).add_column, object())
-
- def test_add_multi_columns(self):
- """test that add_column accepts a FROM clause."""
-
- sess = create_session()
-
- eq_(
- sess.query(User.id).add_column(users).all(),
- [(7, 7, u'jack'), (8, 8, u'ed'), (9, 9, u'fred'), (10, 10, u'chuck')]
- )
-
- def test_multi_columns_2(self):
- """test aliased/nonalised joins with the usage of add_column()"""
- sess = create_session()
-
- (user7, user8, user9, user10) = sess.query(User).all()
- expected = [(user7, 1),
- (user8, 3),
- (user9, 1),
- (user10, 0)
- ]
-
- q = sess.query(User)
- q = q.group_by(users).order_by(User.id).outerjoin('addresses').\
- add_column(func.count(Address.id).label('count'))
- eq_(q.all(), expected)
- sess.expunge_all()
-
- adalias = aliased(Address)
- q = sess.query(User)
- q = q.group_by(users).order_by(User.id).outerjoin(adalias, 'addresses').\
- add_column(func.count(adalias.id).label('count'))
- eq_(q.all(), expected)
- sess.expunge_all()
-
- # TODO: figure out why group_by(users) doesn't work here
- s = select([users, func.count(addresses.c.id).label('count')]).\
- select_from(users.outerjoin(addresses)).\
- group_by(*[c for c in users.c]).order_by(User.id)
- q = sess.query(User)
- l = q.add_column("count").from_statement(s).all()
- assert l == expected
-
-
- def test_raw_columns(self):
- sess = create_session()
- (user7, user8, user9, user10) = sess.query(User).all()
- expected = [
- (user7, 1, "Name:jack"),
- (user8, 3, "Name:ed"),
- (user9, 1, "Name:fred"),
- (user10, 0, "Name:chuck")]
-
- adalias = addresses.alias()
- q = create_session().query(User).add_column(func.count(adalias.c.id))\
- .add_column(("Name:" + users.c.name)).outerjoin(adalias, 'addresses')\
- .group_by(users).order_by(users.c.id)
-
- assert q.all() == expected
-
- # test with a straight statement
- s = select([users, func.count(addresses.c.id).label('count'),
- ("Name:" + users.c.name).label('concat')],
- from_obj=[users.outerjoin(addresses)],
- group_by=[c for c in users.c], order_by=[users.c.id])
- q = create_session().query(User)
- l = q.add_column("count").add_column("concat").from_statement(s).all()
- assert l == expected
-
- sess.expunge_all()
-
- # test with select_from()
- q = create_session().query(User).add_column(func.count(addresses.c.id))\
- .add_column(("Name:" + users.c.name)).select_from(users.outerjoin(addresses))\
- .group_by(users).order_by(users.c.id)
-
- assert q.all() == expected
- sess.expunge_all()
-
- q = create_session().query(User).add_column(func.count(addresses.c.id))\
- .add_column(("Name:" + users.c.name)).outerjoin('addresses')\
- .group_by(users).order_by(users.c.id)
-
- assert q.all() == expected
- sess.expunge_all()
-
- q = create_session().query(User).add_column(func.count(adalias.c.id))\
- .add_column(("Name:" + users.c.name)).outerjoin(adalias, 'addresses')\
- .group_by(users).order_by(users.c.id)
-
- assert q.all() == expected
- sess.expunge_all()
-
-class ImmediateTest(_fixtures.FixtureTest):
- run_inserts = 'once'
- run_deletes = None
-
- @classmethod
- @testing.resolve_artifact_names
- def setup_mappers(cls):
- mapper(Address, addresses)
-
- mapper(User, users, properties=dict(
- addresses=relationship(Address)))
-
- @testing.resolve_artifact_names
- def test_one(self):
- sess = create_session()
-
- assert_raises(sa.orm.exc.NoResultFound,
- sess.query(User).filter(User.id == 99).one)
-
- eq_(sess.query(User).filter(User.id == 7).one().id, 7)
-
- assert_raises(sa.orm.exc.MultipleResultsFound,
- sess.query(User).one)
-
- assert_raises(
- sa.orm.exc.NoResultFound,
- sess.query(User.id, User.name).filter(User.id == 99).one)
-
- eq_(sess.query(User.id, User.name).filter(User.id == 7).one(),
- (7, 'jack'))
-
- assert_raises(sa.orm.exc.MultipleResultsFound,
- sess.query(User.id, User.name).one)
-
- assert_raises(sa.orm.exc.NoResultFound,
- (sess.query(User, Address).
- join(User.addresses).
- filter(Address.id == 99)).one)
-
- eq_((sess.query(User, Address).
- join(User.addresses).
- filter(Address.id == 4)).one(),
- (User(id=8), Address(id=4)))
-
- assert_raises(sa.orm.exc.MultipleResultsFound,
- sess.query(User, Address).join(User.addresses).one)
-
- # this result returns multiple rows, the first
- # two rows being the same. but uniquing is
- # not applied for a column based result.
- assert_raises(sa.orm.exc.MultipleResultsFound,
- sess.query(User.id).
- join(User.addresses).
- filter(User.id.in_([8, 9])).
- order_by(User.id).
- one)
-
- # test that a join which ultimately returns
- # multiple identities across many rows still
- # raises, even though the first two rows are of
- # the same identity and unique filtering
- # is applied ([ticket:1688])
- assert_raises(sa.orm.exc.MultipleResultsFound,
- sess.query(User).
- join(User.addresses).
- filter(User.id.in_([8, 9])).
- order_by(User.id).
- one)
-
-
- @testing.future
- def test_getslice(self):
- assert False
-
- @testing.resolve_artifact_names
- def test_scalar(self):
- sess = create_session()
-
- eq_(sess.query(User.id).filter_by(id=7).scalar(), 7)
- eq_(sess.query(User.id, User.name).filter_by(id=7).scalar(), 7)
- eq_(sess.query(User.id).filter_by(id=0).scalar(), None)
- eq_(sess.query(User).filter_by(id=7).scalar(),
- sess.query(User).filter_by(id=7).one())
-
- assert_raises(sa.orm.exc.MultipleResultsFound, sess.query(User).scalar)
- assert_raises(sa.orm.exc.MultipleResultsFound, sess.query(User.id, User.name).scalar)
-
- @testing.resolve_artifact_names
- def test_value(self):
- sess = create_session()
-
- eq_(sess.query(User).filter_by(id=7).value(User.id), 7)
- eq_(sess.query(User.id, User.name).filter_by(id=7).value(User.id), 7)
- eq_(sess.query(User).filter_by(id=0).value(User.id), None)
-
- sess.bind = testing.db
- eq_(sess.query().value(sa.literal_column('1').label('x')), 1)
-
-
-class SelectFromTest(QueryTest, AssertsCompiledSQL):
- run_setup_mappers = None
-
- def test_replace_with_select(self):
- mapper(User, users, properties = {
- 'addresses':relationship(Address)
- })
- mapper(Address, addresses)
-
- sel = users.select(users.c.id.in_([7, 8])).alias()
- sess = create_session()
-
- eq_(sess.query(User).select_from(sel).all(), [User(id=7), User(id=8)])
-
- eq_(sess.query(User).select_from(sel).filter(User.id==8).all(), [User(id=8)])
-
- eq_(sess.query(User).select_from(sel).order_by(desc(User.name)).all(), [
- User(name='jack',id=7), User(name='ed',id=8)
- ])
-
- eq_(sess.query(User).select_from(sel).order_by(asc(User.name)).all(), [
- User(name='ed',id=8), User(name='jack',id=7)
- ])
-
- eq_(sess.query(User).select_from(sel).options(joinedload('addresses')).first(),
- User(name='jack', addresses=[Address(id=1)])
- )
-
- def test_join_mapper_order_by(self):
- """test that mapper-level order_by is adapted to a selectable."""
-
- mapper(User, users, order_by=users.c.id)
-
- sel = users.select(users.c.id.in_([7, 8]))
- sess = create_session()
-
- eq_(sess.query(User).select_from(sel).all(),
- [
- User(name='jack',id=7), User(name='ed',id=8)
- ]
- )
-
- def test_differentiate_self_external(self):
- """test some different combinations of joining a table to a subquery of itself."""
-
- mapper(User, users)
-
- sess = create_session()
-
- sel = sess.query(User).filter(User.id.in_([7, 8])).subquery()
- ualias = aliased(User)
-
- self.assert_compile(
- sess.query(User).join(sel, User.id>sel.c.id),
- "SELECT users.id AS users_id, users.name AS users_name FROM "
- "users JOIN (SELECT users.id AS id, users.name AS name FROM "
- "users WHERE users.id IN (:id_1, :id_2)) AS anon_1 ON users.id > anon_1.id",
- use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(ualias).select_from(sel).filter(ualias.id>sel.c.id),
- "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM "
- "users AS users_1, (SELECT users.id AS id, users.name AS name FROM "
- "users WHERE users.id IN (:id_1, :id_2)) AS anon_1 WHERE users_1.id > anon_1.id",
- use_default_dialect=True
- )
-
- # these two are essentially saying, "join ualias to ualias", so an
- # error is raised. join() deals with entities, not what's in
- # select_from().
- assert_raises(sa_exc.InvalidRequestError,
- sess.query(ualias).select_from(sel).join, ualias, ualias.id>sel.c.id
- )
-
- assert_raises(sa_exc.InvalidRequestError,
- sess.query(ualias).select_from(sel).join, ualias, ualias.id>User.id
- )
-
- salias = aliased(User, sel)
- self.assert_compile(
- sess.query(salias).join(ualias, ualias.id>salias.id),
- "SELECT anon_1.id AS anon_1_id, anon_1.name AS anon_1_name FROM "
- "(SELECT users.id AS id, users.name AS name FROM users WHERE users.id "
- "IN (:id_1, :id_2)) AS anon_1 JOIN users AS users_1 ON users_1.id > anon_1.id",
- use_default_dialect=True
- )
-
-
- # this one uses an explicit join(left, right, onclause) so works
- self.assert_compile(
- sess.query(ualias).select_from(join(sel, ualias, ualias.id>sel.c.id)),
- "SELECT users_1.id AS users_1_id, users_1.name AS users_1_name FROM "
- "(SELECT users.id AS id, users.name AS name FROM users WHERE users.id "
- "IN (:id_1, :id_2)) AS anon_1 JOIN users AS users_1 ON users_1.id > anon_1.id",
- use_default_dialect=True
- )
-
-
-
- def test_join_no_order_by(self):
- mapper(User, users)
-
- sel = users.select(users.c.id.in_([7, 8]))
- sess = create_session()
-
- eq_(sess.query(User).select_from(sel).all(),
- [
- User(name='jack',id=7), User(name='ed',id=8)
- ]
- )
-
- def test_join(self):
- mapper(User, users, properties = {
- 'addresses':relationship(Address)
- })
- mapper(Address, addresses)
-
- sel = users.select(users.c.id.in_([7, 8]))
- sess = create_session()
-
- eq_(sess.query(User).select_from(sel).join('addresses').
- add_entity(Address).order_by(User.id).order_by(Address.id).all(),
- [
- (User(name='jack',id=7), Address(user_id=7,email_address='jack@bean.com',id=1)),
- (User(name='ed',id=8), Address(user_id=8,email_address='ed@wood.com',id=2)),
- (User(name='ed',id=8), Address(user_id=8,email_address='ed@bettyboop.com',id=3)),
- (User(name='ed',id=8), Address(user_id=8,email_address='ed@lala.com',id=4))
- ]
- )
-
- adalias = aliased(Address)
- eq_(sess.query(User).select_from(sel).join(adalias, 'addresses').
- add_entity(adalias).order_by(User.id).order_by(adalias.id).all(),
- [
- (User(name='jack',id=7), Address(user_id=7,email_address='jack@bean.com',id=1)),
- (User(name='ed',id=8), Address(user_id=8,email_address='ed@wood.com',id=2)),
- (User(name='ed',id=8), Address(user_id=8,email_address='ed@bettyboop.com',id=3)),
- (User(name='ed',id=8), Address(user_id=8,email_address='ed@lala.com',id=4))
- ]
- )
-
-
- def test_more_joins(self):
- mapper(User, users, properties={
- 'orders':relationship(Order, backref='user'), # o2m, m2o
- })
- mapper(Order, orders, properties={
- 'items':relationship(Item, secondary=order_items,
- order_by=items.c.id), #m2m
- })
- mapper(Item, items, properties={
- 'keywords':relationship(Keyword, secondary=item_keywords,
- order_by=keywords.c.id) #m2m
- })
- mapper(Keyword, keywords)
-
- sess = create_session()
- sel = users.select(users.c.id.in_([7, 8]))
-
- eq_(sess.query(User).select_from(sel).\
- join('orders', 'items', 'keywords').\
- filter(Keyword.name.in_(['red', 'big', 'round'])).\
- all(),
- [
- User(name=u'jack',id=7)
- ])
-
- eq_(sess.query(User).select_from(sel).\
- join('orders', 'items', 'keywords', aliased=True).\
- filter(Keyword.name.in_(['red', 'big', 'round'])).\
- all(),
- [
- User(name=u'jack',id=7)
- ])
-
- def go():
- eq_(
- sess.query(User).select_from(sel).
- options(joinedload_all('orders.items.keywords')).
- join('orders', 'items', 'keywords', aliased=True).
- filter(Keyword.name.in_(['red', 'big', 'round'])).\
- all(),
- [
- User(name=u'jack',orders=[
- Order(description=u'order 1',items=[
- Item(description=u'item 1',
- keywords=[
- Keyword(name=u'red'),
- Keyword(name=u'big'),
- Keyword(name=u'round')
- ]),
- Item(description=u'item 2',
- keywords=[
- Keyword(name=u'red',id=2),
- Keyword(name=u'small',id=5),
- Keyword(name=u'square')
- ]),
- Item(description=u'item 3',
- keywords=[
- Keyword(name=u'green',id=3),
- Keyword(name=u'big',id=4),
- Keyword(name=u'round',id=6)])
- ]),
- Order(description=u'order 3',items=[
- Item(description=u'item 3',
- keywords=[
- Keyword(name=u'green',id=3),
- Keyword(name=u'big',id=4),
- Keyword(name=u'round',id=6)
- ]),
- Item(description=u'item 4',keywords=[],id=4),
- Item(description=u'item 5',keywords=[],id=5)
- ]),
- Order(description=u'order 5',
- items=[
- Item(description=u'item 5',keywords=[])])
- ])
- ])
- self.assert_sql_count(testing.db, go, 1)
-
- sess.expunge_all()
- sel2 = orders.select(orders.c.id.in_([1,2,3]))
- eq_(sess.query(Order).select_from(sel2).\
- join('items', 'keywords').\
- filter(Keyword.name == 'red').\
- order_by(Order.id).all(), [
- Order(description=u'order 1',id=1),
- Order(description=u'order 2',id=2),
- ])
- eq_(sess.query(Order).select_from(sel2).\
- join('items', 'keywords', aliased=True).\
- filter(Keyword.name == 'red').\
- order_by(Order.id).all(), [
- Order(description=u'order 1',id=1),
- Order(description=u'order 2',id=2),
- ])
-
-
- def test_replace_with_eager(self):
- mapper(User, users, properties = {
- 'addresses':relationship(Address, order_by=addresses.c.id)
- })
- mapper(Address, addresses)
-
- sel = users.select(users.c.id.in_([7, 8]))
- sess = create_session()
-
- def go():
- eq_(sess.query(User).options(joinedload('addresses')).select_from(sel).order_by(User.id).all(),
- [
- User(id=7, addresses=[Address(id=1)]),
- User(id=8, addresses=[Address(id=2), Address(id=3), Address(id=4)])
- ]
- )
- self.assert_sql_count(testing.db, go, 1)
- sess.expunge_all()
-
- def go():
- eq_(sess.query(User).options(joinedload('addresses')).select_from(sel).filter(User.id==8).order_by(User.id).all(),
- [User(id=8, addresses=[Address(id=2), Address(id=3), Address(id=4)])]
- )
- self.assert_sql_count(testing.db, go, 1)
- sess.expunge_all()
-
- def go():
- eq_(sess.query(User).options(joinedload('addresses')).select_from(sel).order_by(User.id)[1], User(id=8, addresses=[Address(id=2), Address(id=3), Address(id=4)]))
- self.assert_sql_count(testing.db, go, 1)
-
-class CustomJoinTest(QueryTest):
- run_setup_mappers = None
-
- def test_double_same_mappers(self):
- """test aliasing of joins with a custom join condition"""
- mapper(Address, addresses)
- mapper(Order, orders, properties={
- 'items':relationship(Item, secondary=order_items, lazy='select', order_by=items.c.id),
- })
- mapper(Item, items)
- mapper(User, users, properties = dict(
- addresses = relationship(Address, lazy='select'),
- open_orders = relationship(Order, primaryjoin = and_(orders.c.isopen == 1, users.c.id==orders.c.user_id), lazy='select'),
- closed_orders = relationship(Order, primaryjoin = and_(orders.c.isopen == 0, users.c.id==orders.c.user_id), lazy='select')
- ))
- q = create_session().query(User)
-
- eq_(
- q.join('open_orders', 'items', aliased=True).filter(Item.id==4).\
- join('closed_orders', 'items', aliased=True).filter(Item.id==3).all(),
- [User(id=7)]
- )
-
-class SelfRefMixedTest(_base.MappedTest, AssertsCompiledSQL):
- run_setup_mappers = 'once'
- __dialect__ = default.DefaultDialect()
-
- @classmethod
- def define_tables(cls, metadata):
- nodes = Table('nodes', metadata,
- Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('parent_id', Integer, ForeignKey('nodes.id'))
- )
-
- sub_table = Table('sub_table', metadata,
- Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('node_id', Integer, ForeignKey('nodes.id')),
- )
-
- assoc_table = Table('assoc_table', metadata,
- Column('left_id', Integer, ForeignKey('nodes.id')),
- Column('right_id', Integer, ForeignKey('nodes.id'))
- )
-
- @classmethod
- @testing.resolve_artifact_names
- def setup_classes(cls):
- class Node(Base):
- pass
-
- class Sub(Base):
- pass
-
- mapper(Node, nodes, properties={
- 'children':relationship(Node, lazy='select', join_depth=3,
- backref=backref('parent', remote_side=[nodes.c.id])
- ),
- 'subs' : relationship(Sub),
- 'assoc':relationship(Node,
- secondary=assoc_table,
- primaryjoin=nodes.c.id==assoc_table.c.left_id,
- secondaryjoin=nodes.c.id==assoc_table.c.right_id)
- })
- mapper(Sub, sub_table)
-
- @testing.resolve_artifact_names
- def test_o2m_aliased_plus_o2m(self):
- sess = create_session()
- n1 = aliased(Node)
-
- self.assert_compile(
- sess.query(Node).join(n1, Node.children).join(Sub, n1.subs),
- "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id "
- "FROM nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id "
- "JOIN sub_table ON nodes_1.id = sub_table.node_id"
- )
-
- self.assert_compile(
- sess.query(Node).join(n1, Node.children).join(Sub, Node.subs),
- "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id "
- "FROM nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id "
- "JOIN sub_table ON nodes.id = sub_table.node_id"
- )
-
- @testing.resolve_artifact_names
- def test_m2m_aliased_plus_o2m(self):
- sess = create_session()
- n1 = aliased(Node)
-
- self.assert_compile(
- sess.query(Node).join(n1, Node.assoc).join(Sub, n1.subs),
- "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id "
- "FROM nodes JOIN assoc_table AS assoc_table_1 ON nodes.id = "
- "assoc_table_1.left_id JOIN nodes AS nodes_1 ON nodes_1.id = "
- "assoc_table_1.right_id JOIN sub_table ON nodes_1.id = sub_table.node_id",
- )
-
- self.assert_compile(
- sess.query(Node).join(n1, Node.assoc).join(Sub, Node.subs),
- "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id "
- "FROM nodes JOIN assoc_table AS assoc_table_1 ON nodes.id = "
- "assoc_table_1.left_id JOIN nodes AS nodes_1 ON nodes_1.id = "
- "assoc_table_1.right_id JOIN sub_table ON nodes.id = sub_table.node_id",
- )
-
-
-class SelfReferentialTest(_base.MappedTest, AssertsCompiledSQL):
- run_setup_mappers = 'once'
- run_inserts = 'once'
- run_deletes = None
-
- @classmethod
- def define_tables(cls, metadata):
- global nodes
- nodes = Table('nodes', metadata,
- Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('parent_id', Integer, ForeignKey('nodes.id')),
- Column('data', String(30)))
-
- @classmethod
- def insert_data(cls):
- # TODO: somehow using setup_classes()
- # here normally is screwing up the other tests.
-
- global Node, Sub
- class Node(Base):
- def append(self, node):
- self.children.append(node)
-
- mapper(Node, nodes, properties={
- 'children':relationship(Node, lazy='select', join_depth=3,
- backref=backref('parent', remote_side=[nodes.c.id])
- ),
- })
-
- sess = create_session()
- n1 = Node(data='n1')
- n1.append(Node(data='n11'))
- n1.append(Node(data='n12'))
- n1.append(Node(data='n13'))
- n1.children[1].append(Node(data='n121'))
- n1.children[1].append(Node(data='n122'))
- n1.children[1].append(Node(data='n123'))
- sess.add(n1)
- sess.flush()
- sess.close()
-
- @testing.resolve_artifact_names
- def test_join(self):
- sess = create_session()
-
- node = sess.query(Node).join('children', aliased=True).filter_by(data='n122').first()
- assert node.data=='n12'
+ # this result returns multiple rows, the first
+ # two rows being the same. but uniquing is
+ # not applied for a column based result.
+ assert_raises(sa.orm.exc.MultipleResultsFound,
+ sess.query(User.id).
+ join(User.addresses).
+ filter(User.id.in_([8, 9])).
+ order_by(User.id).
+ one)
- ret = sess.query(Node.data).join(Node.children, aliased=True).filter_by(data='n122').all()
- assert ret == [('n12',)]
+ # test that a join which ultimately returns
+ # multiple identities across many rows still
+ # raises, even though the first two rows are of
+ # the same identity and unique filtering
+ # is applied ([ticket:1688])
+ assert_raises(sa.orm.exc.MultipleResultsFound,
+ sess.query(User).
+ join(User.addresses).
+ filter(User.id.in_([8, 9])).
+ order_by(User.id).
+ one)
+
-
- node = sess.query(Node).join('children', 'children', aliased=True).filter_by(data='n122').first()
- assert node.data=='n1'
+ @testing.future
+ def test_getslice(self):
+ assert False
- node = sess.query(Node).filter_by(data='n122').join('parent', aliased=True).filter_by(data='n12').\
- join('parent', aliased=True, from_joinpoint=True).filter_by(data='n1').first()
- assert node.data == 'n122'
-
- @testing.resolve_artifact_names
- def test_string_or_prop_aliased(self):
- """test that join('foo') behaves the same as join(Cls.foo) in a self
- referential scenario.
-
- """
-
- sess = create_session()
- nalias = aliased(Node, sess.query(Node).filter_by(data='n1').subquery())
-
- q1 = sess.query(nalias).join(nalias.children, aliased=True).\
- join(Node.children, from_joinpoint=True)
-
- q2 = sess.query(nalias).join(nalias.children, aliased=True).\
- join("children", from_joinpoint=True)
-
- for q in (q1, q2):
- self.assert_compile(
- q,
- "SELECT anon_1.id AS anon_1_id, anon_1.parent_id AS "
- "anon_1_parent_id, anon_1.data AS anon_1_data FROM "
- "(SELECT nodes.id AS id, nodes.parent_id AS parent_id, "
- "nodes.data AS data FROM nodes WHERE nodes.data = :data_1) "
- "AS anon_1 JOIN nodes AS nodes_1 ON anon_1.id = "
- "nodes_1.parent_id JOIN nodes ON nodes_1.id = nodes.parent_id",
- use_default_dialect=True
- )
-
- q1 = sess.query(Node).join(nalias.children, aliased=True).\
- join(Node.children, aliased=True, from_joinpoint=True).\
- join(Node.children, from_joinpoint=True)
-
- q2 = sess.query(Node).join(nalias.children, aliased=True).\
- join("children", aliased=True, from_joinpoint=True).\
- join("children", from_joinpoint=True)
-
- for q in (q1, q2):
- self.assert_compile(
- q,
- "SELECT nodes.id AS nodes_id, nodes.parent_id AS "
- "nodes_parent_id, nodes.data AS nodes_data FROM (SELECT "
- "nodes.id AS id, nodes.parent_id AS parent_id, nodes.data "
- "AS data FROM nodes WHERE nodes.data = :data_1) AS anon_1 "
- "JOIN nodes AS nodes_1 ON anon_1.id = nodes_1.parent_id "
- "JOIN nodes AS nodes_2 ON nodes_1.id = nodes_2.parent_id "
- "JOIN nodes ON nodes_2.id = nodes.parent_id",
- use_default_dialect=True
- )
-
@testing.resolve_artifact_names
- def test_from_self_inside_excludes_outside(self):
- """test the propagation of aliased() from inside to outside
- on a from_self()..
- """
+ def test_scalar(self):
sess = create_session()
-
- n1 = aliased(Node)
-
- # n1 is not inside the from_self(), so all cols must be maintained
- # on the outside
- self.assert_compile(
- sess.query(Node).filter(Node.data=='n122').from_self(n1, Node.id),
- "SELECT nodes_1.id AS nodes_1_id, nodes_1.parent_id AS nodes_1_parent_id, "
- "nodes_1.data AS nodes_1_data, anon_1.nodes_id AS anon_1_nodes_id "
- "FROM nodes AS nodes_1, (SELECT nodes.id AS nodes_id, "
- "nodes.parent_id AS nodes_parent_id, nodes.data AS nodes_data FROM "
- "nodes WHERE nodes.data = :data_1) AS anon_1",
- use_default_dialect=True
- )
- parent = aliased(Node)
- grandparent = aliased(Node)
- q = sess.query(Node, parent, grandparent).\
- join(parent, Node.parent).\
- join(grandparent, parent.parent).\
- filter(Node.data=='n122').filter(parent.data=='n12').\
- filter(grandparent.data=='n1').from_self().limit(1)
-
- # parent, grandparent *are* inside the from_self(), so they
- # should get aliased to the outside.
- self.assert_compile(
- q,
- "SELECT anon_1.nodes_id AS anon_1_nodes_id, "
- "anon_1.nodes_parent_id AS anon_1_nodes_parent_id, "
- "anon_1.nodes_data AS anon_1_nodes_data, "
- "anon_1.nodes_1_id AS anon_1_nodes_1_id, "
- "anon_1.nodes_1_parent_id AS anon_1_nodes_1_parent_id, "
- "anon_1.nodes_1_data AS anon_1_nodes_1_data, "
- "anon_1.nodes_2_id AS anon_1_nodes_2_id, "
- "anon_1.nodes_2_parent_id AS anon_1_nodes_2_parent_id, "
- "anon_1.nodes_2_data AS anon_1_nodes_2_data "
- "FROM (SELECT nodes.id AS nodes_id, nodes.parent_id "
- "AS nodes_parent_id, nodes.data AS nodes_data, "
- "nodes_1.id AS nodes_1_id, nodes_1.parent_id AS nodes_1_parent_id, "
- "nodes_1.data AS nodes_1_data, nodes_2.id AS nodes_2_id, "
- "nodes_2.parent_id AS nodes_2_parent_id, nodes_2.data AS "
- "nodes_2_data FROM nodes JOIN nodes AS nodes_1 ON "
- "nodes_1.id = nodes.parent_id JOIN nodes AS nodes_2 "
- "ON nodes_2.id = nodes_1.parent_id "
- "WHERE nodes.data = :data_1 AND nodes_1.data = :data_2 AND "
- "nodes_2.data = :data_3) AS anon_1 LIMIT :param_1",
- {'param_1':1},
- use_default_dialect=True
- )
-
- @testing.resolve_artifact_names
- def test_explicit_join(self):
- sess = create_session()
-
- n1 = aliased(Node)
- n2 = aliased(Node)
+ eq_(sess.query(User.id).filter_by(id=7).scalar(), 7)
+ eq_(sess.query(User.id, User.name).filter_by(id=7).scalar(), 7)
+ eq_(sess.query(User.id).filter_by(id=0).scalar(), None)
+ eq_(sess.query(User).filter_by(id=7).scalar(),
+ sess.query(User).filter_by(id=7).one())
- self.assert_compile(
- join(Node, n1, 'children').join(n2, 'children'),
- "nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id JOIN nodes AS nodes_2 ON nodes_1.id = nodes_2.parent_id",
- use_default_dialect=True
- )
-
- self.assert_compile(
- join(Node, n1, Node.children).join(n2, n1.children),
- "nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id JOIN nodes AS nodes_2 ON nodes_1.id = nodes_2.parent_id",
- use_default_dialect=True
- )
-
- # the join_to_left=False here is unfortunate. the default on this flag should
- # be False.
- self.assert_compile(
- join(Node, n1, Node.children).join(n2, Node.children, join_to_left=False),
- "nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id JOIN nodes AS nodes_2 ON nodes.id = nodes_2.parent_id",
- use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(Node).join(n1, Node.children).join(n2, n1.children),
- "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id, nodes.data AS "
- "nodes_data FROM nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id "
- "JOIN nodes AS nodes_2 ON nodes_1.id = nodes_2.parent_id",
- use_default_dialect=True
- )
-
- self.assert_compile(
- sess.query(Node).join(n1, Node.children).join(n2, Node.children),
- "SELECT nodes.id AS nodes_id, nodes.parent_id AS nodes_parent_id, nodes.data AS "
- "nodes_data FROM nodes JOIN nodes AS nodes_1 ON nodes.id = nodes_1.parent_id "
- "JOIN nodes AS nodes_2 ON nodes.id = nodes_2.parent_id",
- use_default_dialect=True
- )
-
- node = sess.query(Node).select_from(join(Node, n1, 'children')).filter(n1.data=='n122').first()
- assert node.data=='n12'
-
- node = sess.query(Node).select_from(join(Node, n1, 'children').join(n2, 'children')).\
- filter(n2.data=='n122').first()
- assert node.data=='n1'
-
- # mix explicit and named onclauses
- node = sess.query(Node).select_from(join(Node, n1, Node.id==n1.parent_id).join(n2, 'children')).\
- filter(n2.data=='n122').first()
- assert node.data=='n1'
-
- node = sess.query(Node).select_from(join(Node, n1, 'parent').join(n2, 'parent')).\
- filter(and_(Node.data=='n122', n1.data=='n12', n2.data=='n1')).first()
- assert node.data == 'n122'
-
- eq_(
- list(sess.query(Node).select_from(join(Node, n1, 'parent').join(n2, 'parent')).\
- filter(and_(Node.data=='n122', n1.data=='n12', n2.data=='n1')).values(Node.data, n1.data, n2.data)),
- [('n122', 'n12', 'n1')])
-
- @testing.resolve_artifact_names
- def test_join_to_nonaliased(self):
- sess = create_session()
-
- n1 = aliased(Node)
-
- # using 'n1.parent' implicitly joins to unaliased Node
- eq_(
- sess.query(n1).join(n1.parent).filter(Node.data=='n1').all(),
- [Node(parent_id=1,data=u'n11',id=2), Node(parent_id=1,data=u'n12',id=3), Node(parent_id=1,data=u'n13',id=4)]
- )
-
- # explicit (new syntax)
- eq_(
- sess.query(n1).join(Node, n1.parent).filter(Node.data=='n1').all(),
- [Node(parent_id=1,data=u'n11',id=2), Node(parent_id=1,data=u'n12',id=3), Node(parent_id=1,data=u'n13',id=4)]
- )
-
+ assert_raises(sa.orm.exc.MultipleResultsFound, sess.query(User).scalar)
+ assert_raises(sa.orm.exc.MultipleResultsFound, sess.query(User.id, User.name).scalar)
@testing.resolve_artifact_names
- def test_multiple_explicit_entities(self):
- sess = create_session()
-
- parent = aliased(Node)
- grandparent = aliased(Node)
- eq_(
- sess.query(Node, parent, grandparent).\
- join(parent, Node.parent).\
- join(grandparent, parent.parent).\
- filter(Node.data=='n122').filter(parent.data=='n12').\
- filter(grandparent.data=='n1').first(),
- (Node(data='n122'), Node(data='n12'), Node(data='n1'))
- )
-
- eq_(
- sess.query(Node, parent, grandparent).\
- join(parent, Node.parent).\
- join(grandparent, parent.parent).\
- filter(Node.data=='n122').filter(parent.data=='n12').\
- filter(grandparent.data=='n1').from_self().first(),
- (Node(data='n122'), Node(data='n12'), Node(data='n1'))
- )
-
- # same, change order around
- eq_(
- sess.query(parent, grandparent, Node).\
- join(parent, Node.parent).\
- join(grandparent, parent.parent).\
- filter(Node.data=='n122').filter(parent.data=='n12').\
- filter(grandparent.data=='n1').from_self().first(),
- (Node(data='n12'), Node(data='n1'), Node(data='n122'))
- )
-
- eq_(
- sess.query(Node, parent, grandparent).\
- join(parent, Node.parent).\
- join(grandparent, parent.parent).\
- filter(Node.data=='n122').filter(parent.data=='n12').\
- filter(grandparent.data=='n1').\
- options(joinedload(Node.children)).first(),
- (Node(data='n122'), Node(data='n12'), Node(data='n1'))
- )
-
- eq_(
- sess.query(Node, parent, grandparent).\
- join(parent, Node.parent).\
- join(grandparent, parent.parent).\
- filter(Node.data=='n122').filter(parent.data=='n12').\
- filter(grandparent.data=='n1').from_self().\
- options(joinedload(Node.children)).first(),
- (Node(data='n122'), Node(data='n12'), Node(data='n1'))
- )
-
-
- @testing.resolve_artifact_names
- def test_any(self):
- sess = create_session()
- eq_(sess.query(Node).filter(Node.children.any(Node.data=='n1')).all(), [])
- eq_(sess.query(Node).filter(Node.children.any(Node.data=='n12')).all(), [Node(data='n1')])
- eq_(sess.query(Node).filter(~Node.children.any()).order_by(Node.id).all(),
- [Node(data='n11'), Node(data='n13'),Node(data='n121'),Node(data='n122'),Node(data='n123'),])
-
- @testing.resolve_artifact_names
- def test_has(self):
- sess = create_session()
-
- eq_(sess.query(Node).filter(Node.parent.has(Node.data=='n12')).order_by(Node.id).all(),
- [Node(data='n121'),Node(data='n122'),Node(data='n123')])
- eq_(sess.query(Node).filter(Node.parent.has(Node.data=='n122')).all(), [])
- eq_(sess.query(Node).filter(~Node.parent.has()).all(), [Node(data='n1')])
-
- @testing.resolve_artifact_names
- def test_contains(self):
- sess = create_session()
-
- n122 = sess.query(Node).filter(Node.data=='n122').one()
- eq_(sess.query(Node).filter(Node.children.contains(n122)).all(), [Node(data='n12')])
-
- n13 = sess.query(Node).filter(Node.data=='n13').one()
- eq_(sess.query(Node).filter(Node.children.contains(n13)).all(), [Node(data='n1')])
-
- @testing.resolve_artifact_names
- def test_eq_ne(self):
- sess = create_session()
-
- n12 = sess.query(Node).filter(Node.data=='n12').one()
- eq_(sess.query(Node).filter(Node.parent==n12).all(), [Node(data='n121'),Node(data='n122'),Node(data='n123')])
-
- eq_(sess.query(Node).filter(Node.parent != n12).all(), [Node(data='n1'), Node(data='n11'), Node(data='n12'), Node(data='n13')])
-
-class SelfReferentialM2MTest(_base.MappedTest):
- run_setup_mappers = 'once'
- run_inserts = 'once'
- run_deletes = None
-
- @classmethod
- def define_tables(cls, metadata):
- global nodes, node_to_nodes
- nodes = Table('nodes', metadata,
- Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('data', String(30)))
-
- node_to_nodes =Table('node_to_nodes', metadata,
- Column('left_node_id', Integer, ForeignKey('nodes.id'),primary_key=True),
- Column('right_node_id', Integer, ForeignKey('nodes.id'),primary_key=True),
- )
-
- @classmethod
- def insert_data(cls):
- global Node
-
- class Node(Base):
- pass
-
- mapper(Node, nodes, properties={
- 'children':relationship(Node, lazy='select', secondary=node_to_nodes,
- primaryjoin=nodes.c.id==node_to_nodes.c.left_node_id,
- secondaryjoin=nodes.c.id==node_to_nodes.c.right_node_id,
- )
- })
- sess = create_session()
- n1 = Node(data='n1')
- n2 = Node(data='n2')
- n3 = Node(data='n3')
- n4 = Node(data='n4')
- n5 = Node(data='n5')
- n6 = Node(data='n6')
- n7 = Node(data='n7')
-
- n1.children = [n2, n3, n4]
- n2.children = [n3, n6, n7]
- n3.children = [n5, n4]
-
- sess.add(n1)
- sess.add(n2)
- sess.add(n3)
- sess.add(n4)
- sess.flush()
- sess.close()
-
- def test_any(self):
- sess = create_session()
- eq_(sess.query(Node).filter(Node.children.any(Node.data=='n3')).all(), [Node(data='n1'), Node(data='n2')])
-
- def test_contains(self):
- sess = create_session()
- n4 = sess.query(Node).filter_by(data='n4').one()
-
- eq_(sess.query(Node).filter(Node.children.contains(n4)).order_by(Node.data).all(), [Node(data='n1'), Node(data='n3')])
- eq_(sess.query(Node).filter(not_(Node.children.contains(n4))).order_by(Node.data).all(), [Node(data='n2'), Node(data='n4'), Node(data='n5'), Node(data='n6'), Node(data='n7')])
-
- def test_explicit_join(self):
- sess = create_session()
-
- n1 = aliased(Node)
- eq_(
- sess.query(Node).select_from(join(Node, n1, 'children')).filter(n1.data.in_(['n3', 'n7'])).order_by(Node.id).all(),
- [Node(data='n1'), Node(data='n2')]
- )
-
-class ExternalColumnsTest(QueryTest):
- """test mappers with SQL-expressions added as column properties."""
-
- run_setup_mappers = None
-
- def test_external_columns_bad(self):
-
- assert_raises_message(sa_exc.ArgumentError, "not represented in the mapper's table", mapper, User, users, properties={
- 'concat': (users.c.id * 2),
- })
- clear_mappers()
-
- def test_external_columns(self):
- """test querying mappings that reference external columns or selectables."""
-
- mapper(User, users, properties={
- 'concat': column_property((users.c.id * 2)),
- 'count': column_property(
- select([func.count(addresses.c.id)], users.c.id==addresses.c.user_id).\
- correlate(users).\
- as_scalar())
- })
-
- mapper(Address, addresses, properties={
- 'user':relationship(User)
- })
-
- sess = create_session()
-
- sess.query(Address).options(joinedload('user')).all()
-
- eq_(sess.query(User).all(),
- [
- User(id=7, concat=14, count=1),
- User(id=8, concat=16, count=3),
- User(id=9, concat=18, count=1),
- User(id=10, concat=20, count=0),
- ]
- )
-
- address_result = [
- Address(id=1, user=User(id=7, concat=14, count=1)),
- Address(id=2, user=User(id=8, concat=16, count=3)),
- Address(id=3, user=User(id=8, concat=16, count=3)),
- Address(id=4, user=User(id=8, concat=16, count=3)),
- Address(id=5, user=User(id=9, concat=18, count=1))
- ]
- eq_(sess.query(Address).all(), address_result)
-
- # run the eager version twice to test caching of aliased clauses
- for x in range(2):
- sess.expunge_all()
- def go():
- eq_(sess.query(Address).\
- options(joinedload('user')).\
- order_by(Address.id).all(),
- address_result)
- self.assert_sql_count(testing.db, go, 1)
-
- ualias = aliased(User)
- eq_(
- sess.query(Address, ualias).join(ualias, 'user').all(),
- [(address, address.user) for address in address_result]
- )
-
- eq_(
- sess.query(Address, ualias.count).\
- join(ualias, 'user').\
- join('user', aliased=True).\
- order_by(Address.id).all(),
- [
- (Address(id=1), 1),
- (Address(id=2), 3),
- (Address(id=3), 3),
- (Address(id=4), 3),
- (Address(id=5), 1)
- ]
- )
-
- eq_(sess.query(Address, ualias.concat, ualias.count).
- join(ualias, 'user').
- join('user', aliased=True).order_by(Address.id).all(),
- [
- (Address(id=1), 14, 1),
- (Address(id=2), 16, 3),
- (Address(id=3), 16, 3),
- (Address(id=4), 16, 3),
- (Address(id=5), 18, 1)
- ]
- )
-
- ua = aliased(User)
- eq_(sess.query(Address, ua.concat, ua.count).
- select_from(join(Address, ua, 'user')).
- options(joinedload(Address.user)).order_by(Address.id).all(),
- [
- (Address(id=1, user=User(id=7, concat=14, count=1)), 14, 1),
- (Address(id=2, user=User(id=8, concat=16, count=3)), 16, 3),
- (Address(id=3, user=User(id=8, concat=16, count=3)), 16, 3),
- (Address(id=4, user=User(id=8, concat=16, count=3)), 16, 3),
- (Address(id=5, user=User(id=9, concat=18, count=1)), 18, 1)
- ]
- )
-
- eq_(list(sess.query(Address).join('user').values(Address.id, User.id, User.concat, User.count)),
- [(1, 7, 14, 1), (2, 8, 16, 3), (3, 8, 16, 3), (4, 8, 16, 3), (5, 9, 18, 1)]
- )
-
- eq_(list(sess.query(Address, ua).select_from(join(Address,ua, 'user')).values(Address.id, ua.id, ua.concat, ua.count)),
- [(1, 7, 14, 1), (2, 8, 16, 3), (3, 8, 16, 3), (4, 8, 16, 3), (5, 9, 18, 1)]
- )
-
- def test_external_columns_joinedload(self):
- # in this test, we have a subquery on User that accesses "addresses", underneath
- # an joinedload for "addresses". So the "addresses" alias adapter needs to *not* hit
- # the "addresses" table within the "user" subquery, but "user" still needs to be adapted.
- # therefore the long standing practice of eager adapters being "chained" has been removed
- # since its unnecessary and breaks this exact condition.
- mapper(User, users, properties={
- 'addresses':relationship(Address, backref='user', order_by=addresses.c.id),
- 'concat': column_property((users.c.id * 2)),
- 'count': column_property(select([func.count(addresses.c.id)], users.c.id==addresses.c.user_id).correlate(users))
- })
- mapper(Address, addresses)
- mapper(Order, orders, properties={
- 'address':relationship(Address), # m2o
- })
-
+ def test_value(self):
sess = create_session()
- def go():
- o1 = sess.query(Order).options(joinedload_all('address.user')).get(1)
- eq_(o1.address.user.count, 1)
- self.assert_sql_count(testing.db, go, 1)
- sess = create_session()
- def go():
- o1 = sess.query(Order).options(joinedload_all('address.user')).first()
- eq_(o1.address.user.count, 1)
- self.assert_sql_count(testing.db, go, 1)
+ eq_(sess.query(User).filter_by(id=7).value(User.id), 7)
+ eq_(sess.query(User.id, User.name).filter_by(id=7).value(User.id), 7)
+ eq_(sess.query(User).filter_by(id=0).value(User.id), None)
-class TestOverlyEagerEquivalentCols(_base.MappedTest):
- @classmethod
- def define_tables(cls, metadata):
- global base, sub1, sub2
- base = Table('base', metadata,
- Column('id', Integer, primary_key=True, test_needs_autoincrement=True),
- Column('data', String(50))
- )
+ sess.bind = testing.db
+ eq_(sess.query().value(sa.literal_column('1').label('x')), 1)
- sub1 = Table('sub1', metadata,
- Column('id', Integer, ForeignKey('base.id'), primary_key=True),
- Column('data', String(50))
- )
- sub2 = Table('sub2', metadata,
- Column('id', Integer, ForeignKey('base.id'), ForeignKey('sub1.id'), primary_key=True),
- Column('data', String(50))
- )
- def test_equivs(self):
- class Base(_base.ComparableEntity):
- pass
- class Sub1(_base.ComparableEntity):
- pass
- class Sub2(_base.ComparableEntity):
- pass
-
- mapper(Base, base, properties={
- 'sub1':relationship(Sub1),
- 'sub2':relationship(Sub2)
- })
-
- mapper(Sub1, sub1)
- mapper(Sub2, sub2)
- sess = create_session()
-
- s11 = Sub1(data='s11')
- s12 = Sub1(data='s12')
- s2 = Sub2(data='s2')
- b1 = Base(data='b1', sub1=[s11], sub2=[])
- b2 = Base(data='b1', sub1=[s12], sub2=[])
- sess.add(b1)
- sess.add(b2)
- sess.flush()
-
- # theres an overlapping ForeignKey here, so not much option except
- # to artifically control the flush order
- b2.sub2 = [s2]
- sess.flush()
- q = sess.query(Base).outerjoin('sub2', aliased=True)
- assert sub1.c.id not in q._filter_aliases.equivalents
-
- eq_(
- sess.query(Base).join('sub1').outerjoin('sub2', aliased=True).\
- filter(Sub1.id==1).one(),
- b1
- )
class UpdateDeleteTest(_base.MappedTest):
@classmethod