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

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

Bryce Nesbitt wrote:

> Owen Jacobson wrote:
>
> > 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;
> > COMMIT;
> >
> > 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.
>
> Yup, that's exactly how I delete reservations one a time. But here I
> need to select a few thousand reservations, and I don't think
> this will
> work:
> BEGIN;
> DELETE FROM note WHERE issue_id IN (SELECT issue_id FROM isuse
> WHERE reservation_id IN
> (select reservation_id from reservations where date > magic);
> DELETE FROM isuse WHERE reservation_id IN
> (select reservation_id from reservations where date > magic)
> DELETE FROM reservations WHERE reservation_id IN
> (select reservation_id from reservations where date > magic)
> COMMIT;
>
> I suppose I can do the subselect as a perl wrapper, but I was thinking
> that maybe SQL could do it all for me....

Further thinking produced the following functional example.

CREATE TABLE reservation (
reservation_id INTEGER NOT NULL,
date DATE NOT NULL
);

CREATE TABLE issue (
issue_id INTEGER NOT NULL,
reservation_id INTEGER NOT NULL
);

CREATE TABLE note (
issue_id INTEGER NOT NULL
);

INSERT INTO reservation VALUES (1, '2006-01-01');
INSERT INTO reservation VALUES (2, '2006-01-15');
INSERT INTO reservation VALUES (3, '2006-02-01');

INSERT INTO issue VALUES (1, 1);
INSERT INTO issue VALUES (2, 1);
INSERT INTO issue VALUES (3, 2);
INSERT INTO issue VALUES (4, 2);
INSERT INTO issue VALUES (5, 3);
INSERT INTO issue VALUES (6, 3);

INSERT INTO note VALUES (1);
INSERT INTO note VALUES (2);
INSERT INTO note VALUES (3);
INSERT INTO note VALUES (4);
INSERT INTO note VALUES (5);
INSERT INTO note VALUES (6);

-- PostgreSQL 8.0 and prior
BEGIN;
DELETE FROM note
WHERE note.issue_id = issue.issue_id
AND issue.reservation_id = reservation.reservation_id
AND reservation.date > '2006-01-16';
DELETE FROM issue
WHERE issue.reservation_id = reservation.reservation_id
AND reservation.date > '2006-01-16';
DELETE FROM reservation WHERE date > '2006-01-16';
COMMIT;

-- PostgreSQL 8.1 and later
BEGIN;
DELETE FROM note USING issue, reservation
WHERE note.issue_id = issue.issue_id
AND issue.reservation_id = reservation.reservation_id
AND reservation.date > '2006-01-16';
DELETE FROM issue USING reservation
WHERE issue.reservation_id = reservation.reservation_id
AND reservation.date > '2006-01-16';
DELETE FROM reservation WHERE date > '2006-01-16';
COMMIT;

The version using subselects works fine, too.

-Owen

Browse pgsql-sql by date

  From Date Subject
Next Message Bryce Nesbitt 2006-02-08 18:11:17 Re: Delete with join -- deleting related table entries?
Previous Message Markus Schaber 2006-02-08 17:55:14 Re: Delete with join -- deleting related table entries?