Skip to content

Commit 2c973d4

Browse files
authored
Fix INSERT ... SELECT ... edge case in non-strict mode (#285)
In MySQL non-STRICT mode, when inserting from a `SELECT` query: When a column is declared as `NOT NULL`, inserting a `NULL` value saves an IMPLICIT DEFAULT value instead. This behavior only applies to the `INSERT ... SELECT` syntax (not `VALUES` or `SET`). In other words: ```sql CREATE TABLE t (value INT NOT NULL); -- Strict mode: INSERT INTO t VALUES (NULL); -- error INSERT INTO t SET value = NULL; -- error INSERT INTO t SELECT NULL; -- error INSERT INTO t VALUES ((SELECT NULL)); -- error -- Non-strict mode: INSERT INTO t VALUES (NULL); -- error INSERT INTO t SET value = NULL; -- error INSERT INTO t SELECT NULL; -- OK, saves 0 (the implicit default for integer) INSERT INTO t VALUES ((SELECT NULL)); -- error ``` This fixes some failures in the activation of the top 100 plugins.
2 parents 1754169 + eddd736 commit 2c973d4

File tree

2 files changed

+53
-1
lines changed

2 files changed

+53
-1
lines changed

tests/WP_SQLite_Driver_Tests.php

Lines changed: 36 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -10539,6 +10539,42 @@ public function testCastValuesOnInsertInNonStrictMode(): void {
1053910539
$this->assertQuery( 'DROP TABLE t' );
1054010540
}
1054110541

10542+
public function testCastNotNullValuesOnInsert(): void {
10543+
$this->assertQuery( 'CREATE TABLE t (value INT NOT NULL)' );
10544+
10545+
// Strict mode:
10546+
$this->assertQueryError( 'INSERT INTO t VALUES (NULL)', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
10547+
$this->assertQueryError( 'INSERT INTO t SET value = NULL', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
10548+
$this->assertQueryError( 'INSERT INTO t SELECT NULL', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
10549+
$this->assertQueryError( 'INSERT INTO t VALUES ((SELECT NULL))', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
10550+
10551+
// Non-strict mode:
10552+
$this->assertQuery( "SET SESSION sql_mode = ''" );
10553+
$this->assertQueryError( 'INSERT INTO t VALUES (NULL)', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
10554+
$this->assertQueryError( 'INSERT INTO t SET value = NULL', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
10555+
$this->assertQuery( 'INSERT INTO t SELECT NULL' );
10556+
$this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
10557+
$this->assertQueryError( 'INSERT INTO t VALUES ((SELECT NULL))', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
10558+
}
10559+
10560+
public function testCastNotNullValuesOnUpdate(): void {
10561+
$this->assertQuery( 'CREATE TABLE t (value INT NOT NULL)' );
10562+
$this->assertQuery( 'INSERT INTO t VALUES (1)' );
10563+
10564+
// Strict mode:
10565+
$this->assertQueryError( 'UPDATE t SET value = NULL', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
10566+
$this->assertQueryError( 'UPDATE t SET value = (SELECT NULL)', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
10567+
10568+
// Non-strict mode:
10569+
$this->assertQuery( "SET SESSION sql_mode = ''" );
10570+
$this->assertQuery( 'UPDATE t SET value = NULL' );
10571+
$this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
10572+
10573+
$this->assertQuery( 'UPDATE t SET value = (SELECT NULL)' );
10574+
$this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
10575+
$this->assertQuery( 'DROP TABLE t' );
10576+
}
10577+
1054210578
public function testCastValuesOnDuplicateKeyUpdate(): void {
1054310579
$this->assertQuery( 'CREATE TABLE t (value TEXT UNIQUE)' );
1054410580
$this->assertQuery( "INSERT INTO t VALUES ('test')" );

wp-includes/sqlite-ast/class-wp-sqlite-driver.php

Lines changed: 17 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -4594,7 +4594,23 @@ function ( $column ) use ( $is_strict_mode, $insert_map ) {
45944594
// When a column value is included, we need to apply type casting.
45954595
$position = array_search( $column['COLUMN_NAME'], $insert_list, true );
45964596
$identifier = $this->quote_sqlite_identifier( $select_list[ $position ] );
4597-
$fragment .= $this->cast_value_for_saving( $column['DATA_TYPE'], $identifier );
4597+
$value = $this->cast_value_for_saving( $column['DATA_TYPE'], $identifier );
4598+
4599+
/*
4600+
* In MySQL non-STRICT mode, when inserting from a SELECT query:
4601+
*
4602+
* When a column is declared as NOT NULL, inserting a NULL value
4603+
* saves an IMPLICIT DEFAULT value instead. This behavior only
4604+
* applies to the INSERT ... SELECT syntax (not VALUES or SET).
4605+
*/
4606+
$is_insert_from_select = 'insertQueryExpression' === $node->rule_name;
4607+
if ( ! $is_strict_mode && $is_insert_from_select && 'NO' === $column['IS_NULLABLE'] ) {
4608+
$implicit_default = self::DATA_TYPE_IMPLICIT_DEFAULT_MAP[ $column['DATA_TYPE'] ] ?? null;
4609+
if ( null !== $implicit_default ) {
4610+
$value = sprintf( 'COALESCE(%s, %s)', $value, $this->connection->quote( $implicit_default ) );
4611+
}
4612+
}
4613+
$fragment .= $value;
45984614
}
45994615
}
46004616

0 commit comments

Comments
 (0)