Return-Path: Delivered-To: apmail-db-derby-user-archive@www.apache.org Received: (qmail 35781 invoked from network); 3 Mar 2005 16:16:28 -0000 Received: from hermes.apache.org (HELO mail.apache.org) (209.237.227.199) by minotaur-2.apache.org with SMTP; 3 Mar 2005 16:16:28 -0000 Received: (qmail 79283 invoked by uid 500); 3 Mar 2005 16:16:27 -0000 Delivered-To: apmail-db-derby-user-archive@db.apache.org Received: (qmail 79263 invoked by uid 500); 3 Mar 2005 16:16:26 -0000 Mailing-List: contact derby-user-help@db.apache.org; run by ezmlm Precedence: bulk list-help: list-unsubscribe: List-Post: List-Id: Reply-To: "Derby Discussion" Delivered-To: mailing list derby-user@db.apache.org Received: (qmail 79247 invoked by uid 99); 3 Mar 2005 16:16:26 -0000 X-ASF-Spam-Status: No, hits=0.0 required=10.0 tests= X-Spam-Check-By: apache.org Received-SPF: neutral (hermes.apache.org: local policy) Received: from outmx010.isp.belgacom.be (HELO outmx010.isp.belgacom.be) (195.238.3.233) by apache.org (qpsmtpd/0.28) with ESMTP; Thu, 03 Mar 2005 08:16:26 -0800 Received: from outmx010.isp.belgacom.be (localhost [127.0.0.1]) by outmx010.isp.belgacom.be (8.12.11/8.12.11/Skynet-OUT-2.22) with ESMTP id j23GGJxk014143 for ; Thu, 3 Mar 2005 17:16:19 +0100 (envelope-from ) Received: from [192.168.2.163] (59-86.242.81.adsl.skynet.be [81.242.86.59]) by outmx010.isp.belgacom.be (8.12.11/8.12.11/Skynet-OUT-2.22) with ESMTP id j23GG93e014062 for ; Thu, 3 Mar 2005 17:16:09 +0100 (envelope-from ) Message-ID: <422738D7.9090806@immedia.be> Date: Thu, 03 Mar 2005 17:18:31 +0100 From: Benoit Hambucken Organization: IMmedia User-Agent: Mozilla Thunderbird 1.0 (X11/20041206) X-Accept-Language: en-us, en MIME-Version: 1.0 To: Derby Discussion Subject: Re: using a join in UPDATE or DELETE command References: <20050303082234.03C702C07E@bces-1600.de> In-Reply-To: <20050303082234.03C702C07E@bces-1600.de> Content-Type: text/plain; charset=ISO-8859-1; format=flowed Content-Transfer-Encoding: 7bit X-Virus-Checked: Checked X-Spam-Rating: minotaur-2.apache.org 1.6.2 0/1000/N Maybe: update keys set ky='xxx' where person in (select person from badies where age<25); delete from keys where person in (select person from badies where age<25); Benoit Hambucken derby@os10000.net wrote: > Hello, > > I have asked the same question in the IBM Cloudscape forum, but with a > different wording. Perhaps one of you can provide a definitive answer. > > I wish to do the following > > create table keys ( person varchar(10), ky varchar(10) ); > insert into keys values ( 'alice', '9876' ); > insert into keys values ( 'bob', '54321' ); > insert into keys values ( 'charlie', '121212' ); > insert into keys values ( 'douglas', '343434' ); > > create table badies ( person varchar(10), age int ); > insert into badies values ( 'charlie', 20 ); > insert into badies values ( 'douglas', 30 ); > > update keys set ky='xxx' where person=badies.person and badies.age<25; > > ERROR 42X04: Column 'BADIES.PERSON' is not in any table in the FROM list > or it appears within a join specification and is outside the scope of > the join specification or it appears in a HAVING clause and is not in > the GROUP BY list. If this is a CREATE or ALTER TABLE statement then > 'BADIES.PERSON' is not a column in the target table. > ERROR 42X04: Column 'BADIES.PERSON' is not in any table in the FROM list > or it appears within a join specification and is outside the scope of > the join specification or it appears in a HAVING clause and is not in > the GROUP BY list. If this is a CREATE or ALTER TABLE statement then > 'BADIES.PERSON' is not a column in the target table. > delete from keys where person=badies.person and badies.age>=25; > > Do you have any suggestions on how I should construct the update and > delete commands to achieve what I aim for? > > I am currently using a very tedious method with a temporary table, into > which I insert carefully crafted fragments that do not include the data > I would simply delete from an existing table. This is possible, since > the INSERT command does support joins in its select clause. > > Thanks so much, > > Oliver Seidel > > > > >