From b0da0a5a31c9df42890969de7117c8d1c9864733 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Mon, 3 Nov 2025 10:36:09 +0100 Subject: [PATCH] Apply type casting and implicit defaults to ON DUPLICATE KEY UPDATE clause --- tests/WP_SQLite_Driver_Tests.php | 19 ++++++++++ .../sqlite-ast/class-wp-sqlite-driver.php | 38 +++++++++++-------- 2 files changed, 41 insertions(+), 16 deletions(-) diff --git a/tests/WP_SQLite_Driver_Tests.php b/tests/WP_SQLite_Driver_Tests.php index 0ef6e2f0..4bacfcd8 100644 --- a/tests/WP_SQLite_Driver_Tests.php +++ b/tests/WP_SQLite_Driver_Tests.php @@ -10522,6 +10522,25 @@ public function testCastValuesOnInsertInNonStrictMode(): void { $this->assertQuery( 'DROP TABLE t' ); } + public function testCastValuesOnDuplicateKeyUpdate(): void { + $this->assertQuery( 'CREATE TABLE t (value TEXT UNIQUE)' ); + $this->assertQuery( "INSERT INTO t VALUES ('test')" ); + + // Ensure that type casting is applied to ON DUPLICATE KEY UPDATE clause. + $this->assertQuery( "INSERT INTO t VALUES ('test') ON DUPLICATE KEY UPDATE value = 0x61" ); + $this->assertSame( 'a', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); + } + + public function testCastValuesOnDuplicateKeyUpdateInNonStrictMode(): void { + $this->assertQuery( "SET SESSION sql_mode = ''" ); + $this->assertQuery( 'CREATE TABLE t (value INT UNIQUE)' ); + $this->assertQuery( 'INSERT INTO t VALUES (123)' ); + + // Ensure that type casting is applied to ON DUPLICATE KEY UPDATE clause. + $this->assertQuery( "INSERT INTO t VALUES (123) ON DUPLICATE KEY UPDATE value = 'test'" ); + $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); + } + public function testCastValuesOnUpdate(): void { // INTEGER $this->assertQuery( 'CREATE TABLE t (value INT)' ); diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 25147987..0504baa8 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -1531,6 +1531,10 @@ private function execute_insert_or_replace_statement( WP_Parser_Node $node ): vo $table_ref = $node->get_first_child_node( 'tableRef' ); $table_name = $this->unquote_sqlite_identifier( $this->translate( $table_ref ) ); $parts[] = $this->translate_insert_or_replace_body( $table_name, $child ); + } elseif ( $is_node && 'insertUpdateList' === $child->rule_name ) { + // Translate "ON DUPLICATE KEY UPDATE" to "ON CONFLICT DO UPDATE SET". + $parts[] = 'ON CONFLICT DO UPDATE SET '; + $parts[] = $this->translate_update_list( $table_name, $child ); } else { $parts[] = $this->translate( $child ); } @@ -1737,7 +1741,7 @@ private function execute_update_statement( WP_Parser_Node $node ): void { } // Translate UPDATE list, applying relevant type casting and IMPLICIT DEFAULT values. - $update_list = $this->translate_update_list( $update_target_table, $update_list_node ); + $update_list = $this->translate_update_list( $update_target_table, $node ); // Translate WHERE, ORDER BY, and LIMIT clauses. if ( $where_subquery ) { @@ -3241,12 +3245,6 @@ private function translate( $node ): ?string { return null; } return $this->translate_sequence( $node->get_children() ); - case 'insertUpdateList': - // Translate "ON DUPLICATE KEY UPDATE" to "ON CONFLICT DO UPDATE SET". - return sprintf( - 'ON CONFLICT DO UPDATE SET %s', - $this->translate( $node->get_first_child_node( 'updateList' ) ) - ); case 'simpleExpr': return $this->translate_simple_expr( $node ); case 'predicateOperations': @@ -4649,11 +4647,13 @@ function ( $column ) use ( $is_strict_mode, $insert_map ) { * For more information about IMPLICIT DEFAULT values in MySQL, see: * https://dev.mysql.com/doc/refman/8.4/en/data-type-defaults.html#data-type-defaults-implicit * - * @param string $table_name The name of the target table. - * @param WP_Parser_Node $node The "updateList" AST node. - * @return string The translated UPDATE list. + * @param string $table_name The name of the target table. + * @param WP_Parser_Node $parent_node The "updateList" AST node parent node. + * @return string The translated UPDATE list. */ - private function translate_update_list( string $table_name, WP_Parser_Node $node ): string { + private function translate_update_list( string $table_name, WP_Parser_Node $parent_node ): string { + $node = $parent_node->get_first_child_node( 'updateList' ); + // This method is always used with the main database. $database = $this->get_saved_db_name( $this->main_db_name ); @@ -4724,11 +4724,17 @@ private function translate_update_list( string $table_name, WP_Parser_Node $node // Apply type casting. $value = $this->cast_value_for_saving( $data_type, $value ); - // In MySQL non-STRICT mode, when a column is declared as NOT NULL, - // updating to a NULL value saves an IMPLICIT DEFAULT value instead. - $implicit_default = self::DATA_TYPE_IMPLICIT_DEFAULT_MAP[ $data_type ] ?? null; - if ( ! $is_strict_mode && ! $is_nullable && null !== $implicit_default ) { - $value = sprintf( 'COALESCE(%s, %s)', $value, $this->connection->quote( $implicit_default ) ); + /* + * 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 ) ); + } } // Compose the UPDATE list item.