Skip to content

Commit

Permalink
JDBC-293, JDBC-294, JDBC-523, JDBC-524 Improve JDBC function escapes
Browse files Browse the repository at this point in the history
- Support optional parameters for CHAR_LENGTH, CHARACTER_LENGTH, LENGTH, POSITION, and LOCATE as defined in JDBC specification
- Improve CONVERT support to be compliant with JDBC 4.1 and higher
- Add DEGREES/RADIANS
- Add TIMESTAMPADD/TIMESTAMPDIFF
  • Loading branch information
mrotteveel committed Mar 11, 2018
1 parent d6e2d36 commit ccd5fc3
Show file tree
Hide file tree
Showing 40 changed files with 2,660 additions and 938 deletions.
109 changes: 109 additions & 0 deletions src/documentation/release_notes.md
Expand Up @@ -548,6 +548,108 @@ set or retrieved using `String` or the `DecimalXX` types, or the result of
rounding. This behaviour is subject to change, and future releases may 'round'
to `0` (aka `+0`).

Improved JDBC function escape support
-------------------------------------

Revised support for JDBC function escapes with optional parameters, and added
support for a number of previously unsupported functions or options.

If you only target Firebird, then we suggest you do not use JDBC function
escapes.

### New JDBC function escapes ###

- `DEGREES(number)` - Degrees in _number_ radians; implemented as
`((number)*180.0/PI())`
- `RADIANS(number)` - Radians in _number_ degrees; implemented as
`((number)*PI()/180.0)`
- `QUARTER(date)` - Quarter of year for date; implemented as
`(1+(EXTRACT(MONTH FROM date)-1)/3)`
- `TIMESTAMPADD(interval, count, timestamp)` - Implemented using `DATEADD`
with the following caveats:

- _interval_ `SQL_TSI_FRAC_SECOND` unit is nanoseconds and will be
simulated by using `MILLISECOND` and the count multiplied by `1.0e-6` to
convert the value to milliseconds.
- _interval_ `SQL_TSI_QUARTER` will be simulated by using `MONTH` and
_count_ multiplied by 3.
- _interval_ values that are not specified in JDBC will be passed as is,
resulting in an error from the Firebird engine if it is an invalid interval
name for `DATEADD`.
- `TIMESTAMPDIFF(interval, timestamp1, timestamp2)` - Implemented using
`DATEDIFF` with the following caveats:

- _interval_ `SQL_TSI_FRAC_SECOND` unit is nanoseconds and will be
simulated by using `MILLISECOND` and the result multiplied by `1.0e6` and
cast to `BIGINT` to convert the value to nanoseconds.
- Value `SQL_TSI_QUARTER` will be simulated by using `MONTH` and the
result divided by 3.
- Contrary to specified in the JDBC specification, the resulting value
will be `BIGINT`, not `INTEGER`.
- _interval_ values that are not specified in JDBC will be passed as is,
resulting in an error from the Firebird engine if it is an invalid interval
name for `DATEDIFF`.

### Improved JDBC function escapes ###

- `CHAR_LENGTH(string[, CHARACTERS|OCTETS])` - The optional second parameter
with `CHARACTERS` or `OCTETS` is now supported.

Absence of second parameter, or `CHARACTERS` maps to `CHAR_LENGTH`, `OCTETS` maps to
`OCTET_LENGTH`
- `CHARACTER_LENGTH(string[, CHARACTERS|OCTETS])` - see `CHAR_LENGTH`
- `CONCAT(string1, string2)` - Added parentheses around expression to prevent
ambiguity or incorrect evaluation order.
- `LENGTH(string[, CHARACTERS|OCTETS])` - The optional second parameter with
`CHARACTERS` or `OCTETS` is now supported.

The JDBC specification specifies _Number of characters in string, excluding
trailing blanks_, we right-trim (`TRIM(TRAILING FROM value)`) the string before
passing the value to either `CHAR_LENGTH` or `OCTETS_LENGTH`. As a result, the
interpretation of what is a blank depends on the type of _value_. Is the value a
normal `(VAR)CHAR` (non-octets), then the blank is space (0x20), for a
`VAR(CHAR)CHARACTER SET OCTETS / (VAR)BINARY` the blank is NUL (0x00). This means
that the optional `CHARACTERS|OCTETS` parameter has no influence on which blanks
are trimmed, but only whether we count characters or bytes after trimming.
- `LOCATE(string1, string2[, start])` - The third parameter _start_ is now
optional.
- `POSITION(substring IN string[, CHARACTERS|OCTETS])` - The optional second
parameter is now supported if `CHARACTERS`. `OCTETS` is not supported.
- `CONVERT(value, SQLtype)` - See [Improved CONVERT support].

### Improved CONVERT support ###

In Jaybird 3, `CONVERT(value, SQLtype)` would map directly to
`CAST(value as SQLtype)`, we have improved support to better conform to the JDBC
requirements, with some caveats:

- Both the `SQL_<datatype>` and `<datatype>` mapping is now supported
- Contrary to the specification, we allow explicit length or precision and
scale parameters
- `(SQL_)VARCHAR`, `(SQL_)NVARCHAR` (and _value_ not a parameter (`?`))
without explicit length is converted using `TRIM(TRAILING FROM value)`, which
means the result is `VARCHAR` except for blobs where this will result in a blob;
national character set will be lost. If _value_ is a parameter (`?`), and no
length is specified, then a length of 50 will be applied (cast to
`(N)VARCHAR(50)`).
- `(SQL_)CHAR`, `(SQL_)NCHAR` without explicit length will be cast to
`(N)CHAR(50)`
- `(SQL_)BINARY`, and `(SQL_)VARBINARY` without explicit length will be cast
to `(VAR)CHAR(50) CHARACTER SET OCTETS`. With explicit length,
`CHARACTER SET OCTETS` is appended.
- `(SQL_)LONGVARCHAR`, `(SQL_)LONGNVARCHAR`, `(SQL_)CLOB`, `(SQL_)NCLOB` will
be cast to `BLOB SUB_TYPE TEXT`, national character set will be lost
- `(SQL_)LONGVARBINARY`, `(SQL_)BLOB` will be cast to `BLOB SUB_TYPE BINARY`
- `(SQL_)TINYINT` is mapped to `SMALLINT`
- `(SQL_)ROWID` is not supported as length of `DB_KEY` values depend on the
context
- `(SQL_)DECIMAL` and `(SQL_)NUMERIC` without precision and scale are passed
as is, in current Firebird versions, this means the value will be equivalent to
`DECIMAL(9,0)` (which is equivalent to `INTEGER`)
- Unsupported/unknown _SQLtype_ values (or invalid length or precision and
scale) are passed as is to cast, resulting in an error from the Firebird engine
if the resulting cast is invalid

Potentially breaking changes
----------------------------

Expand Down Expand Up @@ -706,6 +808,13 @@ The following methods will be removed in Jaybird 5:
- `TraceManager.loadConfigurationFromFile(String)`, use standard Java
functionality like `new String(Files.readAllBytes(Paths.get(fileName)), <charset>)`

### Removal of deprecated constants ###

The following constants will be removed in Jaybird 5:

- All `SQL_STATE_*` constants in `FBSQLParseException` will be removed. Use equivalent
constants in `org.firebirdsql.jdbc.SQLStateConstants`.

Compatibility notes
===================

Expand Down
1 change: 1 addition & 0 deletions src/main/org/firebirdsql/jdbc/SQLStateConstants.java
Expand Up @@ -64,6 +64,7 @@ public final class SQLStateConstants {
public static final String SQL_STATE_COMM_LINK_FAILURE = "08S01";

public static final String SQL_STATE_SYNTAX_ERROR = "42000";
public static final String SQL_STATE_INVALID_ESCAPE_SEQ = SQL_STATE_SYNTAX_ERROR;

private SQLStateConstants() {
// no instances
Expand Down
52 changes: 52 additions & 0 deletions src/main/org/firebirdsql/jdbc/escape/CharacterLengthFunction.java
@@ -0,0 +1,52 @@
/*
* Firebird Open Source JavaEE Connector - JDBC Driver
*
* Distributable under LGPL license.
* You may obtain a copy of the License at http://www.gnu.org/copyleft/lgpl.html
*
* This program is distributed in the hope that it will be useful,
* but WITHOUT ANY WARRANTY; without even the implied warranty of
* MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
* LGPL License for more details.
*
* This file was created by members of the firebird development team.
* All individual contributions remain the Copyright (C) of those
* individuals. Contributors to this file are either listed here or
* can be obtained from a source control history command.
*
* All rights reserved.
*/
package org.firebirdsql.jdbc.escape;

/**
* Implements the {@code CHAR_LENGTH} and {@code CHARACTER_LENGTH} JDBC escape
*
* @author <a href="mailto:mrotteveel@users.sourceforge.net">Mark Rotteveel</a>
* @since 4.0
*/
final class CharacterLengthFunction implements SQLFunction {

private static final SQLFunction CHAR_LENGTH_FUNCTION = new PatternSQLFunction("CHAR_LENGTH({0})");
private static final SQLFunction OCTET_LENGTH_FUNCTION = new PatternSQLFunction("OCTET_LENGTH({0})");

@Override
public String apply(String... parameters) throws FBSQLParseException {
switch (parameters.length) {
case 1:
return CHAR_LENGTH_FUNCTION.apply(parameters);
case 2:
String typeParam = parameters[1].trim();
if ("CHARACTERS".equalsIgnoreCase(typeParam)) {
return CHAR_LENGTH_FUNCTION.apply(parameters);
} else if ("OCTETS".equalsIgnoreCase(typeParam)) {
return OCTET_LENGTH_FUNCTION.apply(parameters);
} else {
throw new FBSQLParseException(
"Second parameter for CHAR(ACTER)_LENGTH must be OCTETS or CHARACTERS, was " + parameters[1]);
}
default:
throw new FBSQLParseException(
"Expected 1 or 2 parameters for CHAR(ACTER)_LENGTH, received " + parameters.length);
}
}
}
43 changes: 43 additions & 0 deletions src/main/org/firebirdsql/jdbc/escape/ConstantSQLFunction.java
@@ -0,0 +1,43 @@
/*
* Firebird Open Source JavaEE Connector - JDBC Driver
*
* Distributable under LGPL license.
* You may obtain a copy of the License at http://www.gnu.org/copyleft/lgpl.html
*
* This program is distributed in the hope that it will be useful,
* but WITHOUT ANY WARRANTY; without even the implied warranty of
* MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
* LGPL License for more details.
*
* This file was created by members of the firebird development team.
* All individual contributions remain the Copyright (C) of those
* individuals. Contributors to this file are either listed here or
* can be obtained from a source control history command.
*
* All rights reserved.
*/
package org.firebirdsql.jdbc.escape;

/**
* Implementation of {@link SQLFunction} for constants or functions without parameters.
*
* @author <a href="mailto:mrotteveel@users.sourceforge.net">Mark Rotteveel</a>
* @since 4.0
*/
final class ConstantSQLFunction implements SQLFunction {

private final String functionConstant;

ConstantSQLFunction(String functionConstant) {
this.functionConstant = functionConstant;
}

@Override
public String apply(String... parameters) throws FBSQLParseException {
if (parameters.length > 0) {
throw new FBSQLParseException(
"Invalid number of arguments, expected no arguments, received " + parameters.length);
}
return functionConstant;
}
}
145 changes: 145 additions & 0 deletions src/main/org/firebirdsql/jdbc/escape/ConvertFunction.java
@@ -0,0 +1,145 @@
/*
* Firebird Open Source JavaEE Connector - JDBC Driver
*
* Distributable under LGPL license.
* You may obtain a copy of the License at http://www.gnu.org/copyleft/lgpl.html
*
* This program is distributed in the hope that it will be useful,
* but WITHOUT ANY WARRANTY; without even the implied warranty of
* MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
* LGPL License for more details.
*
* This file was created by members of the firebird development team.
* All individual contributions remain the Copyright (C) of those
* individuals. Contributors to this file are either listed here or
* can be obtained from a source control history command.
*
* All rights reserved.
*/
package org.firebirdsql.jdbc.escape;

import java.util.regex.Matcher;
import java.util.regex.Pattern;

/**
* Implements the {@code CONVERT} JDBC escape with some caveats.
* <p>
* Most important caveats:
* </p>
* <ul>
* <li>Contrary to the specification, we allow explicit length or precision and scale parameters</li>
* <li>{@code VARCHAR}, {@code NVARCHAR} (and value not a parameter ({@code ?})) without explicit length is converted
* using {@code TRIM(TRAILING FROM value)}, which means the result is {@code VARCHAR} except for blobs where this will
* result in a blob; national character set will be lost. If value is a parameter ({@code ?}), and no length is
* specified, then a length of 50 will be applied.</li>
* <li>{@code CHAR}, {@code NCHAR} without explicit length will be cast to {@code (N)CHAR(50)}</li>
* <li>{@code BINARY}, and {@code VARBINARY} without explicit length will be cast to
* {@code (VAR)CHAR(50) CHARACTER SET OCTETS}, with explicit length, {@code CHARACTER SET OCTETS} is appended</li>
* <li>{@code LONGVARCHAR}, {@code LONGNVARCHAR}, {@code CLOB}, {@code NCLOB} will be cast to
* {@code BLOB SUB_TYPE TEXT}, national character set will be lost</li>
* <li>{@code LONGVARBINARY}, {@code BLOB} will be cast to {@code BLOB SUB_TYPE BINARY}</li>
* <li>{@code TINYINT} is mapped to {@code SMALLINT}</li>
* <li>{@code ROWID} is not supported as length of {@code DB_KEY} values depend on the context
* TODO: consider cast to CHAR(8) character set binary or maybe multiples of 8?</li>
* <li>{@code `(SQL_)DECIMAL`} and {@code `(SQL_)NUMERIC`} without precision and scale are passed as is, in current
* Firebird versions, this means the value will be equivalent to {@code DECIMAL(9,0)} (which is equivalent to
* {@code INTEGER})</li>
* <li>Unsupported/unknown datatypes (or invalid length or precision and scale) are passed as is to cast, resulting in
* an error from the Firebird engine if the resulting cast is invalid</li>
* </ul>
*
* @author <a href="mailto:mrotteveel@users.sourceforge.net">Mark Rotteveel</a>
* @since 4.0
*/
final class ConvertFunction implements SQLFunction {

private static final Pattern TYPE_PATTERN =
Pattern.compile("(?:SQL_)?(\\w+)(?:\\s*(\\([^)]*\\)))?", Pattern.CASE_INSENSITIVE);

@Override
public String apply(String... parameters) throws FBSQLParseException {
if (parameters.length != 2) {
throw new FBSQLParseException("Expected 2 parameters for CONVERT, received " + parameters.length);
}
final String value = parameters[0];
final String sqlType = parameters[1];
final Matcher typeMatcher = TYPE_PATTERN.matcher(sqlType);
if (!typeMatcher.matches()) {
return renderCast(value, sqlType);
}

return renderCast(value, typeMatcher);
}

private String renderCast(final String value, final String sqlType) {
return "CAST(" + value + " AS " + sqlType + ")";
}

private String renderCast(final String value, final Matcher typeMatcher) {
String dataType = typeMatcher.group(1).toUpperCase();
String parameters = typeMatcher.group(2);
switch (dataType) {
case "TINYINT":
dataType = "SMALLINT";
break;
case "DOUBLE":
dataType = "DOUBLE PRECISION";
break;
case "CHAR":
case "NCHAR":
// Caveat: without parameters, size fixed at 50 (seems a reasonable trade off)
if (parameters == null) {
parameters = "(50)";
}
break;
case "VARCHAR":
case "NVARCHAR":
// Caveat: for blob use of TRIM results in a blob, not VARCHAR
// Caveat: for NVARCHAR without parameters, this results in a VARCHAR
// Caveat: if value is a parameter, size fixed at 50 (seems a reasonable trade off)
if (parameters == null) {
if (!"?".equals(value)) {
return "TRIM(TRAILING FROM " + value + ")";
} else {
parameters = "(50)";
}
}
break;
case "BINARY":
// Caveat: without parameters, size fixed at 50 (seems a reasonable trade off)
if (parameters == null) {
dataType = "CHAR";
parameters = "(50) CHARACTER SET OCTETS";
} else {
dataType = "CHAR";
parameters += " CHARACTER SET OCTETS";
}
break;
case "VARBINARY":
// Caveat: without parameters, size fixed at 50 (seems a reasonable trade off)
if (parameters == null) {
dataType = "VARCHAR";
parameters = "(50) CHARACTER SET OCTETS";
} else {
dataType = "VARCHAR";
parameters += " CHARACTER SET OCTETS";
}
break;
case "LONGVARCHAR":
case "LONGNVARCHAR":
case "CLOB":
case "NCLOB":
// Caveat: LONGNVARCHAR / NCLOB doesn't apply Firebird N(VAR)CHAR semantics of ISO-8859-1 charset
dataType = "BLOB SUB_TYPE TEXT";
parameters = null;
break;
case "LONGVARBINARY":
case "BLOB":
dataType = "BLOB SUB_TYPE BINARY";
parameters = null;
break;
}
return renderCast(value, parameters == null ? dataType : dataType + parameters);
}

}

0 comments on commit ccd5fc3

Please sign in to comment.