× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



John,

There are several ways to identify duplicate records using SQL. The
ones I know tend to be slow, and (as is almost always the case with
SQL) do benefit of having the adequate indexes.

IF (big IF) you can determine which fields on your table make a record
unique, you can create a view with that shows only duplicate records,
the following way:

CREATE VIEW DUPRECORDS AS
WITH T1 AS(
SELECT A.*, RRN(A) AS RRNO FROM MYFILE A )

SELECT * FROM T1 A WHERE EXISTS(
      SELECT 1 FROM T1 B
WHERE A.HOSPNUM = B. HOSPNUM
AND   A.ACCOUNT = B. ACCOUNT
AND   A.IDPOSTER = B. IDPOSTER
 AND A.RRNO > B.RRNO
)
;

So, when you do a SELECT * FROM DUPRECORDS you will see only the
duplicate records in MYFILE. If you want to delete your records, just
do a DELETE FROM DUPRECORDS.

***WARNING***
There some things to be aware of, using this method:

1.- You must have a backup of your data. An error can be disastrous.
2.- You must choose carefully the fields that make your records unique.
3.- This method can be SLOW, particularly with big fields. That’s the
reason having good indexes help.
4.- Check your data before deleting it (do a SELECT)
5.- AGAIN: You must have a backup of your data.

HTH,

Luis Rodriguez
IBM Certified Systems Expert — eServer i5 iSeries


On Wed, Sep 23, 2009 at 8:27 AM, Alan Shore <AlanShore@xxxxxxxx> wrote:

Hi John
this web page may give you a start as to how to delete the records in
question using SQL
The "unfortunate" thing here is that this is a join logical, so (I believe)
you cannot delete the records in question from this join

Good luck



Alan Shore
Programmer/Analyst, Distribution
E:AShore@xxxxxxxxxxx
P:(631) 200-5019
C:(631) 880-8640
"If you're going through Hell, keep going" - Winston Churchill

midrange-l-bounces@xxxxxxxxxxxx wrote on 09/23/2009 12:28:10 AM:

I made a mistake today.  Accidentally ran a posting program three
additional times.  I normally try to automate things so  dumb things
like thisdon't happen.  But, this has not been a project developed
in the proper manner - meaning GET IT DONE!

The file is a join logical.  Common ields are 1) hospital number, 2)
account, 3) date, 4) time , and 5) id of poster.  The first four
fields are numeric and the last is alpha.

The two files are a main file with 30 characters of text and the
second file contains multiple records for additional text.

Something like 5000 records posted three extra times..

The problem will disappear in about 6 months, if nothing is done.
Just  looks bad and a lot of people will see my blunder and have to
deal with it.

Can SQL be used to identify when there are multiple records for the
same hospital and account number that have identical date, time,
andposter id?

Can SQL be used to remove three of the four multiples?

Can SQL be used to do the previous two operations, but for one
specific account - for testing?

Would it be easier if the original posting file was available?  My
assumption is yes.  and that file can be available.


This doesn't effect any totals.  Just looks really bad.


Seems this would be pretty simple in RPG, especially with the
original file available.  Just don't know if I can get the time to
devote to tis.

Is this something a) best left alone, b) best fixed with SQL, or c)
best fixed with RPG?


Easiest approach would be to back out all the records and ten post
once, I am guessing.


Wish I hadn't made the mess, in any case.

John McKee




--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing
list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-l.

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-l.


As an Amazon Associate we earn from qualifying purchases.

This thread ...

Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.