Re: Displaying first, last, count columns

From: "Aaron Bono" <postgresql(at)aranya(dot)com>
To: "Worky Workerson" <worky(dot)workerson(at)gmail(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Displaying first, last, count columns
Date: 2006-06-21 15:10:48
Message-ID: bf05e51c0606210810x26ecb272t6d873a0bcbddfb03@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

I would suggest:

select
max(time_occurred) AS last_seen,
min(time_occurred) AS first_seen,
count(*),
prog_data
from t
group by
prog_data

I would also suggest you use inner joins rather than put all your tables in
the from and join in the where clause. It is much easier to read and
understand what you are trying to do. The query you have is not exactly the
same as what I put above but I bet the performance is bad because you have
inner queries that have constraints based on the outer query. I usually
avoid this as much as possible.

-Aaron Bono

On 6/21/06, Worky Workerson <worky(dot)workerson(at)gmail(dot)com> wrote:
>
> I'm having a bit of a brain freeze and can't seem to come up with
> decent SQL for the following problem:
>
> I have a table "t" of the form "time_occurred TIMESTAMP, prog_data
> VARCHAR" and would like to create a query that outputs something of
> the form "first_seen, last_seen, count, prog_data".
>
> I have the current query which gets the first_seen and last_seen via
> subqueries, ala
>
> SELECT t1.time_occurred AS first_seen, t2.time_occurred AS last_seen,
> t3.count, t1.prog_data
> FROM t AS t1, t AS t2
> WHERE t1.prog_data = t2.prog_data
> AND t1.time_occurred IN (SELECT min(time_occurred) FROM t WHERE
> prog_data = t1.prog_data)
> AND t2.time_occurred IN (SELECT max(time_occurred) FROM t WHERE
> prog_data = t1.prog_data)
>
> but I can't seem to work out how to get the count of all the records
> that have. I figure that this is probably a relatively common idiom
> ... can anyone suggest ways to go about doing this. Also, the
> performance of this is pretty horrible, but I figure that creating a
> column on t.prog_data should speed things up noticably, right?
>
> Thanks!

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Frank Bax 2006-06-21 15:21:36 Re: Displaying first, last, count columns
Previous Message virgi 2006-06-21 15:06:12 How to get a result in one row