Re: Delete with join -- deleting related table entries?

From: "Owen Jacobson" <ojacobson(at)osl(dot)com>
To: "Bryce Nesbitt" <bryce1(at)obviously(dot)com>, <pgsql-sql(at)postgresql(dot)org>
Subject: Re: Delete with join -- deleting related table entries?
Date: 2006-02-08 17:32:27
Message-ID: 144D12D7DD4EC04F99241498BB4EEDCC20CC56@nelson.osl.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Bryce Nesbitt wrote:

> When I delete a record from a certain table, I need to delete a
> (possibly) attached note as well. How can I do this with
> postgres? The
> tables are like this:
>
> reservation
> reservation_id
> stuff...
>
> isuse
> issue_id
> reservation_id
references reservation (reservation_id) -- ADD
> stuff..
>
> note
> issue_id
references isuse (issue_id) -- ADD (kept typo in example)
> text comments...
>
> A select that pulls out what I want to delete is:
>
> SELECT reservation_id,issue_id,note_id,eg_note.comments FROM
> eg_reservation
> LEFT JOIN eg_issue USING (reservation_id)
> LEFT JOIN eg_note USING (issue_id)
> WHERE reservation_id > condition;
>
> Can anyone help me turn this into a DELETE statement?

1. Add foreign key references between the tables to ensure that there are only notes and issues (isuses? :) for existing issues and reservations respectively. You can make those references 'ON DELETE CASCADE' so that a delete of the original reservation cascades down to related entries in the issue table, which in turn cascade down to the related entries in the note table.

2. Or...

BEGIN;
DELETE FROM note WHERE issue_id IN (SELECT issue_id FROM isuse
WHERE reservation_id = reservation_to_delete);
DELETE FROM isuse WHERE reservation_id = reservation_to_delete;
DELETE FROM reservations WHERE reservation_id = reservation_to_delete;
END;

with an appropriate value or expression substituted into reservation_to_delete. This would be the "hard way", but (as it's in a single transaction) will still protect other clients from seeing a partial delete.

Get yourself a good, non-MySQL-specific database book, which should explain how referential integrity is handled in databases.

-Owen

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Bryce Nesbitt 2006-02-08 17:33:22 Re: Delete with join -- deleting related table entries?
Previous Message BigSmoke 2006-02-08 17:27:47 Re: (NONE)