I'm surprised in works in one interface and not the other... not sure why
that's happening. Perhaps DECPMT comes into play here?
In any case, try using a table alias in the RRN function, i.e.:
DELETE FROM HORVATAL/SHIPMENTS A
WHERE TRACK00002 > ' ' AND TRACK00002 IN
(
SELECT TRACK00002
FROM HORVATAL/SHIPMENTS B
GROUP BY TRACK00002
HAVING COUNT(RRN(B)) > 1
)
AND NOT RRN(A) IN
(
SELECT MIN(RRN(C)) AS MINID
FROM HORVATAL/SHIPMENTS C
GROUP BY TRACK00002
HAVING COUNT(RRN(C)) > 1
);
It may have a side effect of making the intent clearer as well.
If you don't mind checking out an alternative method for deleting duplicate
rows, see "Delete Duplicate Rows" article on page 5 of this link:
http://www.centerfieldtechnology.com/publications/archive/JulyAugust07.pdf
And finally, I find it surprising that you're going to make this an ongoing
process. Wouldn't it make more sense to fix the original issue and avoid
duplicate data in first place? Perhaps via a check or unique constraint?
Hth, Elvis
Celebrating 11-Years of SQL Performance Excellence on IBM i, i5/OS and
OS/400
www.centerfieldtechnology.com
-----Original Message-----
Subject: Operations Navigator and Interactive SQL Differences
Hello,
A co-working and I set up some SQL in Operations Navigator to delete
duplicate records leaving the first duplicate record intact in a file.
Works fine in Operations Navigator and Planet Java's WOW Tool. But when I
run it from the iSeries Command Line via STRSQL or RUNSQLSTM it fails to
run. I wish to put this job in the Advanced Job Scheduler to run once a day
looking for Dups. Below is the code and the generated error message. Any
help would be appreciated. We are running V5R4 on our iSeries if that
matters.
5722SS1 V5R4M0 060210 Run SQL Statements DELDUPS
Record *...+... 1 ...+... 2 ...+... 3 ...+... 4 ...+... 5 ...+... 6 ...+...
7
1 DELETE FROM HORVATAL/SHIPMENTS
2 WHERE TRACK00002 > ' ' AND TRACK00002 IN (
3 SELECT TRACK00002 FROM HORVATAL/SHIPMENTS
4 GROUP BY TRACK00002
5 HAVING COUNT(RRN(HORVATAL/SHIPMENTS)) > 1)
6 AND NOT RRN(HORVATAL/SHIPMENTS) IN(
7 SELECT MIN(RRN(HORVATAL/SHIPMENTS)) AS MINID FROM
HORVATAL/SHIPMENTS
8 GROUP BY TRACK00002
9 HAVING COUNT(RRN(HORVATAL/SHIPMENTS)) > 1)
* * * * * E N D O F S O U R C E * * * *
*
SQL5001 30 5 Position 22 Column qualifier or table SHIPMENTS
undefined.
As an Amazon Associate we earn from qualifying purchases.