Re: Aggregating both tables in a join? - Mailing list pgsql-sql

From Aaron Bono
Subject Re: Aggregating both tables in a join?
Date
Msg-id bf05e51c0701111155l640194bble2c5c647db20cf93@mail.gmail.com
Whole thread Raw
In response to Aggregating both tables in a join?  ("Steve Sabljak" <sql-ss@sabljak.org>)
List pgsql-sql
On 1/11/07, Steve Sabljak <sql-ss@sabljak.org> wrote:


select cf.flight_id, tl1.num_legs, cf.cmp_flight_id, tl2.num_legs cmp_num_legs
from cmp_flight cf
    join (select fl1.flight_id fid1, count(*) num_legs
        from flight_leg fl1 group by fl1.flight_id) tl1 on fid1 = cf.flight_id
    join (select fl2.flight_id fid2, count(*) num_legs
        from flight_leg fl2 group by fl2.flight_id) tl2 on fid2 =
cf.cmp_flight_id;

Is this a better way to go about it?
I've considered keeping a track of the number of legs in the flight
table, using a trigger, but it doesn't seem relationally 'clean'.


You can try this but I cannot say which would perform better.  I have heard many times that "distinct" can be a performance killer.

select
    cf.flight_id,
    count(distinct(fl1.leg_id)) as num_legs,
    cf.cmp_flight_id,
    count(distinct(fl2.leg_id)) cmp_num_legs
from cmp_flight cf
join flight_leg fl1 on fl1.flight_id = cf.flight_id
join flight_leg fl2 on fl2.flight_id = cf.cmp_flight_id
group by
    cf.flight_id,
    cf.cmp_flight_id
;

This can give different results if you don't have a unique constraint (or primary key set to) cmp_flight.flight_id, cmp_flight.cmp_flight_id .

--
==================================================================
   Aaron Bono
   Aranya Software Technologies, Inc.
   http://www.aranya.com
   http://codeelixir.com
==================================================================

pgsql-sql by date:

Previous
From: Bruno Wolff III
Date:
Subject: Re: How to aggregates this data
Next
From: "devil live"
Date:
Subject: Conditional SQL Query