Skip to content

Add a new documentation page for complex queries #111

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 1 commit into from
Jul 4, 2019
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
47 changes: 47 additions & 0 deletions src/site/markdown/docs/complexQueries.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,47 @@
# Complex Queries
Enhancements in version 1.1.2 make it easier to code complex queries.

For example, suppose you want to code a complex search on a Person table. The search parameters are id, first name, and last name. The rules are:

1. If an id is entered, use the id and ignore the other search parameters
1. If an id is not entered, then do a fuzzy search based on the other parameters

This can be implemented with code like the following...

```java
public SelectStatementProvider search(Integer targetId, String fName, String lName) {
var builder = select(id, firstName, lastName) // (1)
.from(person)
.where(); // (2)

if (targetId != null) { // (3)
builder
.and(id, isEqualTo(targetId));
} else {
builder
.and(firstName, isLike(fName).when(Objects::nonNull).then(s -> "%" + s + "%")) // (4)
.and(lastName, isLikeWhenPresent(lName).then(this::addWildcards)); // (5)
}

builder
.orderBy(lastName, firstName)
.fetchFirst(50).rowsOnly(); // (6)

return builder.build().render(RenderingStrategy.MYBATIS3); // (7)
}

public String addWildcards(String s) {
return "%" + s + "%";
}
```

Notes:

1. Note the use of the `var` keyword here. If you are using an older version of Java, the actual type is `QueryExpressionDSL<SelectModel>.QueryExpressionWhereBuilder`
1. Here we are calling `where()` with no parameters. This sets up the builder to accept conditions further along in the code. If no conditions are added, then the where clause will not be rendered
1. This `if` statement implements the rules of the search. If an ID is entered , use it. Otherwise do a fuzzy search based on first name and last name.
1. The `then` statement on this line allows you to change the parameter value before it is place in the parameter Map. In this case we are adding SQL wildcards to the start and end of the search String - but only if the search String is not null. If the search String is null, the lambda will not be called and the condition will not render
1. This shows using a method reference instead of a lambda on the `then`. Method references allow you to more clearly express intent. Note also the use of the `isLikeWhenPresent` condition which is a built in condition that checks for nulls
1. It is a good idea to limit the number of rows returned from a search
1. Note that we are calling the `build` method from the intermediate object retrieved in step 1. It is no longer necessary to call `build` on the last object returned from a select builder

4 changes: 3 additions & 1 deletion src/site/site.xml
Original file line number Diff line number Diff line change
Expand Up @@ -41,7 +41,9 @@
<item href="docs/whereClauses.html" name="WHERE Clause Support" >
<item href="docs/conditions.html" name="WHERE Conditions"/>
</item>
<item href="docs/select.html" name="SELECT Statements" />
<item href="docs/select.html" name="SELECT Statements" >
<item href="docs/complexQueries.html" name="Complex Queries"/>
</item>
<item href="docs/delete.html" name="DELETE Statements" />
<item href="docs/insert.html" name="INSERT Statements" />
<item href="docs/update.html" name="UPDATE Statements" />
Expand Down
134 changes: 134 additions & 0 deletions src/test/java/examples/complexquery/ComplexQueryTest.java
Original file line number Diff line number Diff line change
@@ -0,0 +1,134 @@
/**
* Copyright 2016-2019 the original author or authors.
*
* Licensed under the Apache License, Version 2.0 (the "License");
* you may not use this file except in compliance with the License.
* You may obtain a copy of the License at
*
* http://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing, software
* distributed under the License is distributed on an "AS IS" BASIS,
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
* See the License for the specific language governing permissions and
* limitations under the License.
*/
package examples.complexquery;

import static examples.complexquery.PersonDynamicSqlSupport.firstName;
import static examples.complexquery.PersonDynamicSqlSupport.id;
import static examples.complexquery.PersonDynamicSqlSupport.lastName;
import static examples.complexquery.PersonDynamicSqlSupport.person;
import static org.assertj.core.api.Assertions.assertThat;
import static org.mybatis.dynamic.sql.SqlBuilder.*;

import java.util.Objects;

import org.junit.jupiter.api.Test;
import org.mybatis.dynamic.sql.render.RenderingStrategy;
import org.mybatis.dynamic.sql.select.QueryExpressionDSL;
import org.mybatis.dynamic.sql.select.SelectModel;
import org.mybatis.dynamic.sql.select.render.SelectStatementProvider;

public class ComplexQueryTest {

@Test
public void testId() {
SelectStatementProvider selectStatement = search(2, null, null);

String expected = "select person_id, first_name, last_name"
+ " from Person"
+ " where person_id = #{parameters.p1}"
+ " order by last_name, first_name"
+ " fetch first #{parameters._fetchFirstRows} rows only";

assertThat(selectStatement.getSelectStatement()).isEqualTo(expected);
assertThat(selectStatement.getParameters().get("p1")).isEqualTo(2);
assertThat(selectStatement.getParameters().get("_fetchFirstRows")).isEqualTo(50L);
}

@Test
public void testFirstNameOnly() {
SelectStatementProvider selectStatement = search(null, "fred", null);

String expected = "select person_id, first_name, last_name"
+ " from Person"
+ " where first_name like #{parameters.p1}"
+ " order by last_name, first_name"
+ " fetch first #{parameters._fetchFirstRows} rows only";

assertThat(selectStatement.getSelectStatement()).isEqualTo(expected);
assertThat(selectStatement.getParameters().get("p1")).isEqualTo("%fred%");
assertThat(selectStatement.getParameters().get("_fetchFirstRows")).isEqualTo(50L);
}

@Test
public void testLastNameOnly() {
SelectStatementProvider selectStatement = search(null, null, "flintstone");

String expected = "select person_id, first_name, last_name"
+ " from Person"
+ " where last_name like #{parameters.p1}"
+ " order by last_name, first_name"
+ " fetch first #{parameters._fetchFirstRows} rows only";

assertThat(selectStatement.getSelectStatement()).isEqualTo(expected);
assertThat(selectStatement.getParameters().get("p1")).isEqualTo("%flintstone%");
assertThat(selectStatement.getParameters().get("_fetchFirstRows")).isEqualTo(50L);
}

@Test
public void testBothNames() {
SelectStatementProvider selectStatement = search(null, "fred", "flintstone");

String expected = "select person_id, first_name, last_name"
+ " from Person"
+ " where first_name like #{parameters.p1}"
+ " and last_name like #{parameters.p2}"
+ " order by last_name, first_name"
+ " fetch first #{parameters._fetchFirstRows} rows only";

assertThat(selectStatement.getSelectStatement()).isEqualTo(expected);
assertThat(selectStatement.getParameters().get("p1")).isEqualTo("%fred%");
assertThat(selectStatement.getParameters().get("p2")).isEqualTo("%flintstone%");
assertThat(selectStatement.getParameters().get("_fetchFirstRows")).isEqualTo(50L);
}

@Test
public void testAllNull() {
SelectStatementProvider selectStatement = search(null, null, null);

String expected = "select person_id, first_name, last_name"
+ " from Person"
+ " order by last_name, first_name"
+ " fetch first #{parameters._fetchFirstRows} rows only";

assertThat(selectStatement.getSelectStatement()).isEqualTo(expected);
assertThat(selectStatement.getParameters().get("_fetchFirstRows")).isEqualTo(50L);
}

public SelectStatementProvider search(Integer targetId, String fName, String lName) {
QueryExpressionDSL<SelectModel>.QueryExpressionWhereBuilder builder = select(id, firstName, lastName)
.from(person)
.where();

if (targetId != null) {
builder
.and(id, isEqualTo(targetId));
} else {
builder
.and(firstName, isLike(fName).when(Objects::nonNull).then(s -> "%" + s + "%"))
.and(lastName, isLikeWhenPresent(lName).then(this::addWildcards));
}

builder
.orderBy(lastName, firstName)
.fetchFirst(50).rowsOnly();

return builder.build().render(RenderingStrategy.MYBATIS3);
}

public String addWildcards(String s) {
return "%" + s + "%";
}
}
38 changes: 38 additions & 0 deletions src/test/java/examples/complexquery/PersonDynamicSqlSupport.java
Original file line number Diff line number Diff line change
@@ -0,0 +1,38 @@
/**
* Copyright 2016-2019 the original author or authors.
*
* Licensed under the Apache License, Version 2.0 (the "License");
* you may not use this file except in compliance with the License.
* You may obtain a copy of the License at
*
* http://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing, software
* distributed under the License is distributed on an "AS IS" BASIS,
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
* See the License for the specific language governing permissions and
* limitations under the License.
*/
package examples.complexquery;

import org.mybatis.dynamic.sql.SqlColumn;
import org.mybatis.dynamic.sql.SqlTable;

public final class PersonDynamicSqlSupport {
public static final Person person = new Person();
public static final SqlColumn<Integer> id = person.id;
public static final SqlColumn<String> firstName = person.firstName;
public static final SqlColumn<String> lastName = person.lastName;
public static final SqlColumn<Integer> age = person.age;

public static final class Person extends SqlTable {
public final SqlColumn<Integer> id = column("person_id");
public final SqlColumn<String> firstName = column("first_name");
public final SqlColumn<String> lastName = column("last_name");
public final SqlColumn<Integer> age = column("age");

public Person() {
super("Person");
}
}
}
22 changes: 22 additions & 0 deletions src/test/java/examples/complexquery/SearchUtils.java
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
/**
* Copyright 2016-2019 the original author or authors.
*
* Licensed under the Apache License, Version 2.0 (the "License");
* you may not use this file except in compliance with the License.
* You may obtain a copy of the License at
*
* http://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing, software
* distributed under the License is distributed on an "AS IS" BASIS,
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
* See the License for the specific language governing permissions and
* limitations under the License.
*/
package examples.complexquery;

public class SearchUtils {
public static String addWildcards(String s) {
return "%" + s + "%";
}
}