Re: Combining two SELECTs by same filters

From: Michael Fuhr <mike(at)fuhr(dot)org>
To: Volkan YAZICI <volkan(dot)yazici(at)gmail(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Combining two SELECTs by same filters
Date: 2005-10-26 16:15:58
Message-ID: 20051026161558.GA44965@winnie.fuhr.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On Wed, Oct 26, 2005 at 06:16:13PM +0300, Volkan YAZICI wrote:
> => SELECT
> -> (SELECT count(id) FROM sales
> -> WHERE id = 2
> -> AND date_trunc('hour', dt) = '2005-10-25 21:00:00'),
> -> (SELECT count(id) FROM sales
> -> WHERE id = 2
> -> AND date_trunc('hour', dt) = '2005-10-25 22:00:00');
> ?column? | ?column?
> ----------+----------
> 6 | 2
> (1 row)
>
> Isn't it possible to combine these two SELECTs as one.

If you can accept multiple rows instead of multiple columns then
one way would be to group by the hour:

SELECT date_trunc('hour', dt) AS hour, count(*)
FROM sales
WHERE id = 2
AND date_trunc('hour', dt) IN ('2005-10-25 21:00:00', '2005-10-25 22:00:00')
GROUP BY hour
ORDER BY hour;
hour | count
---------------------+-------
2005-10-25 21:00:00 | 6
2005-10-25 22:00:00 | 2
(2 rows)

Here's another possibility, but I find it a bit ugly:

SELECT sum(CASE date_trunc('hour', dt)
WHEN '2005-10-25 21:00:00' THEN 1
ELSE 0
END) AS count1,
sum(CASE date_trunc('hour', dt)
WHEN '2005-10-25 22:00:00' THEN 1
ELSE 0
END) AS count2
FROM sales
WHERE id = 2;
count1 | count2
--------+--------
6 | 2
(1 row)

If you're looking for the fastest method then use EXPLAIN ANALYZE
on each to see what works best on your data set.

--
Michael Fuhr

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Scott Marlowe 2005-10-26 16:18:36 Re: why vacuum
Previous Message chester c young 2005-10-26 16:12:57 Re: broken join optimization? (8.0)