Thread: slow subselects

slow subselects

From
"Marko Niinimaki"
Date:
Hello,

I'm having a surprising performance problem with the following simple
'highscore report'

select studentid, (select max(score) from
studentprofile prof where prof.studentid = students.studentid) from students;

I have indexes on students(studentid) and studentprofile(studentid).

Row counts: about 160 000 in each students and studentprofile.
Postgres version:
postgresql-8.1.8-1.fc5
postgresql-server-8.1.8-1.fc5

This is a dual-processor 3Ghz 64bit box with 2 GB mem.

Running the query takes 99% CPU and 1% mem.

I have the same data in MSSQL and there the query takes less than a
minute. With postgres it seems to take several hours.

Is there a way of making this faster?

Marko

Re: slow subselects

From
ismo.tuononen@solenovo.fi
Date:
try:

select studentid,max(score) from studentprofile group by studentid;

or if you want only those which exists in students

select s.studentid,max(p.score)
from studentprofile p,students s
where s.studentid=p.studentid
group by s.studentid;

if it takes longer than 1-2 seconds something is seriously wrong

Ismo

On Tue, 20 Feb 2007, Marko Niinimaki wrote:

> Hello,
>
> I'm having a surprising performance problem with the following simple
> 'highscore report'
>
> select studentid, (select max(score) from
> studentprofile prof where prof.studentid = students.studentid) from students;
>
> I have indexes on students(studentid) and studentprofile(studentid).
>
> Row counts: about 160 000 in each students and studentprofile.
> Postgres version:
> postgresql-8.1.8-1.fc5
> postgresql-server-8.1.8-1.fc5
>
> This is a dual-processor 3Ghz 64bit box with 2 GB mem.
>
> Running the query takes 99% CPU and 1% mem.
>
> I have the same data in MSSQL and there the query takes less than a
> minute. With postgres it seems to take several hours.
>
> Is there a way of making this faster?
>
> Marko
>
> ---------------------------(end of broadcast)---------------------------
> TIP 9: In versions below 8.0, the planner will ignore your desire to
>       choose an index scan if your joining column's datatypes do not
>       match
>
>

Re: slow subselects

From
Tom Lane
Date:
"Marko Niinimaki" <manzikki@gmail.com> writes:
> I'm having a surprising performance problem with the following simple
> 'highscore report'

> select studentid, (select max(score) from
> studentprofile prof where prof.studentid = students.studentid) from students;

> I have indexes on students(studentid) and studentprofile(studentid).

The optimal index for this would be on studentprofile(studentid,score).
A quick test says that PG 8.1 knows what to do with such an index ---
what does EXPLAIN show for this query?

            regards, tom lane

Re: slow subselects

From
"Marko Niinimaki"
Date:
Many thanks! Ismo's reply solved the problem, and Tom's reply solved
another one.

Marko

Ismo Tuononen wrote:
> select studentid,max(score) from studentprofile group by studentid;

On 20/02/07, Tom Lane <tgl@sss.pgh.pa.us> wrote:

> The optimal index for this would be on studentprofile(studentid,score).