Обсуждение: BUG #3308: Nested outer join gives wrong results

Поиск
Список
Период
Сортировка

BUG #3308: Nested outer join gives wrong results

От
"George Sakkis"
Дата:
The following bug has been logged online:

Bug reference:      3308
Logged by:          George Sakkis
Email address:      george.sakkis@gmail.com
PostgreSQL version: 8.2.3
Operating system:   Linux
Description:        Nested outer join gives wrong results
Details:

I have the following two subqueries, both returning a single column q_id;
also the result set of A is a strict superset of B:

Query A
-------
SELECT query.id as q_id
FROM ranker, run, query
WHERE ranker.id = 72 AND
      run.id = ranker.run_id AND
      query.set_id = run.set_id

(966 rows)

Query B
-------
SELECT serp_result.q_id
FROM serp_result LEFT OUTER JOIN editor_rating using (q_id,norm_url)
WHERE serp_result.ranker_id = 72 AND
      serp_result.rank <= 1
      AND editor_rating.grade is null

(251 rows)


Now, the left outer join of A and B should be equal to A in this case since
A is a superset of B. If I save A in a temp table and use this for the join,
that's indeed the result:

SELECT query.id as q_id INTO TEMP t1
FROM ranker, run, query
WHERE ranker.id = 72 AND
      run.id = ranker.run_id AND
      query.set_id = run.set_id

SELECT *
FROM t1
LEFT JOIN (
  SELECT serp_result.q_id
  FROM serp_result LEFT OUTER JOIN editor_rating using (q_id,norm_url)
  WHERE serp_result.ranker_id = 72 AND serp_result.rank <= 1 AND
editor_rating.grade is null
) AS t2 USING (q_id)
;

(966 rows)

Likewise if I save B into a temp table and join with A:

SELECT serp_result.q_id into TEMP t2
FROM serp_result LEFT OUTER JOIN editor_rating using (q_id,norm_url)
WHERE serp_result.ranker_id = 72 AND serp_result.rank <= 1 AND
editor_rating.grade is null

SELECT *
FROM (
  SELECT query.id as q_id
  FROM ranker, run, query
  WHERE ranker.id = 72 AND
        run.id = ranker.run_id AND
        query.set_id = run.set_id
) AS t1
LEFT JOIN t2 USING (q_id)

(966 rows)

If I don't use temp tables though, the result is equal to B instead:

SELECT *
FROM (
  SELECT query.id as q_id
  FROM ranker, run, query
  WHERE ranker.id = 72 AND
        run.id = ranker.run_id AND
        query.set_id = run.set_id
) AS t1
LEFT JOIN (
  SELECT serp_result.q_id
  FROM serp_result LEFT OUTER JOIN editor_rating using (q_id,norm_url)
  WHERE serp_result.ranker_id = 72 AND
        serp_result.rank <= 1
        AND editor_rating.grade is null
) AS t2 USING (q_id)
;

(251 rows)

What gives ?

Re: BUG #3308: Nested outer join gives wrong results

От
Tom Lane
Дата:
"George Sakkis" <george.sakkis@gmail.com> writes:
> SELECT *
> FROM (
>   SELECT query.id as q_id
>   FROM ranker, run, query
>   WHERE ranker.id = 72 AND
>         run.id = ranker.run_id AND
>         query.set_id = run.set_id
> ) AS t1
> LEFT JOIN (
>   SELECT serp_result.q_id
>   FROM serp_result LEFT OUTER JOIN editor_rating using (q_id,norm_url)
>   WHERE serp_result.ranker_id = 72 AND
>         serp_result.rank <= 1
>         AND editor_rating.grade is null
> ) AS t2 USING (q_id)

This query looks like it's probably affected by the same bug reported a
couple days ago:
http://archives.postgresql.org/pgsql-bugs/2007-05/msg00187.php
and patched here:
http://archives.postgresql.org/pgsql-committers/2007-05/msg00305.php

The "WHERE editor_rating.grade is null" bit prevents the two outer joins
from being re-ordered, but released 8.2.x versions fail to notice that.

            regards, tom lane