|
| 1 | +# Case Expressions in the Java DSL |
| 2 | + |
| 3 | +Support for case expressions was added in version 1.5.1. For information about case expressions in the Kotlin DSL, see |
| 4 | +the [Kotlin Case Expressions](kotlinCaseExpressions.md) page. |
| 5 | + |
| 6 | +## Case Statements in SQL |
| 7 | +The library supports different types of case expressions - a "simple" case expression, and a "searched" case |
| 8 | +expressions. |
| 9 | + |
| 10 | +A simple case expression checks the values of a single column. It looks like this: |
| 11 | + |
| 12 | +```sql |
| 13 | +select case id |
| 14 | + when 1, 2, 3 then true |
| 15 | + else false |
| 16 | + end as small_id |
| 17 | +from foo |
| 18 | +``` |
| 19 | + |
| 20 | +Some databases also support simple comparisons on simple case expressions, which look lke this: |
| 21 | + |
| 22 | +```sql |
| 23 | +select case total_length |
| 24 | + when < 10 then 'small' |
| 25 | + when > 20 then 'large' |
| 26 | + else 'medium' |
| 27 | + end as tshirt_size |
| 28 | +from foo |
| 29 | +``` |
| 30 | + |
| 31 | +A searched case expression allows arbitrary logic, and it can check the values of multiple columns. It looks like this: |
| 32 | + |
| 33 | +```sql |
| 34 | +select case |
| 35 | + when animal_name = 'Small brown bat' or animal_name = 'Large brown bat' then 'Bat' |
| 36 | + when animal_name = 'Artic fox' or animal_name = 'Red fox' then 'Fox' |
| 37 | + else 'Other' |
| 38 | + end as animal_type |
| 39 | +from foo |
| 40 | +``` |
| 41 | + |
| 42 | +## Bind Variables and Casting |
| 43 | + |
| 44 | +The library will always render the "when" part of a case expression using bind variables. Rendering of the "then" and |
| 45 | +"else" parts of a case expression may or may not use bind variables depending on how you write the query. In general, |
| 46 | +the library will render "then" and "else" as constants - meaning not using bind variables. If you wish to use bind |
| 47 | +variables for these parts of a case expressions, then you can use the `value` function to turn a constant into a |
| 48 | +bind variable. We will show examples of the different renderings in the following sections. |
| 49 | + |
| 50 | +If you choose to use bind variables for all "then" and "else" values, it is highly likely that the database will |
| 51 | +require you to specify an expected datatype by using a `cast` function. |
| 52 | + |
| 53 | +Even for "then" and "else" sections that are rendered with constants, you may still desire to use a `cast` in some |
| 54 | +cases. For example, if you specify Strings for all "then" and "else" values, the database will likely return all |
| 55 | +values as datatype CHAR with the length of the longest constant string. Typically, we would prefer the use of VARCHAR, |
| 56 | +so we don't have to strip trailing blanks from the results. This is a good use for a `cast` with a constant. |
| 57 | +Similarly, Java float constants are often interpreted by databases as BigDecimal. You can use a `cast` to have them |
| 58 | +returned as floats. |
| 59 | + |
| 60 | +Note: in the following sections we will use `?` to show a bind variable, but the actual rendered SQL will be different |
| 61 | +because bind variables will be rendered appropriately for the execution engine you are using (either MyBatis or Spring). |
| 62 | + |
| 63 | +Also note: in Java, `case` and `else` are reserved words - meaning we cannot use them as method names. For this reason, |
| 64 | +the library uses `case_` and `else_` respectively as method names. |
| 65 | + |
| 66 | +Full examples for case expressions are in the test code for the library here: |
| 67 | +https://github.com/mybatis/mybatis-dynamic-sql/blob/master/src/test/java/examples/animal/data/CaseExpressionTest.java |
| 68 | + |
| 69 | +## Java DSL for Simple Case Statements with Simple Values |
| 70 | + |
| 71 | +A simple case expression can be coded like the following in the Java DSL: |
| 72 | + |
| 73 | +```java |
| 74 | +select(case_(id) |
| 75 | + .when(1, 2, 3).then(true) |
| 76 | + .else_(false) |
| 77 | + .end().as("small_id")) |
| 78 | +.from(foo) |
| 79 | +``` |
| 80 | + |
| 81 | +A statement written this way will render as follows: |
| 82 | + |
| 83 | +```sql |
| 84 | +select case id when ?, ?, ? then true else false end as small_id from foo |
| 85 | +``` |
| 86 | + |
| 87 | +Note that the "then" and "else" parts are NOT rendered with bind variables. If you with to use bind variables, then |
| 88 | +you can write the query as follows: |
| 89 | + |
| 90 | +```java |
| 91 | +select(case_(id) |
| 92 | + .when(1, 2, 3).then(value(true)) |
| 93 | + .else_(value(false)) |
| 94 | + .end().as("small_id")) |
| 95 | +.from(foo) |
| 96 | +``` |
| 97 | + |
| 98 | +In this case, we are using the `value` function to denote a bind variable. The SQL will now be rendered as follows: |
| 99 | + |
| 100 | +```sql |
| 101 | +select case id when ?, ?, ? then ? else ? end as small_id from foo |
| 102 | +``` |
| 103 | + |
| 104 | +*Important*: Be aware that your database may throw an exception for SQL like this because the database cannot determine |
| 105 | +the datatype of the resulting column. If that happens, you will need to cast one or more of the variables to the |
| 106 | +expected data type. Here's an example of using the `cast` function: |
| 107 | + |
| 108 | +```java |
| 109 | +select(case_(id) |
| 110 | + .when(1, 2, 3).then(value(true)) |
| 111 | + .else_(cast(value(false)).as("BOOLEAN)")) |
| 112 | + .end().as("small_id")) |
| 113 | +.from(foo) |
| 114 | +``` |
| 115 | + |
| 116 | +In this case, the SQL will render as follows: |
| 117 | + |
| 118 | +```sql |
| 119 | +select case id when ?, ?, ? then ? else cast(? as BOOLEAN) end as small_id from foo |
| 120 | +``` |
| 121 | + |
| 122 | +In our testing, casting a single bound value is enough to inform the database of your expected datatype, but |
| 123 | +you should perform your own testing. |
| 124 | + |
| 125 | +## Java DSL for Simple Case Statements with Conditions |
| 126 | + |
| 127 | +A simple case expression can be coded like the following in the Java DSL: |
| 128 | + |
| 129 | +```java |
| 130 | +select(case_(total_length) |
| 131 | + .when(isLessThan(10)).then_("small") |
| 132 | + .when(isGreaterThan(20)).then_("large") |
| 133 | + .else_("medium") |
| 134 | + .end().as("tshirt_size")) |
| 135 | +.from(foo) |
| 136 | +``` |
| 137 | + |
| 138 | +A statement written this way will render as follows: |
| 139 | + |
| 140 | +```sql |
| 141 | +select case total_length when < ? then 'small' when > ? then 'large' else 'medium' end as tshirt_size from foo |
| 142 | +``` |
| 143 | + |
| 144 | +Note that the "then" and "else" parts are NOT rendered with bind variables. If you with to use bind variables, then |
| 145 | +you can use the `value` function as shown above. |
| 146 | + |
| 147 | +A query like this could be a good place to use casting with constants. Most databases will return the calculated |
| 148 | +"tshirt_size" column as CHAR(6) - so the "small" and "large" values will have a trailing blank. If you wish to use |
| 149 | +VARCHAR, you can use the `cast` function as follows: |
| 150 | + |
| 151 | +```java |
| 152 | +select(case_(total_length) |
| 153 | + .when(isLessThan(10)).then_("small") |
| 154 | + .when(isGreaterThan(20)).then_("large") |
| 155 | + .else_(cast("medium").as("VARCHAR(6)")) |
| 156 | + .end().as("tshirt_size")) |
| 157 | +.from(foo) |
| 158 | +``` |
| 159 | + |
| 160 | +In this case, we are using the `cast` function to specify the datatype of a constant. The SQL will now be rendered as |
| 161 | +follows (without the line breaks): |
| 162 | + |
| 163 | +```sql |
| 164 | +select case total_length |
| 165 | + when < ? then 'small' when > ? then 'large' |
| 166 | + else cast('medium' as VARCHAR(6)) end as tshirt_size from foo |
| 167 | +``` |
| 168 | + |
| 169 | +## Java DSL for Searched Case Statements |
| 170 | + |
| 171 | +A searched case statement is written as follows: |
| 172 | + |
| 173 | +```java |
| 174 | +select(case_() |
| 175 | + .when(animalName, isEqualTo("Small brown bat")).or(animalName, isEqualTo("Large brown bat")).then("Bat") |
| 176 | + .when(animalName, isEqualTo("Artic fox")).or(animalName, isEqualTo("Red fox")).then("Fox") |
| 177 | + .else_("Other") |
| 178 | + .end().as("animal_type")) |
| 179 | +.from(foo) |
| 180 | +``` |
| 181 | + |
| 182 | +The full syntax of "where" and "having" clauses is supported in the "when" clause - but that may or may not be supported |
| 183 | +by your database. Testing is crucial. In addition, the library does not support conditions that don't render in a case |
| 184 | +statement - so avoid the use of conditions like "isEqualToWhenPresent", etc. |
| 185 | + |
| 186 | +The rendered SQL will be as follows (without the line breaks): |
| 187 | +```sql |
| 188 | +select case |
| 189 | + when animal_name = ? or animal_name = ? then 'Bat' |
| 190 | + when animal_name = ? or animal_name = ? then 'Fox' |
| 191 | + else 'Other' |
| 192 | + end as animal_type |
| 193 | +from foo |
| 194 | +``` |
| 195 | + |
| 196 | +The use of the `value` function to support bind variables, and the use of casting, is the same is shown above. |
0 commit comments