Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
36 changes: 36 additions & 0 deletions tests/WP_SQLite_Driver_Tests.php
Original file line number Diff line number Diff line change
Expand Up @@ -10526,6 +10526,42 @@ public function testCastValuesOnInsertInNonStrictMode(): void {
$this->assertQuery( 'DROP TABLE t' );
}

public function testCastNotNullValuesOnInsert(): void {
$this->assertQuery( 'CREATE TABLE t (value INT NOT NULL)' );

// Strict mode:
$this->assertQueryError( 'INSERT INTO t VALUES (NULL)', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
$this->assertQueryError( 'INSERT INTO t SET value = NULL', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
$this->assertQueryError( 'INSERT INTO t SELECT NULL', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
$this->assertQueryError( 'INSERT INTO t VALUES ((SELECT NULL))', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );

// Non-strict mode:
$this->assertQuery( "SET SESSION sql_mode = ''" );
$this->assertQueryError( 'INSERT INTO t VALUES (NULL)', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
$this->assertQueryError( 'INSERT INTO t SET value = NULL', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
$this->assertQuery( 'INSERT INTO t SELECT NULL' );
$this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
$this->assertQueryError( 'INSERT INTO t VALUES ((SELECT NULL))', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
}

public function testCastNotNullValuesOnUpdate(): void {
$this->assertQuery( 'CREATE TABLE t (value INT NOT NULL)' );
$this->assertQuery( 'INSERT INTO t VALUES (1)' );

// Strict mode:
$this->assertQueryError( 'UPDATE t SET value = NULL', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );
$this->assertQueryError( 'UPDATE t SET value = (SELECT NULL)', 'SQLSTATE[23000]: Integrity constraint violation: 19 NOT NULL constraint failed: t.value' );

// Non-strict mode:
$this->assertQuery( "SET SESSION sql_mode = ''" );
$this->assertQuery( 'UPDATE t SET value = NULL' );
$this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );

$this->assertQuery( 'UPDATE t SET value = (SELECT NULL)' );
$this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
$this->assertQuery( 'DROP TABLE t' );
}

public function testCastValuesOnDuplicateKeyUpdate(): void {
$this->assertQuery( 'CREATE TABLE t (value TEXT UNIQUE)' );
$this->assertQuery( "INSERT INTO t VALUES ('test')" );
Expand Down
18 changes: 17 additions & 1 deletion wp-includes/sqlite-ast/class-wp-sqlite-driver.php
Original file line number Diff line number Diff line change
Expand Up @@ -4580,7 +4580,23 @@ function ( $column ) use ( $is_strict_mode, $insert_map ) {
// When a column value is included, we need to apply type casting.
$position = array_search( $column['COLUMN_NAME'], $insert_list, true );
$identifier = $this->quote_sqlite_identifier( $select_list[ $position ] );
$fragment .= $this->cast_value_for_saving( $column['DATA_TYPE'], $identifier );
$value = $this->cast_value_for_saving( $column['DATA_TYPE'], $identifier );

/*
* 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).
*/
$is_insert_from_select = 'insertQueryExpression' === $node->rule_name;
if ( ! $is_strict_mode && $is_insert_from_select && 'NO' === $column['IS_NULLABLE'] ) {
$implicit_default = self::DATA_TYPE_IMPLICIT_DEFAULT_MAP[ $column['DATA_TYPE'] ] ?? null;
if ( null !== $implicit_default ) {
$value = sprintf( 'COALESCE(%s, %s)', $value, $this->connection->quote( $implicit_default ) );
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Is that SQLite coalesce? Will it give us the result we need?

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@adamziel Yes. There is a very similar logic for UPDATE SET ... = NULL already:

/*
* In MySQL non-STRICT mode, when a column is declared as NOT NULL,
* updating to a NULL value saves an IMPLICIT DEFAULT value instead.
* This behavior does not apply to ON DUPLICATE KEY UPDATE clauses.
*/
$is_on_duplicate_key_update = 'insertUpdateList' === $parent_node->rule_name;
if ( ! $is_strict_mode && ! $is_nullable && ! $is_on_duplicate_key_update ) {
$implicit_default = self::DATA_TYPE_IMPLICIT_DEFAULT_MAP[ $data_type ] ?? null;
if ( null !== $implicit_default ) {
$value = sprintf( 'COALESCE(%s, %s)', $value, $this->connection->quote( $implicit_default ) );
}
}

}
}
$fragment .= $value;
}
}

Expand Down
Loading