Thread: PG UPDATE question

PG UPDATE question

From
Jeff Butera
Date:
I'm new to postgres and am having an UPDATE problem when
using a join.  I've got two tables like so:

CREATE TABLE QUESTION_ANSWERS (
  QUESTIONS_ID   int4  NOT NULL,  -- question ID
  ANSWERS_ID     int4  NOT NULL,  -- answer ID
  CORRECT        boolean
);

CREATE TABLE STUDENT_ANSWERS (
  STUDENTS_ID    int4   NOT NULL,  -- student ID
  QUESTIONS_ID   int4   NOT NULL,  -- question ID
  ANSWERS_ID     int4   NOT NULL,  -- answer ID
  CORRECT        boolean
);

The table QUESTION_ANSWERS is completely populated.  The table
STUDENT_ANSWERS has all fields except CORRECT populated.  I want to
write an update that'll copy CORRECT from QUESTION_ANSWERS into
STUDENT_ANSWERS when the IDs match.  Here's what I wrote:

UPDATE STUDENT_ANSWERS SET CORRECT=QA.CORRECT
  FROM QUESTION_ANSWERS QA,STUDENT_ANSWERS SA
  WHERE SA.CORRECT=null
    AND SA.QUESTIONS_ID=QA.QUESTIONS_ID
    AND SA.ANSWERS_ID=QA.ANSWERS_ID;

It executes without an error and correctly returns the count of the
records in the join, but the CORRECT field in STUDENT_ANSWERS is
populated entirely with false regardless of what CORRECT is
QUESTION_ANSWERS.

Can anyone shed light on what I'm missing?

--
Jeff Butera, Ph.D.                               Junk e-mail is like
Department of Mathematics & Computer Science     plastic grocery bags:
High Point University                            they just seem to
jbutera@linus.highpoint.edu                      multiply at will...
http://linus.highpoint.edu/~jbutera                        Anonymous


Re: PG UPDATE question

From
Tom Lane
Date:
Jeff Butera <jbutera@linus.highpoint.edu> writes:
> UPDATE STUDENT_ANSWERS SET CORRECT=QA.CORRECT
>   FROM QUESTION_ANSWERS QA,STUDENT_ANSWERS SA
>   WHERE SA.CORRECT=null
>     AND SA.QUESTIONS_ID=QA.QUESTIONS_ID
>     AND SA.ANSWERS_ID=QA.ANSWERS_ID;

What you've got here is a three-way join between QUESTION_ANSWERS and
two instances of STUDENT_ANSWERS (the update target and the SA alias).
I doubt that's what you want.  FROM in update should only be used for
*additional* tables.  The target table has no alias and must be spelled
out:

UPDATE STUDENT_ANSWERS SET CORRECT=QA.CORRECT
  FROM QUESTION_ANSWERS QA
  WHERE STUDENT_ANSWERS.CORRECT=null
    AND STUDENT_ANSWERS.QUESTIONS_ID=QA.QUESTIONS_ID
    AND STUDENT_ANSWERS.ANSWERS_ID=QA.ANSWERS_ID;

            regards, tom lane