Re: Combining two SELECTs by same filters - Mailing list pgsql-sql

From Michael Fuhr
Subject Re: Combining two SELECTs by same filters
Date
Msg-id 20051026161558.GA44965@winnie.fuhr.org
Whole thread Raw
In response to Combining two SELECTs by same filters  (Volkan YAZICI <volkan.yazici@gmail.com>)
List 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 |     62005-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


pgsql-sql by date:

Previous
From: Tom Lane
Date:
Subject: Re: why vacuum
Next
From: Scott Marlowe
Date:
Subject: Re: why vacuum