IBM Mainframe Forum Index
 
Log In
 
IBM Mainframe Forum Index Mainframe: Search IBM Mainframe Forum: FAQ Register
 

DELETE query to have deletion of the rows count from >40


IBM Mainframe Forums -> DB2
Post new topic   Reply to topic
View previous topic :: View next topic  
Author Message
tecnokrat
Warnings : 1

Active User


Joined: 22 May 2009
Posts: 160
Location: Bangalore

PostPosted: Mon Nov 25, 2013 12:19 am
Reply with quote

Hi,
I have a table with records more than 40 for each of the particular entry.

Now my program has a logic which checks for 40 occurences only in this table and then close the cursor.

But the records are more than 40 for each of these entries the flag is not set appropriately and the Cursor is not getting closed.

This is the reason when some other records are tried to fetch and the cursor never got closed.

The below query gave the total number of records having count more than 40 for each record in the table.
Quote:

SELECT A
from table TAB1
GROUP BY A
HAVING COUNT(*) > 40


Now I need to tweak the query where it should delete only the record's entries from 41st and not the whole of the record.


Quote:

DELETE
FROM TABLE TAB1 a
WHERE a.A IN (
SELECT b.A
FROM TABLE TAB1 b
GROUP BY b.A
HAVING COUNT(*) > 40)


Please can you help.
Back to top
View user's profile Send private message
Nic Clouston

Global Moderator


Joined: 10 May 2007
Posts: 2455
Location: Hampshire, UK

PostPosted: Mon Nov 25, 2013 2:51 pm
Reply with quote

suppose the 41st, or greater, row is the latest? DB2 does not guarantee the order in which is returns rows so you could be getting back ones thaty you would perhaps want deleted. Why not read all the records, process the 40 that you need and then issue deletes for the remining using keys that you have stored in working storage?
Back to top
View user's profile Send private message
GuyC

Senior Member


Joined: 11 Aug 2009
Posts: 1281
Location: Belgium

PostPosted: Mon Nov 25, 2013 2:59 pm
Reply with quote

1) Using Olap function row_number() partition by
Code:
delete from tableX X  where rid(x) in (
select RI from (                                     
select row_number() over                             
                       (partition by ColA
                        order by ColB) as RN       
        ,rid(A) as RI                                 
         from  tableX A) B               
where rn > 40                                        )

or
2) Using fetch first n Rows only in subselect
Code:
delete from tableX X where RID(X) not in (                               
select y.ri    from                                 
           (select ColA from tableX  group by ColA) A                   
, table  (select rid(B) as RI from TableX B       
         where a.ColA = b.ColA
            order by b.colB                                 
   fetch first 40 rows only) Y                     
)
Back to top
View user's profile Send private message
View previous topic :: :: View next topic  
Post new topic   Reply to topic View Bookmarks
All times are GMT + 6 Hours
Forum Index -> DB2

 


Similar Topics
Topic Forum Replies
No new posts DELETE SPUFI DB2 1
No new posts To get the count of rows for every 1 ... DB2 3
No new posts DSNTIAUL driven delete IBM Tools 0
No new posts To find whether record count are true... DFSORT/ICETOOL 6
No new posts RC query -Time column CA Products 3
Search our Forums:

Back to Top