Hibernate Books

All times are UTC - 5 hours [ DST ]



Post new topic Reply to topic  [ 2 posts ] 
Author Message
 Post subject: SQL to UPDATE conditionally based on the MAX of a column
PostPosted: Mon Aug 28, 2017 2:43 am 
Newbie

Joined: Mon Aug 28, 2017 2:40 am
Posts: 1
I want to update column c5 (to 1) of each grouped date base on column c1,c2,c3 where c3 is maximum in same c1,c2 group.I am working with hql on oracle db

Code:
c1     |  c2 | c3 | c4 | c5 | c5 after update
2000  |   a | 01 | x  | 0  | 0
2000  |   a | 01 | y  | 0  | 0
2000  |   a | 01 | z  | 0  | 0
2000  |   a | 02 | z  | 0  | 1
2000  |   a | 02 | x  | 0  | 1
...........................
2000  |   b | 01 | x  | 0  | 0
2000  |   b | 01 | y  | 0  | 0
2000  |   b | 01 | z  | 0  | 0
2000  |   b | 02 | z  | 0  | 1
..........................
..........................
2001  |   a | 01 | x  | 0  | 0
2001  |   a | 01 | y  | 0  | 0
2001  |   a | 01 | z  | 0  | 0
2001  |   a | 02 | z  | 0  | 0
2001  |   a | 02 | x  | 0  | 0
2001  |   a | 02 | y  | 0  | 0
2001  |   a | 02 | w | 0  | 0
2001  |   a | 03 | y  | 0  | 1
2001  |   a | 03 | w  | 0  | 1
...........................
2001  |   b | 01 | x  | 0  | 0
2001  |   b | 01 | y  | 0  | 0
2001  |   b | 02 | x  | 0  | 1
2001  |   b | 02 | z  | 0  | 1


Top
 Profile  
 
 Post subject: Re: update conditionally base on maximum of a column
PostPosted: Tue Sep 05, 2017 1:45 am 
Hibernate Team
Hibernate Team

Joined: Thu Sep 11, 2014 2:50 am
Posts: 1527
Easy peasy!

As long as you also have an id in your entries table, this is the SQL query you need to run:

Code:
int updateCount = entityManager.createNativeQuery(
   "update entries set c5 = 1 " +
   "where id in " +
   "( " +
   "    select id " +
   "    from ( " +
   "        select *, MAX (c3) OVER (PARTITION BY c1, c2) as max_c3 " +
   "        from entries " +
   "    ) t " +
   "    where t.c3 = t.max_c3 " +
   ") ")
.executeUpdate();


If the database does not support Windows Functions, then the query looks like this:

Code:
int updateCount = entityManager.createNativeQuery(
   "update entries set c5 = 1 " +
   "where id in " +
   "( " +
   "    select e.id " +
   "    from entries e  " +
   "    inner join ( " +
   "        select c1, c2, max(c3) as max_c3 " +
   "        from entries " +
   "        group by c1, c2 " +
   "    ) t " +
   "    on e.c1 = t.c1 and e.c2 = t.c2 and e.c3 = t.max_c3  " +
   ") " )
.executeUpdate();


Check out this article for more details.

_________________
If you liked my answer, you are going to love my High-Performance Java Persistence book and my blog as well.


Top
 Profile  
 
Display posts from previous:  Sort by  
Post new topic Reply to topic  [ 2 posts ] 

All times are UTC - 5 hours [ DST ]


You cannot post new topics in this forum
You cannot reply to topics in this forum
You cannot edit your posts in this forum
You cannot delete your posts in this forum

Search for:
© Copyright 2014, Red Hat Inc. All rights reserved. JBoss and Hibernate are registered trademarks and servicemarks of Red Hat, Inc.