Thread: Doing a conditional aggregate (e.g. count(*) if x=y) in postgres?

Doing a conditional aggregate (e.g. count(*) if x=y) in postgres?

From
Bryce Nesbitt
Date:
All;
Is there a way to get a conditional aggregate?  I have this two column view:
SELECT count(*) AS count, xx_plan.plan_name  FROM xx_membership  JOIN xx_account USING (account_id)  JOIN xx_plan USING
(plan_id)WHERE xx_membership.status = 10 GROUP BY xx_plan.plan_name;
 

And would like to add additional columns (not rows) breaking out
"status=20" and "status=30" totals.
Is this possible without a stored procedure?



Re: Doing a conditional aggregate (e.g. count(*) if x=y) in postgres?

From
"Jim Buttafuoco"
Date:
Use case statement and sum to get a count where status=20...

For example

Select sum(case when status=20 then 1 else 0 end) as status20,      Sum(case when status=30 then 1 else 0 end) as
status30
....


-----Original Message-----
From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org]
On Behalf Of Bryce Nesbitt
Sent: Monday, May 14, 2007 6:56 PM
To: pgsql-sql@postgresql.org
Subject: [SQL] Doing a conditional aggregate (e.g. count(*) if x=y) in
postgres?

All;
Is there a way to get a conditional aggregate?  I have this two column view:
SELECT count(*) AS count, xx_plan.plan_name  FROM xx_membership  JOIN xx_account USING (account_id)  JOIN xx_plan USING
(plan_id)WHERE xx_membership.status = 10 GROUP BY xx_plan.plan_name;
 

And would like to add additional columns (not rows) breaking out
"status=20" and "status=30" totals.
Is this possible without a stored procedure?


---------------------------(end of broadcast)---------------------------
TIP 2: Don't 'kill -9' the postmaster




Re: Doing a conditional aggregate (e.g. count(*) if x=y) in postgres?

From
Geoff Tolley
Date:
Bryce Nesbitt wrote:
> All;
> Is there a way to get a conditional aggregate?  I have this two column view:
> 
>  SELECT count(*) AS count, xx_plan.plan_name
>    FROM xx_membership
>    JOIN xx_account USING (account_id)
>    JOIN xx_plan USING (plan_id)
>   WHERE xx_membership.status = 10
>   GROUP BY xx_plan.plan_name;
> 
> And would like to add additional columns (not rows) breaking out
> "status=20" and "status=30" totals.
> Is this possible without a stored procedure?

SELECT sum(CASE WHEN xx_membership.status = 10 THEN 1 ELSE 0 END) AS sum10,       sum(CASE WHEN xx_membership.status =
20THEN 1 ELSE 0 END) AS sum20,       sum(CASE WHEN xx_membership.status = 30 THEN 1 ELSE 0 END) AS sum30,
xx_plan.plan_name FROM xx_membership  JOIN xx_account USING (account_id)  JOIN xx_plan USING (plan_id) WHERE
xx_membership.statusIN (10,20,30) GROUP BY xx_plan.plan_name;
 

You may or may not care about including the WHERE clause there depending 
upon its selectivity and whether there's an index for the planner to use.

HTH,
Geoff


Re: Doing a conditional aggregate (e.g. count(*) if x=y) in postgres?

From
Bryce Nesbitt
Date:
Ah perfect.  I was struggling with CASE outside the SUM(), which was not
working.