Thread: Originally created and last_mod by whom and when ?
Hello, In a web app (Pg 8.2.4 + php) I have product and other tables with fields like product_created timestamp without time zone product_created_user_id integer product_last_mod timestamp without time zone product_last_mod_user_id integer The person who last modified an item can obviously be someone else who originally created it. I can get the names and timestamps with two separate queries but how can I do a single query to get the names of both ? product_id | 1 ... product_created_user_id | 1 product_last_mod_user_id | 2 ID 1, created by X / date and time, last_mod by Y / date and time And a similar query to only one table, users ? user_id integer user_forename text ... user_created timestamp without time zone user_created_user_id integer user_last_mod timestamp without time zone user_last_mod_user_id integer ID 4, name Z, created by X / date and time, last_mod by Y / date and time Join, sub select ? I tried some but only managed to get only one name, errors, nothing at all or two rows with inner join + union ... Lotsa thanks for any help, Aarni --
Aarni Ruuhimäki wrote: > Hello, > > In a web app (Pg 8.2.4 + php) I have product and other tables with fields like > > product_created timestamp without time zone > product_created_user_id integer > product_last_mod timestamp without time zone > product_last_mod_user_id integer > > The person who last modified an item can obviously be someone else who > originally created it. > > I can get the names and timestamps with two separate queries but how can I do > a single query to get the names of both ? Alias the tables, so you can join to the user-table twice. SELECT p.*, u_cre.username as created_by, u_mod.username as modified_by FROM products p LEFT JOIN app_users u_cre ON p.product_created_user_id = u_cre.id LEFT JOIN app_users u_mod ON p.product_last_mod_user_id = u.mod.id ; -- Richard Huxton Archonet Ltd
On Wednesday 14 November 2007 13:28, Richard Huxton wrote: > Aarni Ruuhimäki wrote: > > Hello, > > > > In a web app (Pg 8.2.4 + php) I have product and other tables with fields > > like > > > > product_created timestamp without time zone > > product_created_user_id integer > > product_last_mod timestamp without time zone > > product_last_mod_user_id integer > > > > The person who last modified an item can obviously be someone else who > > originally created it. > > > > I can get the names and timestamps with two separate queries but how can > > I do a single query to get the names of both ? > > Alias the tables, so you can join to the user-table twice. > > SELECT p.*, u_cre.username as created_by, u_mod.username as modified_by > FROM > products p > LEFT JOIN > app_users u_cre ON p.product_created_user_id = u_cre.id > LEFT JOIN > app_users u_mod ON p.product_last_mod_user_id = u.mod.id > ; Charming ! Many thanks to you Richard. Aarni --