By using this site, you agree to our updated Privacy Policy and our Terms of Use. Manage your Cookies Settings.
440,230 Members | 2,471 Online
Bytes IT Community
+ Ask a Question
Need help? Post your question and get tips & solutions from a community of 440,230 IT Pros & Developers. It's quick & easy.

Update with join statement not working in DB2

P: n/a
------------------------
UPDATE A
SET A.ID = '?' + A.ID
FROM TABLEA A
LEFT OUTER JOIN TABLEB B ON
A.INDEX = B.INDEX
WHERE B.DUP_ID IS NULL
------------------------

seems like update with join statement not working in DB2 version 5

any idea to update duplicated 'ID' without joining table and "where....
in" statement ??

Sep 21 '06 #1
Share this Question
Share on Google+
5 Replies


P: n/a
Sphenix wrote:
------------------------
UPDATE A
SET A.ID = '?' + A.ID
FROM TABLEA A
LEFT OUTER JOIN TABLEB B ON
A.INDEX = B.INDEX
WHERE B.DUP_ID IS NULL
------------------------

seems like update with join statement not working in DB2 version 5

any idea to update duplicated 'ID' without joining table and "where....
in" statement ??
DB2 Version 5? I hope you are talking about DB2 V5R? for iSeries.
Let me clarify the intent here:
You want to prepend a '?' to all IDs for which there is NO match in B?
Is B.DUP_ID nullable?

UPDATE TABLEA A
SET A.ID = '?' || A.ID
WHERE NOT EXISTS(SELECT 1 FROM TABLEB B WHERE A.INDEX = B.INDEX)

Cheers
Serge
--
Serge Rielau
DB2 Solutions Development
IBM Toronto Lab

IOD Conference
http://www.ibm.com/software/data/ond...ness/conf2006/
Sep 21 '06 #2

P: n/a
DB2 Version 5? I hope you are talking about DB2 V5R? for iSeries.
Let me clarify the intent here:
You want to prepend a '?' to all IDs for which there is NO match in B?
Is B.DUP_ID nullable?

UPDATE TABLEA A
SET A.ID = '?' || A.ID
WHERE NOT EXISTS(SELECT 1 FROM TABLEB B WHERE A.INDEX = B.INDEX)

Cheers
Serge
--
Serge Rielau
DB2 Solutions Development
IBM Toronto Lab

IOD Conference
http://www.ibm.com/software/data/ond...ness/conf2006/
above statement can be use, however my friend said not recommended to
update a table where have another select statement

e.g.
UPDATE TABLEA A
SET A.ID = '?' || A.ID
WHERE NOT EXISTS(SELECT 1 FROM TABLEB B WHERE A.INDEX = B.INDEX)
or
UPDATE TABLEA A
SET A.ID = '?' || A.ID
WHERE A.ID NOT IN (SELECT B.ID FROM TABLEB B WHERE A.INDEX =
B.INDEX)

-----------------
TABLEA
------------------
INDEX ID
1 A
2 B
3 B --Duplicated Record
4 D
5 E
6 E --Duplicated Record
7 G
8 H
9 J
10 J --Duplicated Record
------------------

so my task is update duplicated record of ID with '?' on the biggest
number of INDEX
so my result should be INDEX 3, 6 & 10 with '?' infront the ID

Sep 22 '06 #3

P: n/a
Sphenix wrote:
>DB2 Version 5? I hope you are talking about DB2 V5R? for iSeries.
Let me clarify the intent here:
You want to prepend a '?' to all IDs for which there is NO match in B?
Is B.DUP_ID nullable?

UPDATE TABLEA A
SET A.ID = '?' || A.ID
WHERE NOT EXISTS(SELECT 1 FROM TABLEB B WHERE A.INDEX = B.INDEX)

Cheers
Serge
--
Serge Rielau
DB2 Solutions Development
IBM Toronto Lab

IOD Conference
http://www.ibm.com/software/data/ond...ness/conf2006/

above statement can be use, however my friend said not recommended to
update a table where have another select statement

e.g.
UPDATE TABLEA A
SET A.ID = '?' || A.ID
WHERE NOT EXISTS(SELECT 1 FROM TABLEB B WHERE A.INDEX = B.INDEX)
or
UPDATE TABLEA A
SET A.ID = '?' || A.ID
WHERE A.ID NOT IN (SELECT B.ID FROM TABLEB B WHERE A.INDEX =
B.INDEX)

-----------------
TABLEA
------------------
INDEX ID
1 A
2 B
3 B --Duplicated Record
4 D
5 E
6 E --Duplicated Record
7 G
8 H
9 J
10 J --Duplicated Record
------------------

so my task is update duplicated record of ID with '?' on the biggest
number of INDEX
so my result should be INDEX 3, 6 & 10 with '?' infront the ID
That is definitely NOT what that SQL Server query you posted is doing.
Aside where is TABLEB? You only posted half the data!
Here is what does the job given the TABLEA you posted:
CREATE TABLE TABLEA(INDEX INT, ID VARCHAR(10));
INSERT INTO TABLEA VALUES
(1 , 'A'),
(2 , 'B'),
(3 , 'B'),
(4 , 'D'),
(5 , 'E'),
(6 , 'E'),
(7 , 'G'),
(8 , 'H'),
(9 , 'J'),
(10, 'J');

UPDATE TABLEA A
SET ID = '?' || ID
WHERE EXISTS(SELECT 1 FROM TABLEA B
WHERE A.ID = B.ID
AND A.INDEX B.INDEX);

SELECT * FROM TABLEA;
INDEX ID
----------- ----------
1 A
2 B
3 ?B
4 D
5 E
6 ?E
7 G
8 H
9 J
10 ?J

10 record(s) selected.

In DB2 V8.2 for LUW (I still don't know which platform you are using)
you can write this, which is much faster:
UPDATE
(SELECT ID,
ROWNUMBER() OVER(PARTITION BY ID ORDER BY INDEX) AS rn
FROM TABLEA) AS U
SET ID = '?' || ID
WHERE rn 1;

Cheers
Serge

PS: I never ask my friends for SQL advise ;-)
--
Serge Rielau
DB2 Solutions Development
IBM Toronto Lab

IOD Conference
http://www.ibm.com/software/data/ond...ness/conf2006/
Sep 22 '06 #4

P: n/a
UPDATE
(SELECT ID,
ROWNUMBER() OVER(PARTITION BY ID ORDER BY INDEX) AS rn
FROM TABLEA) AS U
SET ID = '?' || ID
WHERE rn 1;
I think i'm using "Version 5 Release 3 Modification Level 0"
btw the code above is not supported.... :(

Sep 22 '06 #5

P: n/a
Sphenix wrote:
>UPDATE
(SELECT ID,
ROWNUMBER() OVER(PARTITION BY ID ORDER BY INDEX) AS rn
FROM TABLEA) AS U
SET ID = '?' || ID
WHERE rn 1;

I think i'm using "Version 5 Release 3 Modification Level 0"
btw the code above is not supported.... :(
Correct, DB2 V5R3 for iSeries doesn't have OLAP.
But the EXISTS query will work.

Cheers
Serge
--
Serge Rielau
DB2 Solutions Development
IBM Toronto Lab

IOD Conference
http://www.ibm.com/software/data/ond...ness/conf2006/
Sep 22 '06 #6

This discussion thread is closed

Replies have been disabled for this discussion.