Thread: How to join several selects

How to join several selects

From
Josep Sanmartí
Date:
Hello,
I have a 'big' problem:
I have the following table users(name, start_time, end_time), a new row 
is set whenever a user logs into a server.  I want to know how many 
users have logged in EVERYDAY between 2 different dates. The only idea 
that I have is making several select (one for each day):   SELECT COUNT(name) FROM users WHERE start_time between
"startDate"
 
and "startDate+1"   SELECT COUNT(name) FROM users WHERE start_time between "startDate+1" 
and "startDate+2"   ...
I would like to know if its possible to make it in 1 sql statement or 
just which is the best efficient way to solve it.
By the way, I use Postgres 7.4.

Thanks!

-- 
Josep Sanmarti
Analista de Projectes

Grup OpenWired, S.L.
Caballero, 87 - 08029 - Barcelona (Spain)
Tel (+34) 93/410 75 70 - Fax (+34) 93/419 45 91



Re: How to join several selects

From
Sean Davis
Date:
On 8/24/05 9:46 AM, "Josep Sanmartí" <josep.sanmarti@openwired.net> wrote:

> Hello,
> I have a 'big' problem:
> I have the following table users(name, start_time, end_time), a new row
> is set whenever a user logs into a server.  I want to know how many
> users have logged in EVERYDAY between 2 different dates. The only idea
> that I have is making several select (one for each day):
>   SELECT COUNT(name) FROM users WHERE start_time between "startDate"
> and "startDate+1"
>   SELECT COUNT(name) FROM users WHERE start_time between "startDate+1"
> and "startDate+2"
>   ...
> I would like to know if its possible to make it in 1 sql statement or
> just which is the best efficient way to solve it.
> By the way, I use Postgres 7.4.


See:

http://www.postgresql.org/docs/8.0/interactive/sql-select.html#SQL-UNION
like:

SELECT COUNT(name) FROM users WHERE start_time between "startDate"and "startDate+1"
union
SELECT COUNT(name) FROM users WHERE start_time between "startDate+1"and "startDate+2"

Sean



Re: How to join several selects

From
Rod Taylor
Date:
On Wed, 2005-08-24 at 15:46 +0200, Josep Sanmartí wrote:
> Hello,
> I have a 'big' problem:
> I have the following table users(name, start_time, end_time), a new row
> is set whenever a user logs into a server.  I want to know how many
> users have logged in EVERYDAY between 2 different dates. The only idea
> that I have is making several select (one for each day):
>     SELECT COUNT(name) FROM users WHERE start_time between "startDate"
> and "startDate+1"
>     SELECT COUNT(name) FROM users WHERE start_time between "startDate+1"
> and "startDate+2"

You have columns named "startDate+2" or are you adding 2 days to a
column named "startDate"?

--



Re: How to join several selects

From
Michael Glaesemann
Date:
On Aug 24, 2005, at 11:03 PM, Sean Davis wrote:

> On 8/24/05 9:46 AM, "Josep Sanmartí" <josep.sanmarti@openwired.net>
> wrote:
>
>
>> Hello,
>> I have a 'big' problem:
>> I have the following table users(name, start_time, end_time), a
>> new row
>> is set whenever a user logs into a server.  I want to know how many
>> users have logged in EVERYDAY between 2 different dates. The only
>> idea
>> that I have is making several select (one for each day):
>>   SELECT COUNT(name) FROM users WHERE start_time between "startDate"
>> and "startDate+1"
>>   SELECT COUNT(name) FROM users WHERE start_time between "startDate
>> +1"
>> and "startDate+2"
>>   ...
>> I would like to know if its possible to make it in 1 sql statement or
>> just which is the best efficient way to solve it.
>> By the way, I use Postgres 7.4.
>>
>
>
> See:
>
> http://www.postgresql.org/docs/8.0/interactive/sql-select.html#SQL-
> UNION
> like:
>
> SELECT COUNT(name) FROM users WHERE start_time between "startDate"
>  and "startDate+1"
> union
> SELECT COUNT(name) FROM users WHERE start_time between "startDate+1"
>  and "startDate+2"

I'm guessing he wants something more like this, so he knows which
period is which:

SELECT count_1, count_2
FROM (    SELECT COUNT(name) AS count_1    FROM users    WHERE start_time BETWEEN startDate AND startDate + 1    ) as
period_1
CROSS JOIN (    SELECT COUNT(name) AS count_2    FROM users    WHERE start_time BETWEEN startDate + 1 AND startDate + 2
  ) as period_2 

Though, you could do the same thing using UNION like this:

SELECT 'period_1'::text as period, COUNT(name) AS num_of_users
FROM users
WHERE start_time BETWEEN startDate AND startDate + 1

UNION

SELECT 'period_2'::text as period, COUNT(name) AS num_of_users
FROM users
WHERE start_time BETWEEN startDate + 1 AND startDate + 2

And of course, using EXPLAIN ANALYZE will help decide which is more
performant.

Michael Glaesemann
grzm myrealbox com




Re: How to join several selects

From
Zac
Date:
Josep Sanmartí wrote:
> Hello,
> I have a 'big' problem:
> I have the following table users(name, start_time, end_time), a new row 
> is set whenever a user logs into a server.  I want to know how many 
> users have logged in EVERYDAY between 2 different dates. The only idea 
> that I have is making several select (one for each day):
>    SELECT COUNT(name) FROM users WHERE start_time between "startDate" 
> and "startDate+1"
>    SELECT COUNT(name) FROM users WHERE start_time between "startDate+1" 
> and "startDate+2"
>    ...
> I would like to know if its possible to make it in 1 sql statement or 
> just which is the best efficient way to solve it.
> By the way, I use Postgres 7.4.
> 
> Thanks!
> 
SELECTdate_trunc('day', start_time) as day, count(name)
FROMusers
WHEREstart_time between "startDate" AND "endDate"
GROUP BYday;