Hibernate generates in for some DBMS wrong SQL in special cases. In my case, i have an Spring application that querys an table with an collection of an embeddable key with two fields and one additional boolean value (similar as in-List with tuples - which is not supported by DB2). In this case, the generated SQL returns all rows that matches the embeddable expect for the last - for this the row must match the embeddable and the boolean value.
h3. Example
*Table-Definition*
{noformat}No Name Typ 1 id int(11) 2 key_1 char(3) 3 key_2 char(3) 4 present char(1) {noformat}
*Data*
{noformat} id key_1 key_2 present 1 ZH2 HDS Y 2 ZH3 HDS Y 3 GXZ HDS N 4 KAZ TST Y{noformat}
*Query-Method (Spring Data JPA)* {{public List<TestEntity> findAllBySubInAndPresent(Collection<Sub> subs, String present);}}
*Model*
{noformat}@AllArgsConstructor @Data @Entity @Table(name = "tester") public class TestEntity {
@Id @Column(name = "id") private int id; @Embedded private Sub sub; @Column(name = "present") private String present; @RequiredArgsConstructor @AllArgsConstructor @Data @Embeddable public static class Sub { @Column(name = "key_1") private String key1; @Column(name = "key_2") private String key2; } }{noformat}
*generated wrong SQL:* {{select t1_0.id,t1_0.present,t1_0.key_1,t1_0.key_2 from tester t1_0 where (t1_0.key_1=? and t1_0.key_2=?) or (t1_0.key_1=? and t1_0.key_2=?) or (t1_0.key_1=? and t1_0.key_2=?) and t1_0.present=? }} Which returns the rows with the IDs: 1, 3 and 4.
Expected are only the rows with the IDs: 1 and 4
*This is fixed by adding parenthesis around the ORs of the Collection-Data:* {{select t1_0.id,t1_0.present,t1_0.key_1,t1_0.key_2 from tester t1_0 where ((t1_0.key_1=? and t1_0.key_2=?) or (t1_0.key_1=? and t1_0.key_2=?) or (t1_0.key_1=? and t1_0.key_2=?)) and t1_0.present=?}}
This incorrect SQL generation only occours for DBMS that do not support the {{supportsRowValueConstructorSyntaxInInList}}. For example DB2. This problem occurs in versions 5.x and 6.x.
_I've allready fixed this issue and i'll submit an PR the next hours._ |
|