Re: Drawing a blank on some SQL

From: Samuel Gendler <sgendler(at)ideasculptor(dot)com>
To: Aaron Burnett <aburnett(at)bzzagent(dot)com>
Cc: "pgsql-sql(at)postgresql(dot)org" <pgsql-sql(at)postgresql(dot)org>
Subject: Re: Drawing a blank on some SQL
Date: 2011-02-11 19:22:14
Message-ID: AANLkTi=QyMsdU6YVww4gx1=76sDvh5HTm3GxgEf2Y7Jm@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Assuming you have a table which lists all possible activities, with one
activity per row and no duplicates, you need to do a left outer join between
activities and your query result. That will generate a resultset that has
at least one row for every row in activities, with nulls in all the columns
coming from the query for rows that don't have a match. Then use coalesce
to turn null into 0. Something like this:

select a.activity_id, coalesce(q.total, 0) as total
from activities a left outer join
(select fa.activity_id, count(fa.activity_id) as total from foo_activity fa
where fa.created between '01/01/2011' and '01/08/2011'
group by 1) q on a.activity_id = q.activity_id
order by a.activity_id

If you don't have an activities table with one row per activity, just
replace the activities table in that query with another query - select
distinct activity_id from foo_activity

On Fri, Feb 11, 2011 at 10:46 AM, Aaron Burnett <aburnett(at)bzzagent(dot)com>wrote:

>
> Hi,
>
> I'm just drawing a blank entirely today and would appreciate some help on
> this.
>
> The long and short; there are 12 distinct activities that need to be
> queried
> on a weekly basis:
>
> SELECT count(activity_id), activity_id
> FROM foo_activity
> WHERE created >= '01/01/2011' and created < '01/08/2011'
> GROUP BY 2
> ORDER BY 2;
>
> It gives me this answer, which is correct:
>
> count | activity_id
> -------+---------------------
> 1502 | 1
> 11 | 2
> 2 | 3
> 815 | 4
> 4331 | 7
> 30 | 9
> 1950 | 10
> 7 | 11
> 67 | 12
>
> But what I need to see is if there are no activities for the particular
> activity_id that week, that it lists the count as 0 and lists the
> activity_id associated like this:
>
> count | activity_id
> -------+---------------------
> 1502 | 1
> 11 | 2
> 2 | 3
> 815 | 4
> 0 | 5
> 0 | 6
> 4331 | 7
> 0 | 8
> 30 | 9
> 1950 | 10
> 7 | 11
> 67 | 12
>
> Thanking you in advance for any help on this. The caffiene seems to be not
> working well today.
>
> Aaron
>
>
> --
> Sent via pgsql-sql mailing list (pgsql-sql(at)postgresql(dot)org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-sql
>

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Osvaldo Kussama 2011-02-11 20:09:10 Re: Drawing a blank on some SQL
Previous Message Rob Sargent 2011-02-11 19:17:08 Re: Drawing a blank on some SQL