How to order_by relation by another join?

2,431 views
Skip to first unread message

Andrija Zarić

unread,
Feb 10, 2010, 10:17:58 AM2/10/10
to sqlalchemy
Let's say I've got simple structure Order-->Item-->Detail.

class Detail(Base):
...

class Order(Base):
...

class Item(Base):
...
detail = relation(Detail, uselist=False, lazy=False)
order = relation(Order, uselist=False, backref='items')

Of course I can specify order_by for Order.items by any columns from
Item, but is there a way I can order_by a column defined in Detail?

I've naively tried something as backref('items', order_by=Detail.id),
but because Detail is anonymously joined to Item as e.g. 'details_1',
I've received ProgrammingError: invalid reference to FROM-clause
entry for table "details".

Michael Bayer

unread,
Feb 10, 2010, 10:34:28 AM2/10/10
to sqlal...@googlegroups.com

The Order.items collection doesn't have the ability to order by a remote column in the collection, unless you set the order_by to a subquery that joined out to the ultimate target you care about.

Maybe, I haven't tried this, you could make an alternate (non primary) mapping to Item that was a join of Item and Detail, i.e. like:

itemdetail = mapper(Item.__table__.join(Detail.__table__), non_primary=True)

Order.items = relation(itemdetail, order_by=itemdetail.c.detail_id)

I'm not 100% sure the non-primary mapper allowing additional attributes, and it might need to be a mapping of a select().select_from(join) and not the join directly, but if you have some time to experiment you might get something out of that.


>
> --
> You received this message because you are subscribed to the Google Groups "sqlalchemy" group.
> To post to this group, send email to sqlal...@googlegroups.com.
> To unsubscribe from this group, send email to sqlalchemy+...@googlegroups.com.
> For more options, visit this group at http://groups.google.com/group/sqlalchemy?hl=en.
>

Michael Bayer

unread,
Feb 10, 2010, 10:56:26 AM2/10/10
to sqlal...@googlegroups.com

On Feb 10, 2010, at 10:34 AM, Michael Bayer wrote:

> Maybe, I haven't tried this, you could make an alternate (non primary) mapping to Item that was a join of Item and Detail, i.e. like:
>
> itemdetail = mapper(Item.__table__.join(Detail.__table__), non_primary=True)
>
> Order.items = relation(itemdetail, order_by=itemdetail.c.detail_id)
>
> I'm not 100% sure the non-primary mapper allowing additional attributes, and it might need to be a mapping of a select().select_from(join) and not the join directly, but if you have some time to experiment you might get something out of that.

Here, I think it works:

from sqlalchemy import *
from sqlalchemy.orm import *
from sqlalchemy.ext.declarative import declarative_base

engine = create_engine('sqlite://', echo=True)
Base = declarative_base()

class Detail(Base):
__tablename__ = 'detail'

id = Column(Integer, primary_key=True)
item_id = Column(Integer, ForeignKey('item.id'))

class Order(Base):
__tablename__ = 'order'
id = Column(Integer, primary_key=True)

class Item(Base):
__tablename__ = 'item'
id = Column(Integer, primary_key=True)
order_id = Column(Integer, ForeignKey('order.id'))



detail = relation(Detail, uselist=False, lazy=False)

order = relation(Order, uselist=False)

j = Item.__table__.join(Detail.__table__)
itemdetail = mapper(Item, j, non_primary=True)
Order.items = relation(itemdetail, order_by=j.c.detail_id, viewonly=True)

metadata = Base.metadata
metadata.create_all(engine)
Session = scoped_session(sessionmaker(bind=engine))
Session.query(Order).options(eagerload(Order.items)).all()

the query is:

SELECT "order".id AS order_id, anon_1.item_id AS anon_1_item_id, anon_1.detail_id AS anon_1_detail_id, anon_1.item_order_id AS anon_1_item_order_id, anon_1.detail_item_id AS anon_1_detail_item_id
FROM "order" LEFT OUTER JOIN (SELECT item.id AS item_id, item.order_id AS item_order_id, detail.id AS detail_id, detail.item_id AS detail_item_id
FROM item JOIN detail ON item.id = detail.item_id) AS anon_1 ON "order".id = anon_1.item_order_id ORDER BY anon_1.detail_id

However I can't currently get "back_populates" or "backref" to relate the two sides together. which isn't necessary if you dont need it.


Andrija Zarić

unread,
Feb 11, 2010, 6:45:34 AM2/11/10
to sqlalchemy
Thanks, Mike!

Your example indeed works, but unfortunately when I add inheritance,
mapper fails to generate proper (inherited) class:
(I've changed code a little, so it represents more what I'm trying to
do)

from sqlalchemy import *
from sqlalchemy.orm import *
from sqlalchemy.ext.declarative import declarative_base

engine = create_engine('sqlite://', echo=True)
Base = declarative_base()

class Detail(Base):
__tablename__ = 'detail'
id = Column(Integer, primary_key=True)

sort = Column(Integer)

class Order(Base):
__tablename__ = 'order'
id = Column(Integer, primary_key=True)

class Item(Base):
__tablename__ = 'item'
id = Column(Integer, primary_key=True)
order_id = Column(Integer, ForeignKey('order.id'))

detail_id = Column(Integer, ForeignKey('detail.id'))

detail = relation(Detail, uselist=False, lazy=False)
order = relation(Order, uselist=False)

type = Column(String(20))
__mapper_args__ = { 'polymorphic_on' : type}


class ValueItem(Item):
__mapper_args__ = { 'polymorphic_identity' : 'quantity' }
value = Column('quantity_value', Numeric(15, 4))


class ErrorItem(Item):
__mapper_args__ = { 'polymorphic_identity' : 'error' }
value = Column('error_value', String(15, 4))


Order.items = relation(Item)


j = Item.__table__.join(Detail.__table__)
itemdetail = mapper(Item, j, non_primary=True)

Order.sorteditems = relation(itemdetail,
order_by=Detail.__table__.c.sort, viewonly=True)

metadata = Base.metadata
metadata.create_all(engine)
Session = scoped_session(sessionmaker(bind=engine))

order = Order(id=1)
Session.add(order)
detail = Detail(id=1, sort=1)
order.items.append(ValueItem(id=1, detail=detail))

Session.commit()

for order in Session.query(Order).all():
for item in order.sorteditems:
print item
for item in order.items:
print item

...
<__main__.Item object at 0x881ddac>

<__main__.ValueItem object at 0x960da6c>


Am I making a obvious mistake somewhere here?

Michael Bayer

unread,
Feb 11, 2010, 8:26:40 AM2/11/10
to sqlal...@googlegroups.com

On Feb 11, 2010, at 6:45 AM, Andrija Zarić wrote:

> Thanks, Mike!
>
> Your example indeed works, but unfortunately when I add inheritance,
> mapper fails to generate proper (inherited) class:
> (I've changed code a little, so it represents more what I'm trying to
> do)

> class ValueItem(Item):


> __mapper_args__ = { 'polymorphic_identity' : 'quantity' }
> value = Column('quantity_value', Numeric(15, 4))
>
>
> class ErrorItem(Item):
> __mapper_args__ = { 'polymorphic_identity' : 'error' }
> value = Column('error_value', String(15, 4))

I'm assuming these are single-table inheritance mappers (I forgot about that "add the column" trick..)

So yeah my solution was a quick hack and to continue in this way you'd have to build non-primary mappers for each of ValueItem, ErrorItem that state "inherits" for the original non-primary mapper, using the polymorphic identities as well. It would still work.

If you don't care much about a high-scaling query you could ditch the secondary mapper idea and order by a subquery, like

detail_alias = Detail.__table__.alias()
class Order(Base):
items = relation(Item, order_by=select([detail_alias.c.id]).where(detail_alias.c.id==Item.__table__.c.detail_id).alias())

again somehting i haven't tried, but should work in theory.

Andrija Zarić

unread,
Feb 11, 2010, 8:57:44 AM2/11/10
to sqlal...@googlegroups.com
On 11 February 2010 14:26, Michael Bayer <mik...@zzzcomputing.com> wrote:
> I'm assuming these are single-table inheritance mappers (I forgot about that "add the column" trick..)
>
> So yeah my solution was a quick hack and to continue in this way you'd have to build non-primary mappers for each of ValueItem, ErrorItem that state "inherits" for the original non-primary mapper, using the polymorphic identities as well.   It would still work.

Thanks again!

It's obvious now, of course. When I added other non-primary mappers,
inheritance is working. I suppose declarative extension spoiled me...

Reply all
Reply to author
Forward
0 new messages