Re: Calculating with sql

From: Masaru Sugawara <rk73(at)sea(dot)plala(dot)or(dot)jp>
To: catweazel(at)catweazel(dot)org
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Calculating with sql
Date: 2002-06-27 16:50:49
Message-ID: 20020628015018.3840.RK73@sea.plala.or.jp
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On Wed, 26 Jun 2002 22:18:07 +0200
Dennis Kaarsemaker <fake_adress(at)use-reply(dot)to> wrote:

> From a copy of the CDDB-database i want to select the artist & album that
> has on average the longest tracks.
>
> But in the tracks table there is no such field as length, so i have to
> calculate it. But when i try to do so it just gives me errors.
>
> This is the erroneous query i have made so far
>
> select albums.ARTIST, albums.TITLE from tracks,albums
> where tracks.DISCID = albums.DISCID
> group by tracks.DISCID
> having(albums.LENGTH/count(tracks.TRACK)) =
> (
> select max(albums.LENGTH/count(tracks.TRACK)) from tracks,albums
> where tracks.DISCID = albums.DISCID
> group by tracks.DISCID
> );
>
> What is the correct way of selecting the album?

As for this query, some columns, AERIST, TITLE, and LENGTH, are lacking
at the GROUP BY clauses. Probably, I would think a nearly correct one is
something like the following.

SELECT
a1.ARTIST, a1.TITLE
FROM
(SELECT a0.DISCID, a0.ARTIST, a0.TITLE
FROM tracks AS t0, albums AS a0
WHERE t0.DISCID = a0.DISCID
GROUP BY a0.DISCID, a0.ARTIST, a0.TITLE , a0.LENGTH
HAVING a0.LENGTH /COUNT(t0.TRACK)
= (SELECT max(mx.average)
FROM (SELECT albums.DISCID,
albums.LENGTH /COUNT(tracks.TRACK)
AS average
FROM tracks, albums
WHERE tracks.DISCID = albums.DISCID
GROUP BY albums.DISCID, albums.LENGTH
) AS mx
)
) AS a1

Regards,
Masaru Sugawara

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Stephan Szabo 2002-06-27 17:11:00 Re: Slow SELECT -> Growing Database
Previous Message Marcos Garcia 2002-06-27 15:24:04 Re: Slow SELECT -> Growing Database