Thread: UPDATE one table with values from another

UPDATE one table with values from another

From
Dan Langille
Date:
I know there is a simple solution, but I can't remember what it is.  :(

I have two similar tables.  I want to update the fields from one table to
contain the values form the other.  The two tables are:

laptop.freshports.org=# \d commit_log_ports  Table "public.commit_log_ports"   Column     |   Type   | Modifiers
---------------+----------+-----------commit_log_id | integer  | not nullport_id       | integer  | not
nullneeds_refresh| smallint | not nullport_version  | text     |port_revision | text     |
 
Indexes: commit_log_ports_pkey primary key btree (commit_log_id, port_id),        needs_refresh btree (needs_refresh)
Foreign Key constraints: $1 FOREIGN KEY (commit_log_id) REFERENCES commit_log(id) ON UPDATE CASCADE ON DELETE CASCADE,
                     $2 FOREIGN KEY (port_id) REFERENCES ports(id) ON UPDATE CASCADE ON DELETE CASCADE
 
Triggers: commit_log_ports_insert

laptop.freshports.org=# \d commit_log_ports_elements
Table "public.commit_log_ports_elements"   Column     |   Type   | Modifiers
---------------+----------+-----------commit_log_id | integer  | not nullelement_id    | integer  | not
nullneeds_refresh| smallint | not nullport_version  | text     |port_revision | text     |
 
Indexes: commit_log_ports_elements_pkey primary key btree (commit_log_id, element_id)
Foreign Key constraints: $1 FOREIGN KEY (commit_log_id) REFERENCES commit_log(id) ON UPDATE CASCADE ON DELETE CASCADE,
                     $2 FOREIGN KEY (element_id) REFERENCES element(id) ON UPDATE CASCADE ON DELETE CASCADE
 

laptop.freshports.org=#

I can obtain the values I want with this query:

SELECT CLP.* FROM commit_log_ports CLP, ports P, commit_log_ports_elements XWHERE CLP.port_id       = P.id  AND
CLP.commit_log_id= X.commit_log_id  AND X.element_id      = P.element_id;
 


I started writing the UPDATE and got as far as this before brain fatigue set in:

UPDATE commit_log_ports_elements X  SET X.needs_refresh = CLP.needs_refresh,      X.port_version  = CLP.port_version,
  X.port_revision = CLP.port_revision
 
WHERE X.commit_log_id = commit_log_ports CLP AND X.

A clue please?  Thank you.


Re: UPDATE one table with values from another

From
Josh Berkus
Date:
Dan,

> UPDATE commit_log_ports_elements X
>    SET X.needs_refresh = CLP.needs_refresh,
>        X.port_version  = CLP.port_version,
>        X.port_revision = CLP.port_revision

FROM commit_log_ports CLP
WHERE X.commit_log_id = CLP.commit_log_id

You can always ask this kind of thing on IRC .....

--
-Josh BerkusAglio Database SolutionsSan Francisco



Re: UPDATE one table with values from another

From
Stephan Szabo
Date:
On Wed, 8 Oct 2003, Josh Berkus wrote:

> > UPDATE commit_log_ports_elements X
IIRC, PostgreSQL doesn't like aliases of the
update table, so I think you'll need to spell it
out in the WHERE.

> >    SET X.needs_refresh = CLP.needs_refresh,
> >        X.port_version  = CLP.port_version,
> >        X.port_revision = CLP.port_revision
I don't think you need the X.'s here anyway, there's
only one update table.


Re: UPDATE one table with values from another

From
Dan Langille
Date:
On Wed, 8 Oct 2003, Josh Berkus wrote:

> Dan,
>
> > UPDATE commit_log_ports_elements X
> >    SET X.needs_refresh = CLP.needs_refresh,
> >        X.port_version  = CLP.port_version,
> >        X.port_revision = CLP.port_revision
>
> FROM commit_log_ports CLP
> WHERE X.commit_log_id = CLP.commit_log_id

Thanks Josh.  After a 5 hour drive to Hamilton, my brain was only capable
of doing the email.

> You can always ask this kind of thing on IRC .....

If I'd been at home, I would have.  This laptop of mine is getting pretty
old.  It took pretty close to 15 minutes for it to set a field to zero in
91,295 rows....  I need more ram and a faster laptop!

cheers