Skip to content

Commit

Permalink
Ignore explicit MySqlDbType for prepared statements. Fixes #659
Browse files Browse the repository at this point in the history
MySQL Server can't actually process many MySqlDbType column types directly as parameters to a prepared statement, so we now just ignore all explicit types and use inferred types. This fixes MySqlDbType.JSON, MySqlDbType.Year, and MySqlDbType.Int24, among others.
  • Loading branch information
bgrainger committed Jun 25, 2019
1 parent 926753a commit ce16109
Show file tree
Hide file tree
Showing 4 changed files with 109 additions and 36 deletions.
10 changes: 6 additions & 4 deletions docs/content/tutorials/migrating-from-connector-net.md
Expand Up @@ -119,14 +119,14 @@ The following bugs in Connector/NET are fixed by switching to MySqlConnector. (~
* [#73610](https://bugs.mysql.com/bug.php?id=73610): Invalid password exception has wrong number
* [#73788](https://bugs.mysql.com/bug.php?id=73788): Can’t use `DateTimeOffset`
* [#75604](https://bugs.mysql.com/bug.php?id=75604): Crash after 29.4 days of uptime
* [#75917](https://bugs.mysql.com/bug.php?id=75917), [#76597](https://bugs.mysql.com/bug.php?id=76597), [#77691](https://bugs.mysql.com/bug.php?id=77691), [#78650](https://bugs.mysql.com/bug.php?id=78650), [#78919](https://bugs.mysql.com/bug.php?id=78919), [#80921](https://bugs.mysql.com/bug.php?id=80921), [#82136](https://bugs.mysql.com/bug.php?id=82136): "Reading from the stream has failed" when connecting to a server
* [#75917](https://bugs.mysql.com/bug.php?id=75917), [#76597](https://bugs.mysql.com/bug.php?id=76597), [#77691](https://bugs.mysql.com/bug.php?id=77691), [#78650](https://bugs.mysql.com/bug.php?id=78650), [#78919](https://bugs.mysql.com/bug.php?id=78919), [#80921](https://bugs.mysql.com/bug.php?id=80921), [#82136](https://bugs.mysql.com/bug.php?id=82136): Reading from the stream has failed when connecting to a server
* [#77421](https://bugs.mysql.com/bug.php?id=77421): Connection is not reset when pulled from the connection pool
* [#78426](https://bugs.mysql.com/bug.php?id=78426): Unknown database exception has wrong number
* [#78760](https://bugs.mysql.com/bug.php?id=78760): Error when using tabs and newlines in SQL statements
* ~~[#78917](https://bugs.mysql.com/bug.php?id=78917), [#79196](https://bugs.mysql.com/bug.php?id=79196), [#82292](https://bugs.mysql.com/bug.php?id=82292), [#89040](https://bugs.mysql.com/bug.php?id=89040): `TINYINT(1)` values start being returned as `sbyte` after `NULL`~~
* ~~[#80030](https://bugs.mysql.com/bug.php?id=80030): Slow to connect with pooling disabled~~
* [#81650](https://bugs.mysql.com/bug.php?id=81650), [#88962](https://bugs.mysql.com/bug.php?id=88962): `Server` connection string option may now contain multiple, comma separated hosts that will be tried in order until a connection succeeds
* [#83229](https://bugs.mysql.com/bug.php?id=83329): "Unknown command" exception inserting large blob with UseCompression=True
* [#83229](https://bugs.mysql.com/bug.php?id=83329): Unknown command exception inserting large blob with UseCompression=True
* [#84220](https://bugs.mysql.com/bug.php?id=84220): Cannot call a stored procedure with `.` in its name
* [#84701](https://bugs.mysql.com/bug.php?id=84701): Can’t create a parameter using a 64-bit enum with a value greater than int.MaxValue
* [#85185](https://bugs.mysql.com/bug.php?id=85185): `ConnectionReset=True` does not preserve connection charset
Expand All @@ -138,7 +138,7 @@ The following bugs in Connector/NET are fixed by switching to MySqlConnector. (~
* ~~[#88058](https://bugs.mysql.com/bug.php?id=88058): `decimal(n, 0)` has wrong `NumericPrecision`~~
* [#88124](https://bugs.mysql.com/bug.php?id=88124): CommandTimeout isn’t reset when calling Read/NextResult
* ~~[#88472](https://bugs.mysql.com/bug.php?id=88472): `TINYINT(1)` is not returned as `bool` if `MySqlCommand.Prepare` is called~~
* [#88611](https://bugs.mysql.com/bug.php?id=88611): `MySqlCommand` can be executed even if it has "wrong" transaction
* [#88611](https://bugs.mysql.com/bug.php?id=88611): `MySqlCommand` can be executed even if it has wrong transaction
* ~~[#88660](https://bugs.mysql.com/bug.php?id=88660): `MySqlClientFactory.Instance.CreateDataAdapter()` and `CreateCommandBuilder` return `null`~~
* [#89085](https://bugs.mysql.com/bug.php?id=89085): `MySqlConnection.Database` not updated after `USE database;`
* [#89159](https://bugs.mysql.com/bug.php?id=89159): `MySqlDataReader` cannot outlive `MySqlCommand`
Expand All @@ -152,7 +152,7 @@ The following bugs in Connector/NET are fixed by switching to MySqlConnector. (~
* [#91754](https://bugs.mysql.com/bug.php?id=91754): Inserting 16MiB `BLOB` shifts it by four bytes when prepared
* [#91770](https://bugs.mysql.com/bug.php?id=91770): `TIME(n)` column loses microseconds with prepared command
* [#92367](https://bugs.mysql.com/bug.php?id=92367): `MySqlDataReader.GetDateTime` and `GetValue` return inconsistent values
* [#92465](https://bugs.mysql.com/bug.php?id=92465): "There is already an open DataReader" `MySqlException` thrown from `TransactionScope.Dispose`
* [#92465](https://bugs.mysql.com/bug.php?id=92465): There is already an open DataReader `MySqlException` thrown from `TransactionScope.Dispose`
* [#92734](https://bugs.mysql.com/bug.php?id=92734): `MySqlParameter.Clone` doesn't copy all property values
* [#92789](https://bugs.mysql.com/bug.php?id=92789): Illegal connection attributes written for non-ASCII values
* ~~[#92912](https://bugs.mysql.com/bug.php?id=92912): `MySqlDbType.LongText` values encoded incorrectly with prepared statements~~
Expand All @@ -167,3 +167,5 @@ The following bugs in Connector/NET are fixed by switching to MySqlConnector. (~
* [#94760](https://bugs.mysql.com/bug.php?id=94760): `MySqlConnection.OpenAsync(CancellationToken)` doesn’t respect cancellation token
* [#95348](https://bugs.mysql.com/bug.php?id=95348): Inefficient query when executing stored procedures
* [#95436](https://bugs.mysql.com/bug.php?id=95436): Client doesn't authenticate with PEM certificate
* [#95984](https://bugs.mysql.com/bug.php?id=95984): “Incorrect arguments to mysqld_stmt_execute” using prepared statement with `MySqlDbType.JSON`
* [#95986](https://bugs.mysql.com/bug.php?id=95986): “Incorrect integer value” using prepared statement with `MySqlDbType.Int24`
13 changes: 12 additions & 1 deletion src/MySqlConnector/Core/SingleCommandPayloadCreator.cs
Expand Up @@ -98,7 +98,18 @@ private void WritePreparedStatement(IMySqlCommand command, PreparedStatement pre
writer.Write((byte) 1);

foreach (var parameter in parameters)
writer.Write(TypeMapper.ConvertToColumnTypeAndFlags(parameter.MySqlDbType, command.Connection.GuidFormat));
{
// override explicit MySqlDbType with inferred type from the Value
var mySqlDbType = parameter.MySqlDbType;
var typeMapping = (parameter.Value is null || parameter.Value == DBNull.Value) ? null : TypeMapper.Instance.GetDbTypeMapping(parameter.Value.GetType());
if (typeMapping is object)
{
var dbType = typeMapping.DbTypes[0];
mySqlDbType = TypeMapper.Instance.GetMySqlDbTypeForDbType(dbType);
}

writer.Write(TypeMapper.ConvertToColumnTypeAndFlags(mySqlDbType, command.Connection.GuidFormat));
}

var options = command.CreateStatementPreparerOptions();
foreach (var parameter in parameters)
Expand Down
4 changes: 4 additions & 0 deletions src/MySqlConnector/Core/TypeMapper.cs
Expand Up @@ -419,6 +419,10 @@ public static ushort ConvertToColumnTypeAndFlags(MySqlDbType dbType, MySqlGuidFo
columnType = ColumnType.Geometry;
break;

case MySqlDbType.Null:
columnType = ColumnType.Null;
break;

default:
throw new NotImplementedException("ConvertToColumnTypeAndFlags for {0} is not implemented".FormatInvariant(dbType));
}
Expand Down
118 changes: 87 additions & 31 deletions tests/SideBySide/PreparedCommandTests.cs
Expand Up @@ -88,7 +88,7 @@ public void ReuseCommand()

[Theory]
[MemberData(nameof(GetInsertAndQueryData))]
public void InsertAndQuery(bool isPrepared, string dataType, object dataValue)
public void InsertAndQuery(bool isPrepared, string dataType, object dataValue, MySqlDbType dbType)
{
var csb = new MySqlConnectionStringBuilder(AppConfig.ConnectionString)
{
Expand All @@ -100,6 +100,53 @@ public void InsertAndQuery(bool isPrepared, string dataType, object dataValue)
connection.Execute($@"DROP TABLE IF EXISTS prepared_command_test;
CREATE TABLE prepared_command_test(rowid INTEGER NOT NULL PRIMARY KEY AUTO_INCREMENT, data {dataType});");

using (var command = new MySqlCommand("INSERT INTO prepared_command_test(data) VALUES(@null), (@data);", connection))
{
command.Parameters.AddWithValue("@null", null);
command.Parameters.AddWithValue("@data", dataValue).MySqlDbType = dbType;
if (isPrepared)
command.Prepare();
Assert.Equal(isPrepared, command.IsPrepared);
command.ExecuteNonQuery();
}

using (var command = new MySqlCommand("SELECT data FROM prepared_command_test ORDER BY rowid;", connection))
{
if (isPrepared)
command.Prepare();
Assert.Equal(isPrepared, command.IsPrepared);

using (var reader = command.ExecuteReader())
{
Assert.True(reader.Read());
Assert.True(reader.IsDBNull(0));

Assert.True(reader.Read());
Assert.False(reader.IsDBNull(0));
Assert.Equal(dataValue, reader.GetValue(0));

Assert.False(reader.Read());
Assert.False(reader.NextResult());
}
}
}
}

[Theory]
[MemberData(nameof(GetInsertAndQueryData))]
public void InsertAndQueryInferrredType(bool isPrepared, string dataType, object dataValue, MySqlDbType dbType)
{
GC.KeepAlive(dbType); // ignore the parameter
var csb = new MySqlConnectionStringBuilder(AppConfig.ConnectionString)
{
IgnorePrepare = !isPrepared,
};
using (var connection = new MySqlConnection(csb.ConnectionString))
{
connection.Open();
connection.Execute($@"DROP TABLE IF EXISTS prepared_command_test;
CREATE TABLE prepared_command_test(rowid INTEGER NOT NULL PRIMARY KEY AUTO_INCREMENT, data {dataType});");

using (var command = new MySqlCommand("INSERT INTO prepared_command_test(data) VALUES(@null), (@data);", connection))
{
command.Parameters.AddWithValue("@null", null);
Expand Down Expand Up @@ -134,7 +181,7 @@ public void InsertAndQuery(bool isPrepared, string dataType, object dataValue)

[SkippableTheory(Baseline = "https://bugs.mysql.com/bug.php?id=14115")]
[MemberData(nameof(GetInsertAndQueryData))]
public void InsertAndQueryMultipleStatements(bool isPrepared, string dataType, object dataValue)
public void InsertAndQueryMultipleStatements(bool isPrepared, string dataType, object dataValue, MySqlDbType dbType)
{
var csb = new MySqlConnectionStringBuilder(AppConfig.ConnectionString)
{
Expand All @@ -151,7 +198,7 @@ public void InsertAndQueryMultipleStatements(bool isPrepared, string dataType, o
SELECT data FROM prepared_command_test ORDER BY rowid;", connection))
{
command.Parameters.AddWithValue("@null", null);
command.Parameters.AddWithValue("@data", dataValue);
command.Parameters.AddWithValue("@data", dataValue).MySqlDbType = dbType;
if (isPrepared)
command.Prepare();
Assert.Equal(isPrepared, command.IsPrepared);
Expand Down Expand Up @@ -348,42 +395,51 @@ public static IEnumerable<object[]> GetInsertAndQueryData()
{
foreach (var isPrepared in new[] { false, true })
{
yield return new object[] { isPrepared, "TINYINT", (sbyte) -123 };
yield return new object[] { isPrepared, "TINYINT UNSIGNED", (byte) 123 };
yield return new object[] { isPrepared, "SMALLINT", (short) -12345 };
yield return new object[] { isPrepared, "SMALLINT UNSIGNED", (ushort) 12345 };
yield return new object[] { isPrepared, "MEDIUMINT", -1234567 };
yield return new object[] { isPrepared, "MEDIUMINT UNSIGNED", 1234567u };
yield return new object[] { isPrepared, "INT", -123456789 };
yield return new object[] { isPrepared, "INT UNSIGNED", 123456789u };
yield return new object[] { isPrepared, "BIGINT", -1234567890123456789L };
yield return new object[] { isPrepared, "BIGINT UNSIGNED", 1234567890123456789UL };
yield return new object[] { isPrepared, "BIT(10)", 1000UL };
yield return new object[] { isPrepared, "BINARY(5)", new byte[] { 5, 6, 7, 8, 9 } };
yield return new object[] { isPrepared, "VARBINARY(100)", new byte[] { 7, 8, 9, 10 } };
yield return new object[] { isPrepared, "BLOB", new byte[] { 5, 4, 3, 2, 1 } };
yield return new object[] { isPrepared, "CHAR(36)", new Guid("00112233-4455-6677-8899-AABBCCDDEEFF") };
yield return new object[] { isPrepared, "FLOAT", 12.375f };
yield return new object[] { isPrepared, "DOUBLE", 14.21875 };
yield return new object[] { isPrepared, "DECIMAL(9,3)", 123.45m };
yield return new object[] { isPrepared, "VARCHAR(100)", "test;@'; -- " };
yield return new object[] { isPrepared, "TEXT", "testing testing" };
yield return new object[] { isPrepared, "DATE", new DateTime(2018, 7, 23) };
yield return new object[] { isPrepared, "DATETIME(3)", new DateTime(2018, 7, 23, 20, 46, 52, 123) };
yield return new object[] { isPrepared, "ENUM('small', 'medium', 'large')", "medium" };
yield return new object[] { isPrepared, "SET('one','two','four','eight')", "two,eight" };
yield return new object[] { isPrepared, "BOOL", true };
yield return new object[] { isPrepared, "TINYINT", (sbyte) -123, MySqlDbType.Byte };
yield return new object[] { isPrepared, "TINYINT UNSIGNED", (byte) 123, MySqlDbType.UByte };
yield return new object[] { isPrepared, "SMALLINT", (short) -12345, MySqlDbType.Int16 };
yield return new object[] { isPrepared, "SMALLINT UNSIGNED", (ushort) 12345, MySqlDbType.UInt16 };
#if !BASELINE
yield return new object[] { isPrepared, "MEDIUMINT", -1234567, MySqlDbType.Int24 };
#else
// https://bugs.mysql.com/bug.php?id=95986
yield return new object[] { isPrepared, "MEDIUMINT", -1234567, MySqlDbType.Int32 };
#endif
yield return new object[] { isPrepared, "MEDIUMINT UNSIGNED", 1234567u, MySqlDbType.UInt24 };
yield return new object[] { isPrepared, "INT", -123456789, MySqlDbType.Int32 };
yield return new object[] { isPrepared, "INT UNSIGNED", 123456789u, MySqlDbType.UInt32 };
yield return new object[] { isPrepared, "BIGINT", -1234567890123456789L, MySqlDbType.Int64 };
yield return new object[] { isPrepared, "BIGINT UNSIGNED", 1234567890123456789UL, MySqlDbType.UInt64 };
yield return new object[] { isPrepared, "BIT(10)", 1000UL, MySqlDbType.Bit };
yield return new object[] { isPrepared, "BINARY(5)", new byte[] { 5, 6, 7, 8, 9 }, MySqlDbType.Binary };
yield return new object[] { isPrepared, "VARBINARY(100)", new byte[] { 7, 8, 9, 10 }, MySqlDbType.VarBinary };
yield return new object[] { isPrepared, "BLOB", new byte[] { 5, 4, 3, 2, 1 }, MySqlDbType.Blob };
yield return new object[] { isPrepared, "CHAR(36)", new Guid("00112233-4455-6677-8899-AABBCCDDEEFF"), MySqlDbType.Guid };
yield return new object[] { isPrepared, "FLOAT", 12.375f, MySqlDbType.Float };
yield return new object[] { isPrepared, "DOUBLE", 14.21875, MySqlDbType.Double };
yield return new object[] { isPrepared, "DECIMAL(9,3)", 123.45m, MySqlDbType.Decimal };
yield return new object[] { isPrepared, "VARCHAR(100)", "test;@'; -- ", MySqlDbType.VarChar };
yield return new object[] { isPrepared, "TEXT", "testing testing", MySqlDbType.Text };
yield return new object[] { isPrepared, "DATE", new DateTime(2018, 7, 23), MySqlDbType.Date };
yield return new object[] { isPrepared, "DATETIME(3)", new DateTime(2018, 7, 23, 20, 46, 52, 123), MySqlDbType.DateTime };
yield return new object[] { isPrepared, "ENUM('small', 'medium', 'large')", "medium", MySqlDbType.Enum };
yield return new object[] { isPrepared, "SET('one','two','four','eight')", "two,eight", MySqlDbType.Set };
#if !BASELINE
yield return new object[] { isPrepared, "BOOL", true, MySqlDbType.Bool };
#else
yield return new object[] { isPrepared, "BOOL", true, MySqlDbType.Int32 };
#endif

#if !BASELINE
// https://bugs.mysql.com/bug.php?id=91770
yield return new object[] { isPrepared, "TIME(3)", TimeSpan.Zero.Subtract(new TimeSpan(15, 10, 34, 56, 789)) };
yield return new object[] { isPrepared, "TIME(3)", TimeSpan.Zero.Subtract(new TimeSpan(15, 10, 34, 56, 789)), MySqlDbType.Time };

// https://bugs.mysql.com/bug.php?id=91751
yield return new object[] { isPrepared, "YEAR", 2134 };
yield return new object[] { isPrepared, "YEAR", 2134, MySqlDbType.Year };
#endif

if (AppConfig.SupportsJson)
yield return new object[] { isPrepared, "JSON", "{\"test\": true}" };
yield return new object[] { isPrepared, "JSON", "{\"test\": true}", MySqlDbType.JSON };
}
}

Expand Down

0 comments on commit ce16109

Please sign in to comment.