Thread: Delete with a multi-column join?

Delete with a multi-column join?

From
leon-pg@comvision.com
Date:
Howdy! I apologize in advance for the ugly query I'm about to throw
your way....

I need to delete some data from a table based on a multi-column join.
Is there a better way to write this?

delete
from tbldata
where unitID || '_' || variableID || '_' || cycleID in
    (select unitID || '_' || variableID || '_' || cycleID from
temp_data_table)

In SQL Server I would just write

delete tblData
from tblData a
    inner join temp_data_table b
        on a.unitID = b.unitID
            and a.variableID = b.variableID
            and a.cycleID = b.cycleID

Re: Delete with a multi-column join?

From
Tom Lane
Date:
leon-pg@comvision.com writes:
> Is there a better way to write this?

> delete
> from tbldata
> where unitID || '_' || variableID || '_' || cycleID in
>     (select unitID || '_' || variableID || '_' || cycleID from
> temp_data_table)

delete
from tbldata
where (unitID, variableID, cycleID) in
    (select unitID, variableID, cycleID from temp_data_table)

            regards, tom lane

Re: Delete with a multi-column join?

From
Martijn van Oosterhout
Date:
On Tue, Jan 25, 2005 at 04:16:29PM -0500, leon-pg@comvision.com wrote:
> Howdy! I apologize in advance for the ugly query I'm about to throw
> your way....
>
> I need to delete some data from a table based on a multi-column join.
> Is there a better way to write this?

Either:

delete
from tbldata
where (unitID,variableID,cycleID) in
    (select unitID, variableID, cycleID from  temp_data_table)

Or:

delete from tblData where
         tblData.unitID = temp_data_table.unitID
         and tblData.variableID = temp_data_table.variableID
         and tblData.cycleID = temp_data_table.cycleID

Hope this helps,
--
Martijn van Oosterhout   <kleptog@svana.org>   http://svana.org/kleptog/
> Patent. n. Genius is 5% inspiration and 95% perspiration. A patent is a
> tool for doing 5% of the work and then sitting around waiting for someone
> else to do the other 95% so you can sue them.

Attachment