提交 2116380c authored 作者: Thomas Mueller's avatar Thomas Mueller

Improved MS SQL Server compatibility: support string concatenation using "+".…

Improved MS SQL Server compatibility: support string concatenation using "+". Thanks to Stepan for the patch!
上级 39ac3dc3
...@@ -18,7 +18,9 @@ Change Log ...@@ -18,7 +18,9 @@ Change Log
<h1>Change Log</h1> <h1>Change Log</h1>
<h2>Next Version (unreleased)</h2> <h2>Next Version (unreleased)</h2>
<ul><li>When using the multi-threaded mode, running ANALYZE concurrently in multiple <ul><li>Improved MS SQL Server compatibility: support string concatenation using "+".
Thanks to Stepan for the patch!
</li><li>When using the multi-threaded mode, running ANALYZE concurrently in multiple
connections could throw an exception. connections could throw an exception.
</li><li>The MERGE statement is now about 30% faster when using a PreparedStatement. </li><li>The MERGE statement is now about 30% faster when using a PreparedStatement.
</li><li>Multi-column indexes where the second or later column was descending did not always </li><li>Multi-column indexes where the second or later column was descending did not always
......
...@@ -1036,6 +1036,7 @@ or the SQL statement <code>SET MODE HSQLDB</code>. ...@@ -1036,6 +1036,7 @@ or the SQL statement <code>SET MODE HSQLDB</code>.
smaller than the current scale. Usually, the scale is converted and 0s are added if required. smaller than the current scale. Usually, the scale is converted and 0s are added if required.
</li><li>For unique indexes, <code>NULL</code> is distinct. </li><li>For unique indexes, <code>NULL</code> is distinct.
That means only one row with <code>NULL</code> in one of the columns is allowed. That means only one row with <code>NULL</code> in one of the columns is allowed.
</li><li>Text can be concatenated using '+'.
</li></ul> </li></ul>
<h3>MS SQL Server Compatibility Mode</h3> <h3>MS SQL Server Compatibility Mode</h3>
...@@ -1051,6 +1052,7 @@ or the SQL statement <code>SET MODE MSSQLServer</code>. ...@@ -1051,6 +1052,7 @@ or the SQL statement <code>SET MODE MSSQLServer</code>.
That means only one row with <code>NULL</code> in one of the columns is allowed. That means only one row with <code>NULL</code> in one of the columns is allowed.
</li><li>Concatenating <code>NULL</code> with another value </li><li>Concatenating <code>NULL</code> with another value
results in the other value. results in the other value.
</li><li>Text can be concatenated using '+'.
</li></ul> </li></ul>
<h3>MySQL Compatibility Mode</h3> <h3>MySQL Compatibility Mode</h3>
......
...@@ -36,6 +36,7 @@ See also <a href="build.html#providing_patches">Providing Patches</a>. ...@@ -36,6 +36,7 @@ See also <a href="build.html#providing_patches">Providing Patches</a>.
</li><li>MVCC: select for update should only lock the selected rows. </li><li>MVCC: select for update should only lock the selected rows.
</li><li>Option to shutdown all the running servers (on the same VM). </li><li>Option to shutdown all the running servers (on the same VM).
</li><li>Full outer joins. </li><li>Full outer joins.
</li><li>Support nested outer joins (see todo.txt).
</li><li>Automatic collection of statistics (auto ANALYZE; AUTOVACUUM). See http://www.postgresql.org/docs/current/static/routine-vacuuming.html#AUTOVACUUM </li><li>Automatic collection of statistics (auto ANALYZE; AUTOVACUUM). See http://www.postgresql.org/docs/current/static/routine-vacuuming.html#AUTOVACUUM
</li><li>Support mixed clustering mode (one embedded, others in server mode). </li><li>Support mixed clustering mode (one embedded, others in server mode).
</li><li>PostgreSQL catalog: use BEFORE SELECT triggers instead of views over metadata tables. </li><li>PostgreSQL catalog: use BEFORE SELECT triggers instead of views over metadata tables.
...@@ -54,7 +55,6 @@ See also <a href="build.html#providing_patches">Providing Patches</a>. ...@@ -54,7 +55,6 @@ See also <a href="build.html#providing_patches">Providing Patches</a>.
</li><li>Rebuild index functionality to shrink index size and improve performance. </li><li>Rebuild index functionality to shrink index size and improve performance.
</li><li>Don't use deleteOnExit (bug 4513817: File.deleteOnExit consumes memory). </li><li>Don't use deleteOnExit (bug 4513817: File.deleteOnExit consumes memory).
</li><li>Console: add accesskey to most important commands (A, AREA, BUTTON, INPUT, LABEL, LEGEND, TEXTAREA). </li><li>Console: add accesskey to most important commands (A, AREA, BUTTON, INPUT, LABEL, LEGEND, TEXTAREA).
</li><li>Support nested outer joins (see todo.txt).
</li><li>Test performance again with SQL Server, Oracle, DB2. </li><li>Test performance again with SQL Server, Oracle, DB2.
</li><li>Test with dbmonster: http://dbmonster.kernelpanic.pl </li><li>Test with dbmonster: http://dbmonster.kernelpanic.pl
</li><li>Test with dbcopy: http://dbcopyplugin.sourceforge.net </li><li>Test with dbcopy: http://dbcopyplugin.sourceforge.net
...@@ -127,7 +127,6 @@ See also <a href="build.html#providing_patches">Providing Patches</a>. ...@@ -127,7 +127,6 @@ See also <a href="build.html#providing_patches">Providing Patches</a>.
</li><li>Default date format for input and output (local date constants). </li><li>Default date format for input and output (local date constants).
</li><li>Support custom Collators. </li><li>Support custom Collators.
</li><li>Document ROWNUM usage for reports: SELECT ROWNUM, * FROM (subquery). </li><li>Document ROWNUM usage for reports: SELECT ROWNUM, * FROM (subquery).
</li><li>MS SQL Server compatibility: support string concatenation using +: 1+'2'=3, '1'+'2'='12'
</li><li>Clustering: when a database is back alive, automatically synchronize with the master. </li><li>Clustering: when a database is back alive, automatically synchronize with the master.
</li><li>File system that writes to two file systems (replication, replicating file system). </li><li>File system that writes to two file systems (replication, replicating file system).
</li><li>Standalone tool to get relevant system properties and add it to the trace output. </li><li>Standalone tool to get relevant system properties and add it to the trace output.
...@@ -477,6 +476,8 @@ See also <a href="build.html#providing_patches">Providing Patches</a>. ...@@ -477,6 +476,8 @@ See also <a href="build.html#providing_patches">Providing Patches</a>.
</li><li>Optimizer: WHERE X=? AND Y IN(?), it always uses the index on Y. Should be cost based. </li><li>Optimizer: WHERE X=? AND Y IN(?), it always uses the index on Y. Should be cost based.
</li><li>Support ALTER SCHEMA name RENAME TO newName (rename schema). </li><li>Support ALTER SCHEMA name RENAME TO newName (rename schema).
</li><li>Make the cache scan resistant (currently a small cache is faster than a large cache for large table scans). </li><li>Make the cache scan resistant (currently a small cache is faster than a large cache for large table scans).
</li><li>Issue 178: Optimizer: index usage when both ascending and descending indexes are available
</li><li>Issue 179: Related subqueries in HAVING clause
</li></ul> </li></ul>
<h2>Not Planned</h2> <h2>Not Planned</h2>
......
...@@ -103,6 +103,11 @@ public class Mode { ...@@ -103,6 +103,11 @@ public class Mode {
*/ */
public boolean uniqueIndexSingleNullExceptAllColumnsAreNull; public boolean uniqueIndexSingleNullExceptAllColumnsAreNull;
/**
* Text can be concatenated using '+'.
*/
public boolean allowPlusForStringConcat;
private String name; private String name;
static { static {
...@@ -126,12 +131,14 @@ public class Mode { ...@@ -126,12 +131,14 @@ public class Mode {
mode.convertOnlyToSmallerScale = true; mode.convertOnlyToSmallerScale = true;
mode.nullConcatIsNull = true; mode.nullConcatIsNull = true;
mode.uniqueIndexSingleNull = true; mode.uniqueIndexSingleNull = true;
mode.allowPlusForStringConcat = true;
add(mode); add(mode);
mode = new Mode("MSSQLServer"); mode = new Mode("MSSQLServer");
mode.aliasColumnName = true; mode.aliasColumnName = true;
mode.squareBracketQuotedNames = true; mode.squareBracketQuotedNames = true;
mode.uniqueIndexSingleNull = true; mode.uniqueIndexSingleNull = true;
mode.allowPlusForStringConcat = true;
add(mode); add(mode);
mode = new Mode("MySQL"); mode = new Mode("MySQL");
......
...@@ -12,6 +12,7 @@ import org.h2.message.DbException; ...@@ -12,6 +12,7 @@ import org.h2.message.DbException;
import org.h2.table.ColumnResolver; import org.h2.table.ColumnResolver;
import org.h2.table.TableFilter; import org.h2.table.TableFilter;
import org.h2.util.MathUtils; import org.h2.util.MathUtils;
import org.h2.value.DataType;
import org.h2.value.Value; import org.h2.value.Value;
import org.h2.value.ValueNull; import org.h2.value.ValueNull;
import org.h2.value.ValueString; import org.h2.value.ValueString;
...@@ -171,9 +172,14 @@ public class Operation extends Expression { ...@@ -171,9 +172,14 @@ public class Operation extends Expression {
int l = left.getType(); int l = left.getType();
int r = right.getType(); int r = right.getType();
if ((l == Value.NULL && r == Value.NULL) || (l == Value.UNKNOWN && r == Value.UNKNOWN)) { if ((l == Value.NULL && r == Value.NULL) || (l == Value.UNKNOWN && r == Value.UNKNOWN)) {
// example: (? + ?) - the most safe data type is probably // (? + ?) - use decimal by default (the most safe data type) or
// decimal // string when text concatenation with + is enabled
if (opType == PLUS && session.getDatabase().getMode().allowPlusForStringConcat) {
dataType = Value.STRING;
opType = CONCAT;
} else {
dataType = Value.DECIMAL; dataType = Value.DECIMAL;
}
} else if (l == Value.DATE || l == Value.TIMESTAMP) { } else if (l == Value.DATE || l == Value.TIMESTAMP) {
if (r == Value.INT && (opType == PLUS || opType == MINUS)) { if (r == Value.INT && (opType == PLUS || opType == MINUS)) {
// Oracle date add // Oracle date add
...@@ -198,6 +204,9 @@ public class Operation extends Expression { ...@@ -198,6 +204,9 @@ public class Operation extends Expression {
} }
} else { } else {
dataType = Value.getHigherOrder(l, r); dataType = Value.getHigherOrder(l, r);
if (DataType.isStringType(dataType) && session.getDatabase().getMode().allowPlusForStringConcat) {
opType = CONCAT;
}
} }
break; break;
default: default:
......
...@@ -925,6 +925,19 @@ public class DataType { ...@@ -925,6 +925,19 @@ public class DataType {
return false; return false;
} }
/**
* Check if the given value type is a String (VARCHAR,...).
*
* @param type the value type
* @return true if the value type is a String type
*/
public static boolean isStringType(int type) {
if (type == Value.STRING || type == Value.STRING_FIXED || type == Value.STRING_IGNORECASE) {
return true;
}
return false;
}
/** /**
* Check if the given value type supports the add operation. * Check if the given value type supports the add operation.
* *
......
...@@ -40,6 +40,7 @@ public class TestCompatibility extends TestBase { ...@@ -40,6 +40,7 @@ public class TestCompatibility extends TestBase {
testUniqueIndexOracle(); testUniqueIndexOracle();
testHsqlDb(); testHsqlDb();
testMySQL(); testMySQL();
testPlusSignAsConcatOperator();
conn.close(); conn.close();
deleteDb("compatibility"); deleteDb("compatibility");
...@@ -162,4 +163,49 @@ public class TestCompatibility extends TestBase { ...@@ -162,4 +163,49 @@ public class TestCompatibility extends TestBase {
} }
private void testPlusSignAsConcatOperator() throws SQLException {
Statement stat = conn.createStatement();
stat.execute("SET MODE MSSQLServer");
stat.execute("DROP TABLE IF EXISTS TEST");
stat.execute("CREATE TABLE TEST(NAME VARCHAR(50), SURNAME VARCHAR(50))");
stat.execute("INSERT INTO TEST VALUES('John', 'Doe')");
stat.execute("INSERT INTO TEST VALUES('Jack', 'Sullivan')");
assertResult("abcd123", stat, "SELECT 'abc' + 'd123'");
assertResult("Doe, John", stat,
"SELECT surname + ', ' + name FROM test WHERE SUBSTRING(NAME,1,1)+SUBSTRING(SURNAME,1,1) = 'JD'");
stat.execute("ALTER TABLE TEST ADD COLUMN full_name VARCHAR(100)");
stat.execute("UPDATE TEST SET full_name = name + ', ' + surname");
assertResult("John, Doe", stat, "SELECT full_name FROM TEST where name='John'");
PreparedStatement prep = conn.prepareStatement("INSERT INTO TEST VALUES(?, ?, ? + ', ' + ?)");
int ca = 1;
prep.setString(ca++, "Paul");
prep.setString(ca++, "Frank");
prep.setString(ca++, "Paul");
prep.setString(ca++, "Frank");
prep.executeUpdate();
prep.close();
assertResult("Paul, Frank", stat, "SELECT full_name FROM test WHERE name = 'Paul'");
prep = conn.prepareStatement("SELECT ? + ?");
int cb = 1;
prep.setString(cb++, "abcd123");
prep.setString(cb++, "d123");
prep.executeQuery();
prep.close();
prep = conn.prepareStatement("SELECT full_name FROM test WHERE (SUBSTRING(name, 1, 1) + SUBSTRING(surname, 2, 3)) = ?");
prep.setString(1, "Joe");
ResultSet res = prep.executeQuery();
assertTrue("Result cannot be empty", res.next());
assertEquals("John, Doe", res.getString(1));
res.close();
prep.close();
}
} }
...@@ -639,4 +639,4 @@ census genealogy scapegoat gov compacted migrating dies typtypmod latch await ...@@ -639,4 +639,4 @@ census genealogy scapegoat gov compacted migrating dies typtypmod latch await
counting dtest fallback infix places formal extern destination stdout memmove counting dtest fallback infix places formal extern destination stdout memmove
stdio printf jchar sizeof stdlib jbyte jint uint ujlong typedef jdouble stdint stdio printf jchar sizeof stdlib jbyte jint uint ujlong typedef jdouble stdint
jfloat wchar hotspot jvoid std ujint jlong vars jboolean calloc argc strlen jfloat wchar hotspot jvoid std ujint jlong vars jboolean calloc argc strlen
equivalent synchronizes equivalent synchronizes sullivan surname doe stepan
\ No newline at end of file \ No newline at end of file
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论