Re: Query - student, skill

From: Kevin Grittner <kgrittn(at)ymail(dot)com>
To: Jayadevan M <maymala(dot)jayadevan(at)gmail(dot)com>, "pgsql-novice(at)postgresql(dot)org" <pgsql-novice(at)postgresql(dot)org>
Subject: Re: Query - student, skill
Date: 2013-10-09 14:42:45
Message-ID: 1381329765.1064.YahooMailNeo@web162902.mail.bf1.yahoo.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-novice

Jayadevan M <maymala(dot)jayadevan(at)gmail(dot)com> wrote:

> To fetch records of students who know , say, 'Java' and 'Oracle',
> is this the best way?
>
> select s.id, s.name
>   from stud s
>   join stud_skill s_k on s.id = s_k.stud_id
>   join skill sk on sk.id = s_k.skill_id
>   where sk_name = 'Java'
> intersect
> select s.id, s.name
>   from stud s
>   join stud_skill s_k on s.id = s_k.stud_id
>   join skill sk on sk.id = s_k.skill_id
>   where sk_name = 'Oracle'
> ;

I think that in most (maybe all?) cases the set operations like
INTERSECT cause the queries on both sides to be executed and the
set operation performed on the results.  It should be faster just
to use two joins to the skill table:

select s.id, s.name
  from stud s
  join stud_skill s_k on s.id = s_k.stud_id
  join skill sk1 on sk1.id = s_k.skill_id and sk1.sk_name = 'Java'
  join skill sk2 on sk2.id = s_k.skill_id and sk2.sk_name = 'Oracle'
;

If the skill names are not unique, you might want to throw a
DISTINCT in there, too.

--
Kevin Grittner
EDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company

In response to

Responses

Browse pgsql-novice by date

  From Date Subject
Next Message Jayadevan M 2013-10-10 00:41:33 Re: Query - student, skill
Previous Message Michael Swierczek 2013-10-09 12:36:53 Re: Query - student, skill