From b67149821ed906c8a46c1a6f2a79759589ef7bda Mon Sep 17 00:00:00 2001 From: Radovan Radic Date: Wed, 13 Nov 2024 10:47:20 +0100 Subject: [PATCH] Oracle duality Json View optimization in property comparison and sort (#3222) * Oracle duality Json View optimization in property comparison and sort * Added more tests * Remove unused import --- .../jsonview/OracleJdbcJsonViewSpec.groovy | 49 +++++++++++++++++-- .../data/jdbc/oraclexe/jsonview/Student.java | 18 +++++-- .../jdbc/oraclexe/jsonview/StudentView.java | 10 ++++ .../jsonview/StudentViewRepository.java | 10 ++++ .../V1__Create_Schema.sql | 3 +- .../sql/AbstractSqlLikeQueryBuilder2.java | 19 ++++--- .../data/processor/sql/JsonViewSpec.groovy | 30 ++++++------ 7 files changed, 108 insertions(+), 31 deletions(-) diff --git a/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/OracleJdbcJsonViewSpec.groovy b/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/OracleJdbcJsonViewSpec.groovy index 2e06b4c2998..8ed8d3633bb 100644 --- a/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/OracleJdbcJsonViewSpec.groovy +++ b/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/OracleJdbcJsonViewSpec.groovy @@ -7,6 +7,7 @@ import io.micronaut.test.extensions.spock.annotation.MicronautTest import jakarta.inject.Inject import spock.lang.Specification +import java.time.LocalDate import java.time.LocalDateTime import java.time.LocalTime @@ -44,9 +45,10 @@ class OracleJdbcJsonViewSpec extends Specification { Address address2 = addressRepository.save(new Address("New Street", "City1")) def startDateTime = LocalDateTime.now() - Student denis = studentRepository.save(new Student("Denis", 8.5, startDateTime.minusDays(1), address1)) - Student josh = studentRepository.save(new Student("Josh", 9.1, startDateTime, address1)) - Student fred = studentRepository.save(new Student("Fred", 7.6, startDateTime.plusDays(2), address2)) + def birthDate = LocalDate.now().minusYears(20) + Student denis = studentRepository.save(new Student("Denis", birthDate, 8.5, startDateTime.minusDays(1), address1)) + Student josh = studentRepository.save(new Student("Josh", birthDate.minusMonths(3), 9.1, startDateTime, address1)) + Student fred = studentRepository.save(new Student("Fred", birthDate.plusMonths(1), 7.6, startDateTime.plusDays(2), address2)) Class math = classRepository.save(new Class("Math", "A101", LocalTime.of(10, 00), teacherAnna)) Class english = classRepository.save(new Class("English", "A102", LocalTime.of(11, 00), teacherJeff)) @@ -104,6 +106,13 @@ class OracleJdbcJsonViewSpec extends Specification { allSorted[0].name == "Denis" allSorted[1].name == "Fred" allSorted[2].name == "Josh" + when: + allSorted = studentViewRepository.findAll(Sort.of(Sort.Order.asc("startDateTime"))) + then: + allSorted.size() == 3 + allSorted[0].name == "Denis" + allSorted[1].name == "Josh" + allSorted[2].name == "Fred" when: def allPages = studentViewRepository.findAll(Pageable.from(0, 2, Sort.of(Sort.Order.desc("name")))) @@ -164,6 +173,34 @@ class OracleJdbcJsonViewSpec extends Specification { def optUnexpectedStudent = studentViewRepository.findByName(randomName) then:"Expected not found" !optUnexpectedStudent.present + + when: + denisStudentView = studentViewRepository.findByName("Denis").orElse(null) + denisStudentView.setActive(false) + studentViewRepository.update(denisStudentView) + allSorted = studentViewRepository.findAllOrderByActive() + then: + allSorted.size() == 3 + allSorted[0].name == "Denis" + when: + def inActives = studentViewRepository.findAllByActive(false) + def actives = studentViewRepository.findAllByActive(true) + then: + inActives.size() == 1 + inActives[0].name == "Denis" + actives.size() == 2 + + when: + def birthDate = studentViewRepository.findBirthDateById(denisStudentView.id) + then: + birthDate == denisStudentView.birthDate + when: + allSorted = studentViewRepository.findAllOrderByBirthDate() + then: + allSorted.size() == 3 + allSorted[0].name == "Josh_" + allSorted[1].name == "Denis" + allSorted[2].name == "Fred_" } def "find and update partial"() { @@ -206,11 +243,13 @@ class OracleJdbcJsonViewSpec extends Specification { when:"Test inserting into the view" def ivoneStudentView = new StudentView() def ivoneStudentName = "Ivone" - ivoneStudentView.setName(ivoneStudentName) + ivoneStudentView.name = ivoneStudentName + ivoneStudentView.birthDate = LocalDate.now().minusYears(20) def peterStudentView = new StudentView() def peterStudentName = "Peter" - peterStudentView.setName(peterStudentName) + peterStudentView.name = peterStudentName + peterStudentView.birthDate = LocalDate.now().minusYears(20).minusDays(10) def newStudentScheduleView = new StudentScheduleView() diff --git a/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/Student.java b/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/Student.java index 636c3fd0bfa..b7708cd3815 100644 --- a/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/Student.java +++ b/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/Student.java @@ -6,6 +6,7 @@ import io.micronaut.data.annotation.Relation; import io.micronaut.data.annotation.sql.JoinTable; +import java.time.LocalDate; import java.time.LocalDateTime; import java.util.Collections; import java.util.List; @@ -16,6 +17,7 @@ public class Student { @GeneratedValue(GeneratedValue.Type.IDENTITY) private Long id; private String name; + private LocalDate birthDate; private Double averageGrade; private LocalDateTime startDateTime; @@ -29,16 +31,18 @@ public class Student { @Relation(Relation.Kind.MANY_TO_ONE) private Address address; - public Student(String name, Double averageGrade, LocalDateTime startDateTime, Address address) { - this(null, name, averageGrade, startDateTime, true, address, Collections.emptyList()); + public Student(String name, LocalDate birthDate, Double averageGrade, LocalDateTime startDateTime, Address address) { + this(null, name, birthDate, averageGrade, startDateTime, true, address, Collections.emptyList()); } - public Student(Long id, String name, Double averageGrade, LocalDateTime startDateTime, boolean active, Address address, List classes) { + public Student(Long id, String name, LocalDate birthDate, Double averageGrade, LocalDateTime startDateTime, boolean active, + Address address, List classes) { this.id = id; this.name = name; this.averageGrade = averageGrade; this.startDateTime = startDateTime; this.active = active; + this.birthDate = birthDate; this.address = address; this.classes = classes; } @@ -55,6 +59,14 @@ public String getName() { return name; } + public LocalDate getBirthDate() { + return birthDate; + } + + public void setBirthDate(LocalDate birthDate) { + this.birthDate = birthDate; + } + public Double getAverageGrade() { return averageGrade; } diff --git a/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/StudentView.java b/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/StudentView.java index 9a633ee9d48..de0cd10383e 100644 --- a/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/StudentView.java +++ b/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/StudentView.java @@ -7,6 +7,7 @@ import io.micronaut.data.annotation.Relation; import io.micronaut.data.tck.entities.Metadata; +import java.time.LocalDate; import java.time.LocalDateTime; import java.util.List; @@ -17,6 +18,7 @@ public class StudentView { private Long id; private String name; + private LocalDate birthDate; private Double averageGrade; @@ -49,6 +51,14 @@ public void setName(String name) { this.name = name; } + public LocalDate getBirthDate() { + return birthDate; + } + + public void setBirthDate(LocalDate birthDate) { + this.birthDate = birthDate; + } + public Double getAverageGrade() { return averageGrade; } diff --git a/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/StudentViewRepository.java b/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/StudentViewRepository.java index 330ecf03da8..c3fd3a55aaf 100644 --- a/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/StudentViewRepository.java +++ b/data-jdbc/src/test/groovy/io/micronaut/data/jdbc/oraclexe/jsonview/StudentViewRepository.java @@ -8,7 +8,9 @@ import io.micronaut.data.model.query.builder.sql.Dialect; import io.micronaut.data.repository.PageableRepository; +import java.time.LocalDate; import java.time.LocalDateTime; +import java.util.List; import java.util.Optional; @JdbcRepository(dialect = Dialect.ORACLE) @@ -34,5 +36,13 @@ public interface StudentViewRepository extends PageableRepository findAllByActive(boolean active); + + List findAllOrderByActive(); + String findAddressStreetById(Long id); + + LocalDate findBirthDateById(Long id); + + List findAllOrderByBirthDate(); } diff --git a/data-jdbc/src/test/resources/oracle-jsonview-migrations/V1__Create_Schema.sql b/data-jdbc/src/test/resources/oracle-jsonview-migrations/V1__Create_Schema.sql index 7de74333625..7b2dbc22891 100644 --- a/data-jdbc/src/test/resources/oracle-jsonview-migrations/V1__Create_Schema.sql +++ b/data-jdbc/src/test/resources/oracle-jsonview-migrations/V1__Create_Schema.sql @@ -1,6 +1,6 @@ CREATE TABLE "TBL_TEACHER" ("ID" NUMBER(19) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL PRIMARY KEY,"NAME" VARCHAR(255) NOT NULL); CREATE TABLE "TBL_ADDRESS" ("ID" NUMBER(19) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL PRIMARY KEY,"STREET" VARCHAR(255) NOT NULL, "CITY" VARCHAR(255) NOT NULL); -CREATE TABLE "TBL_STUDENT" ("ID" NUMBER(19) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL PRIMARY KEY,"NAME" VARCHAR(255) NOT NULL, AVERAGE_GRADE BINARY_DOUBLE, +CREATE TABLE "TBL_STUDENT" ("ID" NUMBER(19) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL PRIMARY KEY,"NAME" VARCHAR(255) NOT NULL, "BIRTH_DATE" DATE NOT NULL, AVERAGE_GRADE BINARY_DOUBLE, START_DATE_TIME TIMESTAMP(6), ACTIVE NUMBER(1) DEFAULT 1, ADDRESS_ID NUMBER(19) NOT NULL); CREATE TABLE "TBL_CLASS" ("ID" NUMBER(19) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL PRIMARY KEY,"NAME" VARCHAR(255) NOT NULL,"ROOM" VARCHAR(255) NOT NULL,"TIME" TIMESTAMP NOT NULL,"TEACHER_ID" NUMBER(19) NOT NULL); CREATE TABLE "TBL_STUDENT_CLASSES" ("ID" NUMBER(19) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL PRIMARY KEY, "STUDENT_ID" NUMBER(19) NOT NULL,"CLASS_ID" NUMBER(19) NOT NULL); @@ -24,6 +24,7 @@ ALTER TABLE "TBL_STUDENT" CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW STUDENT_VIEW AS SELECT JSON{'_id': TBL_STUDENT.id, 'name': TBL_STUDENT.name WITH UPDATE, + 'birthDate': TBL_STUDENT.birth_date WITH UPDATE, 'averageGrade': TBL_STUDENT.AVERAGE_GRADE WITH UPDATE, 'startDateTime': TBL_STUDENT.START_DATE_TIME, 'active': TBL_STUDENT.ACTIVE, diff --git a/data-model/src/main/java/io/micronaut/data/model/query/builder/sql/AbstractSqlLikeQueryBuilder2.java b/data-model/src/main/java/io/micronaut/data/model/query/builder/sql/AbstractSqlLikeQueryBuilder2.java index 41f7eba6e1e..dc31fc4ca13 100644 --- a/data-model/src/main/java/io/micronaut/data/model/query/builder/sql/AbstractSqlLikeQueryBuilder2.java +++ b/data-model/src/main/java/io/micronaut/data/model/query/builder/sql/AbstractSqlLikeQueryBuilder2.java @@ -660,7 +660,11 @@ protected void appendOrder(AnnotationMetadata annotationMetadata, List or if (computePropertyPaths() && jsonEntityColumn == null) { buff.append(propertyPath.getColumnName()).append(SPACE).append(direction); } else { - buff.append(propertyPath.getPath()).append(SPACE).append(direction); + buff.append(propertyPath.getPath()); + if (jsonEntityColumn != null) { + appendJsonProjection(buff, propertyPath.getProperty().getDataType()); + } + buff.append(SPACE).append(direction); } if (i.hasNext()) { buff.append(","); @@ -1084,6 +1088,9 @@ public String buildPropertyByName(@NonNull String propertyName, if (!computePropertyPaths() || jsonEntityColumn != null) { buff.append(path.getProperty().getName()); + if (jsonEntityColumn != null) { + appendJsonProjection(buff, path.getProperty().getDataType()); + } } else { buff.append(getColumnName(path.getProperty())); } @@ -1282,8 +1289,6 @@ protected final void appendPropertyRef(AnnotationMetadata annotationMetadata, } else { query.append(propertyPath.getPath()); } - } - if (jsonEntityColumn != null && isProjection) { DataType dataType = propertyPath.getProperty().getDataType(); appendJsonProjection(query, dataType); } @@ -1300,11 +1305,11 @@ protected final void appendPropertyRef(AnnotationMetadata annotationMetadata, * @param dataType the property data type */ private void appendJsonProjection(StringBuilder sb, DataType dataType) { - if (dataType == DataType.STRING) { - sb.append(".string()"); - } else if (dataType.isNumeric() || dataType == DataType.BOOLEAN) { + if (dataType.isNumeric() || dataType == DataType.BOOLEAN) { // Boolean is represented as number in Oracle (which only supports json view) - sb.append(".number()"); + sb.append(".numberOnly()"); + } else if (dataType == DataType.STRING) { + sb.append(".stringOnly()"); } else if (dataType == DataType.TIMESTAMP) { sb.append(".timestamp()"); } else if (dataType == DataType.DATE) { diff --git a/data-processor/src/test/groovy/io/micronaut/data/processor/sql/JsonViewSpec.groovy b/data-processor/src/test/groovy/io/micronaut/data/processor/sql/JsonViewSpec.groovy index d273c8ae3b7..d66a50e048c 100644 --- a/data-processor/src/test/groovy/io/micronaut/data/processor/sql/JsonViewSpec.groovy +++ b/data-processor/src/test/groovy/io/micronaut/data/processor/sql/JsonViewSpec.groovy @@ -63,23 +63,23 @@ interface ContactViewRepository extends CrudRepository { def findAllOrderByAddressZipCodeDescQuery = getQuery(repository.getRequiredMethod("findAllOrderByAddressZipCodeDesc")) expect: - findStartDateTimeByIdQuery == 'SELECT cv.DATA.startDateTime.timestamp() FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id" = ?)' - findByIdQuery == 'SELECT cv.* FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id" = ?)' + findStartDateTimeByIdQuery == 'SELECT cv.DATA.startDateTime.timestamp() FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id".numberOnly() = ?)' + findByIdQuery == 'SELECT cv.* FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id".numberOnly() = ?)' saveQuery == 'BEGIN INSERT INTO "CONTACT_VIEW" VALUES (?) RETURNING JSON_VALUE(DATA,\'$._id\') INTO ?; END;' - updateQuery == 'UPDATE "CONTACT_VIEW" cv SET cv.DATA=? WHERE (cv.DATA."_id" = ?)' - updateAgeAndNameQuery == 'UPDATE "CONTACT_VIEW" cv SET cv.DATA= json_transform(DATA, SET \'$.age\' = ?, SET \'$.name\' = ?) WHERE (cv.DATA."_id" = ?)' - updateByAddressStreetQuery == 'UPDATE "CONTACT_VIEW" cv SET cv.DATA= json_transform(DATA, SET \'$.name\' = ?) WHERE (cv.DATA.address.street = ?)' - deleteByIdQuery == 'DELETE FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id" = ?)' - deleteQuery == 'DELETE FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id" = ?)' + updateQuery == 'UPDATE "CONTACT_VIEW" cv SET cv.DATA=? WHERE (cv.DATA."_id".numberOnly() = ?)' + updateAgeAndNameQuery == 'UPDATE "CONTACT_VIEW" cv SET cv.DATA= json_transform(DATA, SET \'$.age\' = ?, SET \'$.name\' = ?) WHERE (cv.DATA."_id".numberOnly() = ?)' + updateByAddressStreetQuery == 'UPDATE "CONTACT_VIEW" cv SET cv.DATA= json_transform(DATA, SET \'$.name\' = ?) WHERE (cv.DATA.address.street.stringOnly() = ?)' + deleteByIdQuery == 'DELETE FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id".numberOnly() = ?)' + deleteQuery == 'DELETE FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id".numberOnly() = ?)' deleteAllQuery == 'DELETE FROM "CONTACT_VIEW" cv' - deleteAllIterableQuery == 'DELETE FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id" IN (?))' - findNameByIdQuery == 'SELECT cv.DATA.name.string() FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id" = ?)' - findMaxAgeQuery == 'SELECT MAX(cv.DATA.age.number()) FROM "CONTACT_VIEW" cv' - findActiveByNameQuery == 'SELECT cv.DATA.active.number() FROM "CONTACT_VIEW" cv WHERE (cv.DATA.name = ?)' - findAllOrderByStartDateTimeQuery == 'SELECT cv.* FROM "CONTACT_VIEW" cv ORDER BY cv.DATA.startDateTime ASC' - findByAddressStreetQuery == 'SELECT cv.* FROM "CONTACT_VIEW" cv WHERE (cv.DATA.address.street = ?)' - findAddressStreetByIdQuery == 'SELECT cv.DATA.address.street.string() FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id" = ?)' - findAllOrderByAddressZipCodeDescQuery == 'SELECT cv.* FROM "CONTACT_VIEW" cv ORDER BY cv.DATA.address.zipCode DESC' + deleteAllIterableQuery == 'DELETE FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id".numberOnly() IN (?))' + findNameByIdQuery == 'SELECT cv.DATA.name.stringOnly() FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id".numberOnly() = ?)' + findMaxAgeQuery == 'SELECT MAX(cv.DATA.age.numberOnly()) FROM "CONTACT_VIEW" cv' + findActiveByNameQuery == 'SELECT cv.DATA.active.numberOnly() FROM "CONTACT_VIEW" cv WHERE (cv.DATA.name.stringOnly() = ?)' + findAllOrderByStartDateTimeQuery == 'SELECT cv.* FROM "CONTACT_VIEW" cv ORDER BY cv.DATA.startDateTime.timestamp() ASC' + findByAddressStreetQuery == 'SELECT cv.* FROM "CONTACT_VIEW" cv WHERE (cv.DATA.address.street.stringOnly() = ?)' + findAddressStreetByIdQuery == 'SELECT cv.DATA.address.street.stringOnly() FROM "CONTACT_VIEW" cv WHERE (cv.DATA."_id".numberOnly() = ?)' + findAllOrderByAddressZipCodeDescQuery == 'SELECT cv.* FROM "CONTACT_VIEW" cv ORDER BY cv.DATA.address.zipCode.stringOnly() DESC' } void "test JsonView repository with unsupported dialect"() {