diff --git a/tests/WP_SQLite_Driver_Query_Tests.php b/tests/WP_SQLite_Driver_Query_Tests.php
index 636813f5..073225af 100644
--- a/tests/WP_SQLite_Driver_Query_Tests.php
+++ b/tests/WP_SQLite_Driver_Query_Tests.php
@@ -2,6 +2,87 @@
use PHPUnit\Framework\TestCase;
+$tables = <<<'SQL'
+CREATE TABLE wp_users (
+ ID bigint(20) unsigned NOT NULL auto_increment,
+ user_login varchar(60) NOT NULL default '',
+ user_pass varchar(255) NOT NULL default '',
+ user_nicename varchar(50) NOT NULL default '',
+ user_email varchar(100) NOT NULL default '',
+ user_url varchar(100) NOT NULL default '',
+ user_registered datetime NOT NULL default '0000-00-00 00:00:00',
+ user_activation_key varchar(255) NOT NULL default '',
+ user_status int(11) NOT NULL default '0',
+ display_name varchar(250) NOT NULL default '',
+ PRIMARY KEY (ID),
+ KEY user_login_key (user_login),
+ KEY user_nicename (user_nicename),
+ KEY user_email (user_email)
+) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE wp_usermeta (
+ umeta_id bigint(20) unsigned NOT NULL auto_increment,
+ user_id bigint(20) unsigned NOT NULL default '0',
+ meta_key varchar(255) default NULL,
+ meta_value longtext,
+ PRIMARY KEY (umeta_id),
+ KEY user_id (user_id),
+ KEY meta_key (meta_key(191))
+) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE wp_posts (
+ ID bigint(20) unsigned NOT NULL auto_increment,
+ post_author bigint(20) unsigned NOT NULL default '0',
+ post_date datetime NOT NULL default '0000-00-00 00:00:00',
+ post_date_gmt datetime NOT NULL default '0000-00-00 00:00:00',
+ post_content longtext NOT NULL,
+ post_title text NOT NULL,
+ post_excerpt text NOT NULL,
+ post_status varchar(20) NOT NULL default 'publish',
+ comment_status varchar(20) NOT NULL default 'open',
+ ping_status varchar(20) NOT NULL default 'open',
+ post_password varchar(255) NOT NULL default '',
+ post_name varchar(200) NOT NULL default '',
+ to_ping text NOT NULL,
+ pinged text NOT NULL,
+ post_modified datetime NOT NULL default '0000-00-00 00:00:00',
+ post_modified_gmt datetime NOT NULL default '0000-00-00 00:00:00',
+ post_content_filtered longtext NOT NULL,
+ post_parent bigint(20) unsigned NOT NULL default '0',
+ guid varchar(255) NOT NULL default '',
+ menu_order int(11) NOT NULL default '0',
+ post_type varchar(20) NOT NULL default 'post',
+ post_mime_type varchar(100) NOT NULL default '',
+ comment_count bigint(20) NOT NULL default '0',
+ PRIMARY KEY (ID),
+ KEY post_name (post_name(191)),
+ KEY type_status_date (post_type,post_status,post_date,ID),
+ KEY post_parent (post_parent),
+ KEY post_author (post_author),
+ KEY type_status_author (post_type,post_status,post_author)
+) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE wp_postmeta (
+ meta_id bigint(20) unsigned NOT NULL auto_increment,
+ post_id bigint(20) unsigned NOT NULL default '0',
+ meta_key varchar(255) default NULL,
+ meta_value longtext,
+ PRIMARY KEY (meta_id),
+ KEY post_id (post_id),
+ KEY meta_key (meta_key(191))
+) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+
+CREATE TABLE wp_options (
+ option_id bigint(20) unsigned NOT NULL auto_increment,
+ option_name varchar(191) NOT NULL default '',
+ option_value longtext NOT NULL,
+ autoload varchar(20) NOT NULL default 'yes',
+ PRIMARY KEY (option_id),
+ UNIQUE KEY option_name (option_name),
+ KEY autoload (autoload)
+) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
+SQL;
+
/**
* Unit tests using the WordPress table definitions.
*/
@@ -20,8 +101,8 @@ class WP_SQLite_Driver_Query_Tests extends TestCase {
*/
public function setUp(): void {
/* This is the DDL for WordPress tables in SQLite syntax. */
- global $blog_tables;
- $queries = explode( ';', $blog_tables );
+ global $tables;
+ $queries = explode( ';', $tables );
$this->sqlite = new PDO( 'sqlite::memory:' );
$this->engine = new WP_SQLite_Driver(
@@ -29,29 +110,22 @@ public function setUp(): void {
'wp'
);
- $translator = $this->engine;
-
try {
- $translator->begin_transaction();
+ $this->engine->begin_transaction();
foreach ( $queries as $query ) {
$query = trim( $query );
if ( empty( $query ) ) {
continue;
}
-
- $translator->execute_sqlite_query( $query );
+ $this->engine->query( $query );
}
- $translator->commit();
- } catch ( PDOException $err ) {
- $err_data =
- $err->errorInfo; // phpcs:ignore WordPress.NamingConventions.ValidVariableName.UsedPropertyNotSnakeCase
- $err_code = $err_data[1];
- $translator->rollback();
+ $this->engine->commit();
+ } catch ( Throwable $e ) {
$message = sprintf(
'Error occurred while creating tables or indexes...
Query was: %s
',
var_export( $query, true )
);
- $message .= sprintf( 'Error message is: %s', $err_data[2] );
+ $message .= sprintf( 'Error message is: %s', $e->getMessage() );
wp_die( $message, 'Database Error!' );
}
diff --git a/tests/WP_SQLite_Driver_Tests.php b/tests/WP_SQLite_Driver_Tests.php
index befccbcc..77fef67d 100644
--- a/tests/WP_SQLite_Driver_Tests.php
+++ b/tests/WP_SQLite_Driver_Tests.php
@@ -28,7 +28,7 @@ public function setUp(): void {
"CREATE TABLE _dates (
ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL,
option_name TEXT NOT NULL default '',
- option_value DATE NOT NULL
+ option_value DATETIME NOT NULL
);"
);
}
@@ -39,6 +39,17 @@ private function assertQuery( $sql ) {
return $retval;
}
+ private function assertQueryError( $sql, $error_message ) {
+ $exception = null;
+ try {
+ $this->engine->query( $sql );
+ } catch ( WP_SQLite_Driver_Exception $e ) {
+ $exception = $e;
+ }
+ $this->assertNotNull( $exception, 'An exception was expected, but none was thrown.' );
+ $this->assertSame( $error_message, $exception->getMessage() );
+ }
+
public function testRegexp() {
$this->assertQuery(
"INSERT INTO _options (option_name, option_value) VALUES ('rss_0123456789abcdef0123456789abcdef', '1');"
@@ -173,7 +184,7 @@ public function testUpdateWithLimitNoEndToken() {
public function testUpdateWithoutWhereButWithSubSelect() {
$this->assertQuery(
- "INSERT INTO _options (option_name, option_value) VALUES ('User 0000019', 'second');"
+ "INSERT INTO _options (option_name, option_value) VALUES ('User 0000019', '2025-10-29 13:57:21');"
);
$this->assertQuery(
"INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 10:08:48');"
@@ -188,8 +199,8 @@ public function testUpdateWithoutWhereButWithSubSelect() {
$result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first'" );
$result2 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='second'" );
- $this->assertEquals( 'second', $result1[0]->option_value );
- $this->assertEquals( 'second', $result2[0]->option_value );
+ $this->assertEquals( '2025-10-29 13:57:21', $result1[0]->option_value );
+ $this->assertEquals( '2025-10-29 13:57:21', $result2[0]->option_value );
}
public function testUpdateWithoutWhereButWithLimit() {
@@ -200,13 +211,13 @@ public function testUpdateWithoutWhereButWithLimit() {
"INSERT INTO _dates (option_name, option_value) VALUES ('second', '2003-05-27 10:08:48');"
);
$return = $this->assertQuery(
- "UPDATE _dates SET option_value = 'second' LIMIT 1"
+ "UPDATE _dates SET option_value = '2025-10-29 13:57:21' LIMIT 1"
);
$this->assertSame( 1, $return, 'UPDATE query did not return 2 when two row were changed' );
$result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first'" );
$result2 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='second'" );
- $this->assertEquals( 'second', $result1[0]->option_value );
+ $this->assertEquals( '2025-10-29 13:57:21', $result1[0]->option_value );
$this->assertEquals( '2003-05-27 10:08:48', $result2[0]->option_value );
}
@@ -2342,6 +2353,8 @@ public function testOnDuplicateUpdate() {
}
public function testTruncatesInvalidDates() {
+ $this->assertQuery( "SET sql_mode = ''" );
+
$this->assertQuery( "INSERT INTO _dates (option_value) VALUES ('2022-01-01 14:24:12');" );
$this->assertQuery( "INSERT INTO _dates (option_value) VALUES ('2022-31-01 14:24:12');" );
@@ -3666,6 +3679,8 @@ public function testDefaultNullValue() {
}
public function testCurrentTimestamp() {
+ $this->assertQuery( "SET SESSION sql_mode = ''" );
+
// SELECT
$results = $this->assertQuery(
'SELECT
@@ -3689,15 +3704,16 @@ public function testCurrentTimestamp() {
$this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $results[0]->t );
// UPDATE
- $this->assertQuery( "UPDATE _dates SET option_value = ''" );
+ $this->assertQuery( "UPDATE _dates SET option_value = '0000-00-00 00:00:00'" );
$results = $this->assertQuery( 'SELECT option_value AS t FROM _dates' );
$this->assertCount( 1, $results );
- $this->assertEmpty( $results[0]->t );
+ $this->assertEquals( '0000-00-00 00:00:00', $results[0]->t );
$this->assertQuery( 'UPDATE _dates SET option_value = CURRENT_TIMESTAMP()' );
$results = $this->assertQuery( 'SELECT option_value AS t FROM _dates' );
$this->assertCount( 1, $results );
$this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $results[0]->t );
+ $this->assertNotEquals( '0000-00-00 00:00:00', $results[0]->t );
// DELETE
// We can only assert that the query passes. It is not guaranteed that we'll actually
@@ -10053,4 +10069,1069 @@ public function testEmptyColumnMeta(): void {
$this->assertSame( 0, $this->engine->get_last_column_count() );
$this->assertSame( array(), $this->engine->get_last_column_meta() );
}
+
+ public function testCastValuesOnInsert(): void {
+ // INTEGER
+ $this->assertQuery( 'CREATE TABLE t (value INT)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (1)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('3.0')" );
+
+ // TODO: These are supported in MySQL:
+ $this->assertQueryError( "INSERT INTO t VALUES ('4.5')", 'SQLSTATE[23000]: Integrity constraint violation: 19 cannot store REAL value in INTEGER column t.value' );
+ $this->assertQueryError( 'INSERT INTO t VALUES (0x05)', 'SQLSTATE[23000]: Integrity constraint violation: 19 cannot store BLOB value in INTEGER column t.value' );
+ $this->assertQueryError( "INSERT INTO t VALUES (x'06')", 'SQLSTATE[23000]: Integrity constraint violation: 19 cannot store BLOB value in INTEGER column t.value' );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0', $result[1]->value );
+ $this->assertSame( '1', $result[2]->value );
+ $this->assertSame( '0', $result[3]->value );
+ $this->assertSame( '1', $result[4]->value );
+ $this->assertSame( '2', $result[5]->value );
+ $this->assertSame( '3', $result[6]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // FLOAT
+ $this->assertQuery( 'CREATE TABLE t (value FLOAT)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (1)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (2.34)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('3.45')" );
+ $this->assertQuery( 'INSERT INTO t VALUES (4)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('5')" );
+
+ // TODO: These are supported in MySQL:
+ $this->assertQueryError( 'INSERT INTO t VALUES (0x06)', 'SQLSTATE[23000]: Integrity constraint violation: 19 cannot store BLOB value in REAL column t.value' );
+ $this->assertQueryError( "INSERT INTO t VALUES (x'07')", 'SQLSTATE[23000]: Integrity constraint violation: 19 cannot store BLOB value in REAL column t.value' );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $result[1]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '1.0' : '1', $result[2]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $result[3]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '1.0' : '1', $result[4]->value );
+ $this->assertSame( '2.34', $result[5]->value );
+ $this->assertSame( '3.45', $result[6]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '4.0' : '4', $result[7]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '5.0' : '5', $result[8]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // STRING
+ $this->assertQuery( 'CREATE TABLE t (value TEXT)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (123)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (123.456)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('a')" );
+ $this->assertQuery( 'INSERT INTO t VALUES (0x62)' );
+ $this->assertQuery( "INSERT INTO t VALUES (x'63')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0', $result[1]->value );
+ $this->assertSame( '1', $result[2]->value );
+ $this->assertSame( '0', $result[3]->value );
+ $this->assertSame( '123', $result[4]->value );
+ $this->assertSame( '123.456', $result[5]->value );
+ $this->assertSame( 'a', $result[6]->value );
+ $this->assertSame( 'b', $result[7]->value );
+ $this->assertSame( 'c', $result[8]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // BLOB
+ $this->assertQuery( 'CREATE TABLE t (value BLOB)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (123)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (123.456)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('a')" );
+ $this->assertQuery( 'INSERT INTO t VALUES (0x62)' );
+ $this->assertQuery( "INSERT INTO t VALUES (x'63')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0', $result[1]->value );
+ $this->assertSame( '1', $result[2]->value );
+ $this->assertSame( '0', $result[3]->value );
+ $this->assertSame( '123', $result[4]->value );
+ $this->assertSame( '123.456', $result[5]->value );
+ $this->assertSame( 'a', $result[6]->value );
+ $this->assertSame( 'b', $result[7]->value );
+ $this->assertSame( 'c', $result[8]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // DATE
+ $this->assertQuery( 'CREATE TABLE t (value DATE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQueryError( 'INSERT INTO t VALUES (TRUE)', "Incorrect date value: '1'" );
+ $this->assertQueryError( 'INSERT INTO t VALUES (FALSE)', "Incorrect date value: '0'" );
+ $this->assertQueryError( 'INSERT INTO t VALUES (0)', "Incorrect date value: '0'" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00.123456')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '2025-10-23', $result[1]->value );
+ $this->assertSame( '2025-10-23', $result[2]->value );
+ $this->assertSame( '2025-10-23', $result[3]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // TIME
+ $this->assertQuery( 'CREATE TABLE t (value TIME)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (123)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('18:30:00')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('18:30:00.123456')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '12:00:00', $result[1]->value ); // TODO: 00:00:00 in MySQL
+ $this->assertSame( '12:00:00', $result[2]->value ); // TODO: 00:00:01 in MySQL
+ $this->assertSame( '12:00:00', $result[3]->value ); // TODO: 00:00:01 in MySQL
+ $this->assertSame( '12:00:00', $result[4]->value ); // TODO: 00:01:23 in MySQL
+ $this->assertSame( '18:30:00', $result[5]->value );
+ $this->assertSame( '18:30:00', $result[6]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // DATETIME
+ $this->assertQuery( 'CREATE TABLE t (value DATETIME)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQueryError( 'INSERT INTO t VALUES (FALSE)', "Incorrect datetime value: '0'" );
+ $this->assertQueryError( 'INSERT INTO t VALUES (TRUE)', "Incorrect datetime value: '1'" );
+ $this->assertQueryError( 'INSERT INTO t VALUES (0)', "Incorrect datetime value: '0'" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00.123456')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '2025-10-23 00:00:00', $result[1]->value );
+ $this->assertSame( '2025-10-23 18:30:00', $result[2]->value );
+ $this->assertSame( '2025-10-23 18:30:00', $result[3]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // TIMESTAMP
+ $this->assertQuery( 'CREATE TABLE t (value TIMESTAMP)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQueryError( 'INSERT INTO t VALUES (FALSE)', "Incorrect timestamp value: '0'" );
+ $this->assertQueryError( 'INSERT INTO t VALUES (TRUE)', "Incorrect timestamp value: '1'" );
+ $this->assertQueryError( 'INSERT INTO t VALUES (0)', "Incorrect timestamp value: '0'" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00.123456')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '2025-10-23 00:00:00', $result[1]->value );
+ $this->assertSame( '2025-10-23 18:30:00', $result[2]->value );
+ $this->assertSame( '2025-10-23 18:30:00', $result[3]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // YEAR
+ $this->assertQuery( 'CREATE TABLE t (value YEAR)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00.123456')" );
+ $this->assertQuery( 'INSERT INTO t VALUES (1)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (50)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (70)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (99)' );
+ $this->assertQueryError( 'INSERT INTO t VALUES (-1)', "Out of range value: '-1'" );
+ $this->assertQueryError( 'INSERT INTO t VALUES (1900)', "Out of range value: '1900'" );
+ $this->assertQueryError( 'INSERT INTO t VALUES (2156)', "Out of range value: '2156'" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0000', $result[1]->value );
+ $this->assertSame( '2001', $result[2]->value );
+ $this->assertSame( '2025', $result[3]->value );
+ $this->assertSame( '2025', $result[4]->value );
+ $this->assertSame( '2025', $result[5]->value );
+ $this->assertSame( '2025', $result[6]->value );
+ $this->assertSame( '2001', $result[7]->value );
+ $this->assertSame( '2050', $result[8]->value );
+ $this->assertSame( '1970', $result[9]->value );
+ $this->assertSame( '1999', $result[10]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+ }
+
+ public function testCastValuesOnInsertInNonStrictMode(): void {
+ $this->assertQuery( "SET SESSION sql_mode = ''" );
+
+ // INTEGER
+ $this->assertQuery( 'CREATE TABLE t (value INT)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (1)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('3.0')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('4.5')" );
+ $this->assertQuery( 'INSERT INTO t VALUES (0x05)' );
+ $this->assertQuery( "INSERT INTO t VALUES (x'06')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0', $result[1]->value );
+ $this->assertSame( '1', $result[2]->value );
+ $this->assertSame( '0', $result[3]->value );
+ $this->assertSame( '1', $result[4]->value );
+ $this->assertSame( '2', $result[5]->value );
+ $this->assertSame( '3', $result[6]->value );
+ $this->assertSame( '4', $result[7]->value ); // TODO: 5 in MySQL
+ $this->assertSame( '0', $result[8]->value ); // TODO: 5 in MySQL
+ $this->assertSame( '0', $result[9]->value ); // TODO: 6 in MySQL
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // FLOAT
+ $this->assertQuery( 'CREATE TABLE t (value FLOAT)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (1)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (2.34)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('3.45')" );
+ $this->assertQuery( 'INSERT INTO t VALUES (4)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('5')" );
+ $this->assertQuery( 'INSERT INTO t VALUES (0x06)' );
+ $this->assertQuery( "INSERT INTO t VALUES (x'07')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $result[1]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '1.0' : '1', $result[2]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $result[3]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '1.0' : '1', $result[4]->value );
+ $this->assertSame( '2.34', $result[5]->value );
+ $this->assertSame( '3.45', $result[6]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '4.0' : '4', $result[7]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '5.0' : '5', $result[8]->value );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $result[9]->value ); // TODO: 6 in MySQL
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $result[10]->value ); // TODO: 7 in MySQL
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // STRING
+ $this->assertQuery( 'CREATE TABLE t (value TEXT)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (123)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (123.456)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('a')" );
+ $this->assertQuery( 'INSERT INTO t VALUES (0x62)' );
+ $this->assertQuery( "INSERT INTO t VALUES (x'63')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0', $result[1]->value );
+ $this->assertSame( '1', $result[2]->value );
+ $this->assertSame( '0', $result[3]->value );
+ $this->assertSame( '123', $result[4]->value );
+ $this->assertSame( '123.456', $result[5]->value );
+ $this->assertSame( 'a', $result[6]->value );
+ $this->assertSame( 'b', $result[7]->value );
+ $this->assertSame( 'c', $result[8]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // BLOB
+ $this->assertQuery( 'CREATE TABLE t (value BLOB)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (123)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (123.456)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('a')" );
+ $this->assertQuery( 'INSERT INTO t VALUES (0x62)' );
+ $this->assertQuery( "INSERT INTO t VALUES (x'63')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0', $result[1]->value );
+ $this->assertSame( '1', $result[2]->value );
+ $this->assertSame( '0', $result[3]->value );
+ $this->assertSame( '123', $result[4]->value );
+ $this->assertSame( '123.456', $result[5]->value );
+ $this->assertSame( 'a', $result[6]->value );
+ $this->assertSame( 'b', $result[7]->value );
+ $this->assertSame( 'c', $result[8]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // DATE
+ $this->assertQuery( 'CREATE TABLE t (value DATE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00.123456')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0000-00-00', $result[1]->value );
+ $this->assertSame( '0000-00-00', $result[2]->value );
+ $this->assertSame( '0000-00-00', $result[3]->value );
+ $this->assertSame( '2025-10-23', $result[4]->value );
+ $this->assertSame( '2025-10-23', $result[5]->value );
+ $this->assertSame( '2025-10-23', $result[6]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // TIME
+ $this->assertQuery( 'CREATE TABLE t (value TIME)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (123)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('18:30:00')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('18:30:00.123456')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '12:00:00', $result[1]->value ); // TODO: 00:00:00 in MySQL
+ $this->assertSame( '12:00:00', $result[2]->value ); // TODO: 00:00:01 in MySQL
+ $this->assertSame( '12:00:00', $result[3]->value ); // TODO: 00:00:00 in MySQL
+ $this->assertSame( '12:00:00', $result[4]->value ); // TODO: 00:01:23 in MySQL
+ $this->assertSame( '18:30:00', $result[5]->value );
+ $this->assertSame( '18:30:00', $result[6]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // DATETIME
+ $this->assertQuery( 'CREATE TABLE t (value DATETIME)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00.123456')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0000-00-00 00:00:00', $result[1]->value );
+ $this->assertSame( '0000-00-00 00:00:00', $result[2]->value );
+ $this->assertSame( '0000-00-00 00:00:00', $result[3]->value );
+ $this->assertSame( '2025-10-23 00:00:00', $result[4]->value );
+ $this->assertSame( '2025-10-23 18:30:00', $result[5]->value );
+ $this->assertSame( '2025-10-23 18:30:00', $result[6]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // TIMESTAMP
+ $this->assertQuery( 'CREATE TABLE t (value TIMESTAMP)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (0)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00.123456')" );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0000-00-00 00:00:00', $result[1]->value );
+ $this->assertSame( '0000-00-00 00:00:00', $result[2]->value );
+ $this->assertSame( '0000-00-00 00:00:00', $result[3]->value );
+ $this->assertSame( '2025-10-23 00:00:00', $result[4]->value );
+ $this->assertSame( '2025-10-23 18:30:00', $result[5]->value );
+ $this->assertSame( '2025-10-23 18:30:00', $result[6]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // YEAR
+ $this->assertQuery( 'CREATE TABLE t (value YEAR)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (NULL)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (FALSE)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (TRUE)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00')" );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-10-23 18:30:00.123456')" );
+ $this->assertQuery( 'INSERT INTO t VALUES (1)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (50)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (70)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (99)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (-1)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (1900)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (2156)' );
+
+ $result = $this->assertQuery( 'SELECT * FROM t' );
+ $this->assertSame( null, $result[0]->value );
+ $this->assertSame( '0000', $result[1]->value );
+ $this->assertSame( '2001', $result[2]->value );
+ $this->assertSame( '2025', $result[3]->value );
+ $this->assertSame( '2025', $result[4]->value );
+ $this->assertSame( '2025', $result[5]->value );
+ $this->assertSame( '2025', $result[6]->value );
+ $this->assertSame( '2001', $result[7]->value );
+ $this->assertSame( '2050', $result[8]->value );
+ $this->assertSame( '1970', $result[9]->value );
+ $this->assertSame( '1999', $result[10]->value );
+ $this->assertSame( '0000', $result[11]->value );
+ $this->assertSame( '0000', $result[12]->value );
+ $this->assertSame( '0000', $result[13]->value );
+ $this->assertQuery( 'DROP TABLE t' );
+ }
+
+ public function testCastValuesOnUpdate(): void {
+ // INTEGER
+ $this->assertQuery( 'CREATE TABLE t (value INT)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (1)' );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 1' );
+ $this->assertSame( '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2'" );
+ $this->assertSame( '2', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '3.0'" );
+ $this->assertSame( '3', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ // TODO: These are supported in MySQL:
+ $this->assertQueryError( "UPDATE t SET value = '4.5'", 'SQLSTATE[23000]: Integrity constraint violation: 19 cannot store REAL value in INTEGER column t.value' );
+ $this->assertQueryError( 'UPDATE t SET value = 0x05', 'SQLSTATE[23000]: Integrity constraint violation: 19 cannot store BLOB value in INTEGER column t.value' );
+ $this->assertQueryError( "UPDATE t SET value = x'06'", 'SQLSTATE[23000]: Integrity constraint violation: 19 cannot store BLOB value in INTEGER column t.value' );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // FLOAT
+ $this->assertQuery( 'CREATE TABLE t (value FLOAT)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (1.0)' );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '1.0' : '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 1' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '1.0' : '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 2.34' );
+ $this->assertSame( '2.34', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '3.45'" );
+ $this->assertSame( '3.45', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 4' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '4.0' : '4', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '5'" );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '5.0' : '5', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ // TODO: These are supported in MySQL:
+ $this->assertQueryError( 'UPDATE t SET value = 0x06', 'SQLSTATE[23000]: Integrity constraint violation: 19 cannot store BLOB value in REAL column t.value' );
+ $this->assertQueryError( "UPDATE t SET value = x'07'", 'SQLSTATE[23000]: Integrity constraint violation: 19 cannot store BLOB value in REAL column t.value' );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // STRING
+ $this->assertQuery( 'CREATE TABLE t (value TEXT)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 123' );
+ $this->assertSame( '123', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 123.456' );
+ $this->assertSame( '123.456', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = 'a'" );
+ $this->assertSame( 'a', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0x62' );
+ $this->assertSame( 'b', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = x'63'" );
+ $this->assertSame( 'c', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // BLOB
+ $this->assertQuery( 'CREATE TABLE t (value BLOB)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 123' );
+ $this->assertSame( '123', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 123.456' );
+ $this->assertSame( '123.456', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = 'a'" );
+ $this->assertSame( 'a', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0x62' );
+ $this->assertSame( 'b', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = x'63'" );
+ $this->assertSame( 'c', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // DATE
+ $this->assertQuery( 'CREATE TABLE t (value DATE)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-01-01')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQueryError( 'UPDATE t SET value = TRUE', "Incorrect date value: '1'" );
+ $this->assertQueryError( 'UPDATE t SET value = FALSE', "Incorrect date value: '0'" );
+ $this->assertQueryError( 'UPDATE t SET value = 0', "Incorrect date value: '0'" );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23'" );
+ $this->assertSame( '2025-10-23', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00'" );
+ $this->assertSame( '2025-10-23', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00.123456'" );
+ $this->assertSame( '2025-10-23', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // TIME
+ $this->assertQuery( 'CREATE TABLE t (value TIME)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('18:30:00')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '12:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 00:00:00 in MySQL
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '12:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 00:00:01 in MySQL
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '12:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 00:00:00 in MySQL
+
+ $this->assertQuery( 'UPDATE t SET value = 123' );
+ $this->assertSame( '12:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 00:01:23 in MySQL
+
+ $this->assertQuery( "UPDATE t SET value = '18:30:00'" );
+ $this->assertSame( '18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '18:30:00.123456'" );
+ $this->assertSame( '18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // DATETIME
+ $this->assertQuery( 'CREATE TABLE t (value DATETIME)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-01-01')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQueryError( 'UPDATE t SET value = TRUE', "Incorrect datetime value: '1'" );
+ $this->assertQueryError( 'UPDATE t SET value = FALSE', "Incorrect datetime value: '0'" );
+ $this->assertQueryError( 'UPDATE t SET value = 0', "Incorrect datetime value: '0'" );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23'" );
+ $this->assertSame( '2025-10-23 00:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00'" );
+ $this->assertSame( '2025-10-23 18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00.123456'" );
+ $this->assertSame( '2025-10-23 18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // TIMESTAMP
+ $this->assertQuery( 'CREATE TABLE t (value TIMESTAMP)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-01-01')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQueryError( 'UPDATE t SET value = TRUE', "Incorrect timestamp value: '1'" );
+ $this->assertQueryError( 'UPDATE t SET value = FALSE', "Incorrect timestamp value: '0'" );
+ $this->assertQueryError( 'UPDATE t SET value = 0', "Incorrect timestamp value: '0'" );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23'" );
+ $this->assertSame( '2025-10-23 00:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00'" );
+ $this->assertSame( '2025-10-23 18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00.123456'" );
+ $this->assertSame( '2025-10-23 18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // YEAR
+ $this->assertQuery( 'CREATE TABLE t (value YEAR)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0000', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '2001', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025'" );
+ $this->assertSame( '2025', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23'" );
+ $this->assertSame( '2025', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00'" );
+ $this->assertSame( '2025', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00.123456'" );
+ $this->assertSame( '2025', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 1' );
+ $this->assertSame( '2001', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 50' );
+ $this->assertSame( '2050', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 70' );
+ $this->assertSame( '1970', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 99' );
+ $this->assertSame( '1999', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQueryError( 'UPDATE t SET value = -1', "Out of range value: '-1'" );
+ $this->assertQueryError( 'UPDATE t SET value = 1900', "Out of range value: '1900'" );
+ $this->assertQueryError( 'UPDATE t SET value = 2156', "Out of range value: '2156'" );
+
+ $this->assertQuery( 'DROP TABLE t' );
+ }
+
+ public function testCastValuesOnUpdateInNonStrictMode(): void {
+ $this->assertQuery( "SET SESSION sql_mode = ''" );
+
+ // INTEGER
+ $this->assertQuery( 'CREATE TABLE t (value INT)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (1)' );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 1' );
+ $this->assertSame( '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2'" );
+ $this->assertSame( '2', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '3.0'" );
+ $this->assertSame( '3', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '4.5'" );
+ $this->assertSame( '4', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 5 in MySQL
+
+ $this->assertQuery( 'UPDATE t SET value = 0x05' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 5 in MySQL
+
+ $this->assertQuery( "UPDATE t SET value = x'06'" );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 6 in MySQL
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // FLOAT
+ $this->assertQuery( 'CREATE TABLE t (value FLOAT)' );
+ $this->assertQuery( 'INSERT INTO t VALUES (1.0)' );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '1.0' : '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 1' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '1.0' : '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 2.34' );
+ $this->assertSame( '2.34', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '3.45'" );
+ $this->assertSame( '3.45', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 4' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '4.0' : '4', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '5'" );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '5.0' : '5', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0x06' );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 6 in MySQL
+
+ $this->assertQuery( "UPDATE t SET value = x'07'" );
+ $this->assertSame( PHP_VERSION_ID < 80100 ? '0.0' : '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 7 in MySQL
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // STRING
+ $this->assertQuery( 'CREATE TABLE t (value TEXT)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 123' );
+ $this->assertSame( '123', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 123.456' );
+ $this->assertSame( '123.456', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = 'a'" );
+ $this->assertSame( 'a', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0x62' );
+ $this->assertSame( 'b', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = x'63'" );
+ $this->assertSame( 'c', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // BLOB
+ $this->assertQuery( 'CREATE TABLE t (value BLOB)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '1', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '0', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 123' );
+ $this->assertSame( '123', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 123.456' );
+ $this->assertSame( '123.456', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = 'a'" );
+ $this->assertSame( 'a', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0x62' );
+ $this->assertSame( 'b', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = x'63'" );
+ $this->assertSame( 'c', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // DATE
+ $this->assertQuery( 'CREATE TABLE t (value DATE)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-01-01')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '0000-00-00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0000-00-00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '0000-00-00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23'" );
+ $this->assertSame( '2025-10-23', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00'" );
+ $this->assertSame( '2025-10-23', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00.123456'" );
+ $this->assertSame( '2025-10-23', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // TIME
+ $this->assertQuery( 'CREATE TABLE t (value TIME)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('18:30:00')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '12:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 00:00:00 in MySQL
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '12:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 00:00:01 in MySQL
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '12:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 00:00:00 in MySQL
+
+ $this->assertQuery( 'UPDATE t SET value = 123' );
+ $this->assertSame( '12:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value ); // TODO: 00:01:23 in MySQL
+
+ $this->assertQuery( "UPDATE t SET value = '18:30:00'" );
+ $this->assertSame( '18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '18:30:00.123456'" );
+ $this->assertSame( '18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // DATETIME
+ $this->assertQuery( 'CREATE TABLE t (value DATETIME)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-01-01')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '0000-00-00 00:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0000-00-00 00:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '0000-00-00 00:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23'" );
+ $this->assertSame( '2025-10-23 00:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00'" );
+ $this->assertSame( '2025-10-23 18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00.123456'" );
+ $this->assertSame( '2025-10-23 18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // TIMESTAMP
+ $this->assertQuery( 'CREATE TABLE t (value TIMESTAMP)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025-01-01')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '0000-00-00 00:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0000-00-00 00:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 0' );
+ $this->assertSame( '0000-00-00 00:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23'" );
+ $this->assertSame( '2025-10-23 00:00:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00'" );
+ $this->assertSame( '2025-10-23 18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00.123456'" );
+ $this->assertSame( '2025-10-23 18:30:00', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+
+ // YEAR
+ $this->assertQuery( 'CREATE TABLE t (value YEAR)' );
+ $this->assertQuery( "INSERT INTO t VALUES ('2025')" );
+
+ $this->assertQuery( 'UPDATE t SET value = NULL' );
+ $this->assertSame( null, $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = FALSE' );
+ $this->assertSame( '0000', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = TRUE' );
+ $this->assertSame( '2001', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025'" );
+ $this->assertSame( '2025', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23'" );
+ $this->assertSame( '2025', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00'" );
+ $this->assertSame( '2025', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( "UPDATE t SET value = '2025-10-23 18:30:00.123456'" );
+ $this->assertSame( '2025', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 1' );
+ $this->assertSame( '2001', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 50' );
+ $this->assertSame( '2050', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 70' );
+ $this->assertSame( '1970', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 99' );
+ $this->assertSame( '1999', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = -1' );
+ $this->assertSame( '0000', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 1900' );
+ $this->assertSame( '0000', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'UPDATE t SET value = 2156' );
+ $this->assertSame( '0000', $this->assertQuery( 'SELECT * FROM t' )[0]->value );
+
+ $this->assertQuery( 'DROP TABLE t' );
+ }
+
+ public function testInsertErrors(): void {
+ $this->assertQuery( 'CREATE TABLE t (value INT)' );
+
+ // Missing table.
+ $this->assertQueryError(
+ 'INSERT INTO missing_table VALUES (1)',
+ "SQLSTATE[42S02]: Base table or view not found: 1146 Table 'missing_table' doesn't exist"
+ );
+
+ // Missing column.
+ $this->assertQueryError(
+ 'INSERT INTO t (missing_column) VALUES (1)',
+ "SQLSTATE[42S22]: Column not found: 1054 Unknown column 'missing_column' in 'field list'"
+ );
+ }
+
+ public function testInsertErrorsInNonStrictMode(): void {
+ $this->assertQuery( "SET SESSION sql_mode = ''" );
+ $this->assertQuery( 'CREATE TABLE t (value INT)' );
+
+ // Missing table.
+ $this->assertQueryError(
+ 'INSERT INTO missing_table VALUES (1)',
+ "SQLSTATE[42S02]: Base table or view not found: 1146 Table 'missing_table' doesn't exist"
+ );
+
+ // Missing column.
+ $this->assertQueryError(
+ 'INSERT INTO t (missing_column) VALUES (1)',
+ "SQLSTATE[42S22]: Column not found: 1054 Unknown column 'missing_column' in 'field list'"
+ );
+ }
+
+ public function testUpdateErrors(): void {
+ $this->assertQuery( 'CREATE TABLE t (value INT)' );
+
+ // Missing table.
+ $this->assertQueryError(
+ 'UPDATE missing_table SET value = 1',
+ "SQLSTATE[42S02]: Base table or view not found: 1146 Table 'missing_table' doesn't exist"
+ );
+
+ // Missing column.
+ $this->assertQueryError(
+ 'UPDATE t SET missing_column = 1',
+ "SQLSTATE[42S22]: Column not found: 1054 Unknown column 'missing_column' in 'field list'"
+ );
+ }
+
+ public function testUpdateErrorsInNonStrictMode(): void {
+ $this->assertQuery( "SET SESSION sql_mode = ''" );
+ $this->assertQuery( 'CREATE TABLE t (value INT)' );
+
+ // Missing table.
+ $this->assertQueryError(
+ 'UPDATE missing_table SET value = 1',
+ "SQLSTATE[42S02]: Base table or view not found: 1146 Table 'missing_table' doesn't exist"
+ );
+
+ // Missing column.
+ $this->assertQueryError(
+ 'UPDATE t SET missing_column = 1',
+ "SQLSTATE[42S22]: Column not found: 1054 Unknown column 'missing_column' in 'field list'"
+ );
+ }
}
diff --git a/tests/WP_SQLite_Driver_Translation_Tests.php b/tests/WP_SQLite_Driver_Translation_Tests.php
index e6872f89..59ec6b53 100644
--- a/tests/WP_SQLite_Driver_Translation_Tests.php
+++ b/tests/WP_SQLite_Driver_Translation_Tests.php
@@ -94,60 +94,138 @@ public function testSelect(): void {
}
public function testInsert(): void {
+ $this->driver->query( 'CREATE TABLE t (c INT, c1 INT, c2 INT)' );
+ $this->driver->query( 'CREATE TABLE t1 (c1 INT, c2 INT)' );
+ $this->driver->query( 'CREATE TABLE t2 (c1 INT, c2 INT)' );
+ $this->driver->query( 'INSERT INTO t2 VALUES (1, 2)' );
+
$this->assertQuery(
- 'INSERT INTO `t` ( `c` ) VALUES ( 1 )',
+ 'INSERT INTO `t` (`c`) SELECT `column1` FROM (VALUES ( 1 )) WHERE true',
'INSERT INTO t (c) VALUES (1)'
);
$this->assertQuery(
- 'INSERT INTO `t` ( `c` ) VALUES ( 1 )',
+ 'INSERT INTO `t` (`c`) SELECT `column1` FROM (VALUES ( 1 )) WHERE true',
'INSERT INTO wp.t (c) VALUES (1)'
);
$this->assertQuery(
- 'INSERT INTO `t` ( `c1` , `c2` ) VALUES ( 1 , 2 )',
+ 'INSERT INTO `t` (`c1`, `c2`) SELECT `column1`, `column2` FROM (VALUES ( 1 , 2 )) WHERE true',
'INSERT INTO t (c1, c2) VALUES (1, 2)'
);
$this->assertQuery(
- 'INSERT INTO `t` ( `c` ) VALUES ( 1 ) , ( 2 )',
+ 'INSERT INTO `t` (`c`) SELECT `column1` FROM (VALUES ( 1 ) , ( 2 )) WHERE true',
'INSERT INTO t (c) VALUES (1), (2)'
);
$this->assertQuery(
- 'INSERT INTO `t1` SELECT * FROM `t2`',
+ array(
+ 'SELECT * FROM (SELECT * FROM `t2`) LIMIT 1',
+ 'INSERT INTO `t1` (`c1`, `c2`) SELECT `c1`, `c2` FROM (SELECT * FROM `t2`) WHERE true',
+ ),
+ 'INSERT INTO t1 SELECT * FROM t2'
+ );
+ }
+
+ public function testInsertWithTypeCasting(): void {
+ $this->driver->query( 'CREATE TABLE t1 (c1 TEXT, c2 TEXT)' );
+ $this->driver->query( 'CREATE TABLE t2 (c1 TEXT, c2 TEXT)' );
+ $this->driver->query( 'INSERT INTO t2 VALUES (1, 2)' );
+
+ $this->assertQuery(
+ 'INSERT INTO `t1` (`c1`) SELECT CAST(`column1` AS TEXT) FROM (VALUES ( 1 )) WHERE true',
+ 'INSERT INTO t1 (c1) VALUES (1)'
+ );
+
+ $this->assertQuery(
+ 'INSERT INTO `t1` (`c1`, `c2`) SELECT CAST(`column1` AS TEXT), CAST(`column2` AS TEXT) FROM (VALUES ( 1 , 2 )) WHERE true',
+ 'INSERT INTO t1 (c1, c2) VALUES (1, 2)'
+ );
+
+ $this->assertQuery(
+ 'INSERT INTO `t1` (`c1`) SELECT CAST(`column1` AS TEXT) FROM (VALUES ( 1 ) , ( 2 )) WHERE true',
+ 'INSERT INTO t1 (c1) VALUES (1), (2)'
+ );
+
+ $this->assertQuery(
+ array(
+ 'SELECT * FROM (SELECT * FROM `t2`) LIMIT 1',
+ 'INSERT INTO `t1` (`c1`, `c2`) SELECT CAST(`c1` AS TEXT), CAST(`c2` AS TEXT) FROM (SELECT * FROM `t2`) WHERE true',
+ ),
'INSERT INTO t1 SELECT * FROM t2'
);
}
public function testReplace(): void {
+ $this->driver->query( 'CREATE TABLE t (c INT, c1 INT, c2 INT)' );
+ $this->driver->query( 'CREATE TABLE t1 (c1 INT, c2 INT)' );
+ $this->driver->query( 'CREATE TABLE t2 (c1 INT, c2 INT)' );
+ $this->driver->query( 'INSERT INTO t2 VALUES (1, 2)' );
+
$this->assertQuery(
- 'REPLACE INTO `t` ( `c` ) VALUES ( 1 )',
+ 'REPLACE INTO `t` (`c`) SELECT `column1` FROM (VALUES ( 1 )) WHERE true',
'REPLACE INTO t (c) VALUES (1)'
);
$this->assertQuery(
- 'REPLACE INTO `t` ( `c` ) VALUES ( 1 )',
+ 'REPLACE INTO `t` (`c`) SELECT `column1` FROM (VALUES ( 1 )) WHERE true',
'REPLACE INTO wp.t (c) VALUES (1)'
);
$this->assertQuery(
- 'REPLACE INTO `t` ( `c1` , `c2` ) VALUES ( 1 , 2 )',
+ 'REPLACE INTO `t` (`c1`, `c2`) SELECT `column1`, `column2` FROM (VALUES ( 1 , 2 )) WHERE true',
'REPLACE INTO t (c1, c2) VALUES (1, 2)'
);
$this->assertQuery(
- 'REPLACE INTO `t` ( `c` ) VALUES ( 1 ) , ( 2 )',
+ 'REPLACE INTO `t` (`c`) SELECT `column1` FROM (VALUES ( 1 ) , ( 2 )) WHERE true',
'REPLACE INTO t (c) VALUES (1), (2)'
);
$this->assertQuery(
- 'REPLACE INTO `t1` SELECT * FROM `t2`',
+ array(
+ 'SELECT * FROM (SELECT * FROM `t2`) LIMIT 1',
+ 'REPLACE INTO `t1` (`c1`, `c2`) SELECT `c1`, `c2` FROM (SELECT * FROM `t2`) WHERE true',
+ ),
+ 'REPLACE INTO t1 SELECT * FROM t2'
+ );
+ }
+
+ public function testReplaceWithTypeCasting(): void {
+ $this->driver->query( 'CREATE TABLE t1 (c1 TEXT, c2 TEXT)' );
+ $this->driver->query( 'CREATE TABLE t2 (c1 TEXT, c2 TEXT)' );
+ $this->driver->query( 'INSERT INTO t2 VALUES (1, 2)' );
+
+ $this->assertQuery(
+ 'REPLACE INTO `t1` (`c1`) SELECT CAST(`column1` AS TEXT) FROM (VALUES ( 1 )) WHERE true',
+ 'REPLACE INTO t1 (c1) VALUES (1)'
+ );
+
+ $this->assertQuery(
+ 'REPLACE INTO `t1` (`c1`, `c2`) SELECT CAST(`column1` AS TEXT), CAST(`column2` AS TEXT) FROM (VALUES ( 1 , 2 )) WHERE true',
+ 'REPLACE INTO t1 (c1, c2) VALUES (1, 2)'
+ );
+
+ $this->assertQuery(
+ 'REPLACE INTO `t1` (`c1`) SELECT CAST(`column1` AS TEXT) FROM (VALUES ( 1 ) , ( 2 )) WHERE true',
+ 'REPLACE INTO t1 (c1) VALUES (1), (2)'
+ );
+
+ $this->assertQuery(
+ array(
+ 'SELECT * FROM (SELECT * FROM `t2`) LIMIT 1',
+ 'REPLACE INTO `t1` (`c1`, `c2`) SELECT CAST(`c1` AS TEXT), CAST(`c2` AS TEXT) FROM (SELECT * FROM `t2`) WHERE true',
+ ),
'REPLACE INTO t1 SELECT * FROM t2'
);
}
public function testUpdate(): void {
+ $this->driver->query( 'CREATE TABLE t (c INT, c1 INT, c2 INT)' );
+ $this->driver->query( 'CREATE TABLE t1 (id INT, c1 INT, c2 INT)' );
+ $this->driver->query( 'CREATE TABLE t2 (id INT, c1 INT, c2 INT)' );
+
$this->assertQuery(
'UPDATE `t` SET `c` = 1',
'UPDATE t SET c = 1'
diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php
index 134400cc..002ea5c9 100644
--- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php
+++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php
@@ -1500,12 +1500,6 @@ private function execute_select_statement( WP_Parser_Node $node ): void {
* @throws WP_SQLite_Driver_Exception When the query execution fails.
*/
private function execute_insert_or_replace_statement( WP_Parser_Node $node ): void {
- // Check if strict mode is disabled.
- $is_non_strict_mode = (
- ! $this->is_sql_mode_active( 'STRICT_TRANS_TABLES' )
- && ! $this->is_sql_mode_active( 'STRICT_ALL_TABLES' )
- );
-
$parts = array();
foreach ( $node->get_children() as $child ) {
$is_token = $child instanceof WP_MySQL_Token;
@@ -1527,8 +1521,7 @@ private function execute_insert_or_replace_statement( WP_Parser_Node $node ): vo
// Translate "UPDATE IGNORE" to "UPDATE OR IGNORE".
$parts[] = 'OR IGNORE';
} elseif (
- $is_non_strict_mode
- && $is_node
+ $is_node
&& (
'insertFromConstructor' === $child->rule_name
|| 'insertQueryExpression' === $child->rule_name
@@ -1537,17 +1530,7 @@ 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_in_non_strict_mode( $table_name, $child );
- } elseif ( $is_node && 'updateList' === $child->rule_name ) {
- // Convert "SET c1 = v1, c2 = v2, ... to "(c1, c2, ...) VALUES (v1, v2, ...)".
- $columns = array();
- $values = array();
- foreach ( $child->get_child_nodes( 'updateElement' ) as $update_element ) {
- $column_ref = $update_element->get_first_child_node( 'columnRef' );
- $columns[] = $this->translate( $column_ref );
- $values[] = $this->translate( $update_element->get_first_child_node( 'expr' ) );
- }
- $parts[] = '(' . implode( ', ', $columns ) . ') VALUES (' . implode( ', ', $values ) . ')';
+ $parts[] = $this->translate_insert_or_replace_body( $table_name, $child );
} else {
$parts[] = $this->translate( $child );
}
@@ -1591,12 +1574,6 @@ private function execute_update_statement( WP_Parser_Node $node ): void {
);
}
- // Check if strict mode is disabled.
- $is_non_strict_mode = (
- ! $this->is_sql_mode_active( 'STRICT_TRANS_TABLES' )
- && ! $this->is_sql_mode_active( 'STRICT_ALL_TABLES' )
- );
-
/*
* Translate the UPDATE statement parts.
*
@@ -1759,22 +1736,8 @@ private function execute_update_statement( WP_Parser_Node $node ): void {
$from = 'FROM ' . implode( ', ', $from_items );
}
- // Translate UPDATE list.
- if ( $is_non_strict_mode ) {
- $update_list = $this->translate_update_list_in_non_strict_mode( $update_target, $update_list_node );
- } else {
- $update_parts = array();
- foreach ( $update_list_node->get_child_nodes() as $update_element ) {
- $column_ref = $update_element->get_first_child_node( 'columnRef' );
- $column_ref_parts = $column_ref->get_descendant_nodes( 'identifier' );
-
- $update_part = $this->translate( end( $column_ref_parts ) );
- $update_part .= ' = ';
- $update_part .= $this->translate( $update_element->get_first_child_node( 'expr' ) );
- $update_parts[] = $update_part;
- }
- $update_list = implode( ', ', $update_parts );
- }
+ // Translate UPDATE list, applying relevant type casting and IMPLICIT DEFAULT values.
+ $update_list = $this->translate_update_list( $update_target_table, $update_list_node );
// Translate WHERE, ORDER BY, and LIMIT clauses.
if ( $where_subquery ) {
@@ -4377,28 +4340,32 @@ private function translate_show_like_or_where_condition( WP_Parser_Node $like_or
/**
* Translate INSERT or REPLACE statement body to SQLite, while emulating
- * the behavior of MySQL implicit default values in non-strict mode.
+ * MySQL column type casting and implicit default values when saving data.
*
- * Rewrites a statement body in the following form:
+ * This method rewrites an INSERT or REPLACE statement body from:
* INSERT INTO table (optionally some columns)
* To a statement body with the following structure:
- * INSERT INTO table (all table columns)
- * SELECT FROM () WHERE true
+ * INSERT INTO table (table columns)
+ * SELECT FROM () WHERE true
*
* In MySQL, the behavior of INSERT and UPDATE statements depends on whether
* the STRICT_TRANS_TABLES (InnoDB) or STRICT_ALL_TABLES SQL mode is enabled.
*
- * By default, STRICT_TRANS_TABLES is enabled, which makes the InnoDB table
- * behavior correspond to the natural behavior of SQLite tables. However,
- * some applications, including WordPress, disable strict mode altogether.
+ * This method applies relevant type casting and emulates IMPLICIT DEFAULT
+ * value behavior as follows:
+ * 1. In STRICT mode:
+ * - Apply relevant type casting based on the column data type.
+ * 2. In non-STRICT mode:
+ * - Apply relevant type casting based on the column data type.
+ * - Replace invalid values with IMPLICIT DEFAULTs.
+ * - Replace missing values without defaults with IMPLICIT DEFAULTs.
*
* The strict SQL modes can be set per session, and can be changed at runtime.
- * In SQLite, we can emulate this using the knowledge of the table structure:
- * 1. Explicitly passed INSERT statement values are used without change.
- * 2. Values omitted from the INSERT statement are replaced with the column
- * DEFAULT or an IMPLICIT DEFAULT value based on their data type.
+ * In SQLite, we can emulate this using the knowledge of the table structure.
*
- * Here's a summary of the strict vs. non-strict behaviors in MySQL:
+ * -----
+ *
+ * Here's a summary of the strict vs. non-strict IMPLICIT DEFAULT behavior:
*
* When STRICT_TRANS_TABLES or STRICT_ALL_TABLES is enabled:
* 1. NULL + NO DEFAULT: No value saves NULL, NULL saves NULL, DEFAULT saves NULL.
@@ -4416,6 +4383,9 @@ private function translate_show_like_or_where_condition( WP_Parser_Node $like_or
* NULL is rejected on INSERT, but saves IMPLICIT DEFAULT on UPDATE.
* DEFAULT saves DEFAULT.
*
+ * For more information about STRICT mode in MySQL, see:
+ * https://dev.mysql.com/doc/refman/8.4/en/sql-mode.html#sql-mode-strict
+ *
* 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
*
@@ -4423,55 +4393,102 @@ private function translate_show_like_or_where_condition( WP_Parser_Node $like_or
* @param WP_Parser_Node $node The "insertQueryExpression" or "insertValues" AST node.
* @return string The translated INSERT query body.
*/
- private function translate_insert_or_replace_body_in_non_strict_mode(
+ private function translate_insert_or_replace_body(
string $table_name,
WP_Parser_Node $node
): string {
- // 1. Get column metadata from information schema.
+ // This method is always used with the main database.
+ $database = $this->get_saved_db_name( $this->main_db_name );
+
+ // Check if strict mode is enabled.
+ $is_strict_mode = (
+ $this->is_sql_mode_active( 'STRICT_TRANS_TABLES' )
+ || $this->is_sql_mode_active( 'STRICT_ALL_TABLES' )
+ );
+
+ // Get column metadata for the target table from the information schema.
$is_temporary = $this->information_schema_builder->temporary_table_exists( $table_name );
$columns_table = $this->information_schema_builder->get_table_name( $is_temporary, 'columns' );
$columns = $this->execute_sqlite_query(
'
- SELECT column_name, is_nullable, column_default, data_type, extra
+ SELECT LOWER(column_name) AS COLUMN_NAME, is_nullable, column_default, data_type, extra
FROM ' . $this->quote_sqlite_identifier( $columns_table ) . '
WHERE table_schema = ?
AND table_name = ?
ORDER BY ordinal_position
',
- array( $this->get_saved_db_name(), $table_name )
+ array( $database, $table_name )
)->fetchAll( PDO::FETCH_ASSOC );
- // 2. Get the list of fields explicitly defined in the INSERT statement.
+ // Check if the table exists.
+ if ( 0 === count( $columns ) ) {
+ throw $this->new_driver_exception(
+ sprintf(
+ "SQLSTATE[42S02]: Base table or view not found: 1146 Table '%s' doesn't exist",
+ $table_name
+ ),
+ '42S02'
+ );
+ }
+
+ // Get a list of columns that are targeted by the INSERT or REPLACE query.
+ // This is either an explicit column list, or all columns of the table.
$insert_list = array();
$fields_node = $node->get_first_child_node( 'fields' );
if ( $fields_node ) {
- // This is the optional "INSERT INTO ... (field1, field2, ...)" list.
+ // "INSERT INTO ... (column1, column2, ...)"
foreach ( $fields_node->get_child_nodes() as $field ) {
- $insert_list[] = $this->unquote_sqlite_identifier( $this->translate( $field ) );
+ $column_name = $this->unquote_sqlite_identifier( $this->translate( $field ) );
+ $insert_list[] = strtolower( $column_name );
}
} elseif ( 'updateList' === $node->rule_name ) {
- // This is the "INSERT INTO ... SET c1 = v1, c2 = v2, ... " syntax.
+ // "INSERT INTO ... SET column1 = value1, column2 = value2, ..."
foreach ( $node->get_child_nodes( 'updateElement' ) as $update_element ) {
$column_ref = $update_element->get_first_child_node( 'columnRef' );
- $insert_list[] = $this->unquote_sqlite_identifier( $this->translate( $column_ref ) );
+ $column_name = $this->unquote_sqlite_identifier( $this->translate( $column_ref ) );
+ $insert_list[] = strtolower( $column_name );
}
} else {
- // When no explicit field list is provided, all columns are required.
+ // "INSERT INTO ... VALUES(...)" or "INSERT INTO ... SELECT ..."
+ // No explicit column list is provided; we need to list all columns.
foreach ( array_column( $columns, 'COLUMN_NAME' ) as $column_name ) {
- $insert_list[] = $column_name;
+ $insert_list[] = strtolower( $column_name );
}
}
- // 3. Filter out omitted columns that will get a value from the SQLite engine.
- // That is, nullable columns, columns with defaults, and generated columns.
+ // Check if all listed columns exist.
+ $unknown_columns = array_diff( $insert_list, array_column( $columns, 'COLUMN_NAME' ) );
+ if ( count( $unknown_columns ) > 0 ) {
+ throw $this->new_driver_exception(
+ sprintf(
+ "SQLSTATE[42S22]: Column not found: 1054 Unknown column '%s' in 'field list'",
+ $unknown_columns[0]
+ ),
+ '42S22'
+ );
+ }
+
+ // Prepare a helper map of columns that are included in the INSERT list.
+ $insert_map = array_combine( $insert_list, $insert_list );
+
+ /*
+ * Filter out columns that were omitted in the INSERT list:
+ * 1. In strict mode, filter out all omitted columns.
+ * 2. In non-strict mode, filter out omitted columns that will get a
+ * value from the SQLite engine. That is, nullable columns, columns
+ * with defaults, and generated columns.
+ */
$columns = array_values(
array_filter(
$columns,
- function ( $column ) use ( $insert_list ) {
- $is_omitted = ! in_array( $column['COLUMN_NAME'], $insert_list, true );
+ function ( $column ) use ( $is_strict_mode, $insert_map ) {
+ $is_omitted = ! isset( $insert_map[ $column['COLUMN_NAME'] ] );
if ( ! $is_omitted ) {
return true;
}
+ if ( $is_strict_mode ) {
+ return false;
+ }
$is_nullable = 'YES' === $column['IS_NULLABLE'];
$has_default = $column['COLUMN_DEFAULT'];
$is_generated = str_contains( $column['EXTRA'], 'auto_increment' );
@@ -4480,11 +4497,17 @@ function ( $column ) use ( $insert_list ) {
)
);
- // 4. Get the list of column names returned by VALUES or SELECT clause.
+ /*
+ * Get a list of column names for the INSERT or REPLACE values clause.
+ * These are the columns that will be used in a SELECT statement when
+ * the values clause is wrapped in a subquery:
+ *
+ * INSERT INTO ... SELECT FROM ()
+ */
$select_list = array();
if ( 'insertQueryExpression' === $node->rule_name ) {
// When inserting from a SELECT query, we don't know the column names.
- // Let's wrap the query with a SELECT (...) LIMIT 0 to get obtain them.
+ // Let's wrap the query with a "SELECT (...) LIMIT 0" to obtain them.
$expr = $node->get_first_child_node( 'queryExpressionOrParens' );
$stmt = $this->execute_sqlite_query(
'SELECT * FROM (' . $this->translate( $expr ) . ') LIMIT 1'
@@ -4492,16 +4515,34 @@ function ( $column ) use ( $insert_list ) {
$stmt->execute();
for ( $i = 0; $i < $stmt->columnCount(); $i++ ) {
+ /*
+ * Workaround for PHP PDO SQLite bug (#79664) in PHP < 7.3.
+ * See also: https://github.com/php/php-src/pull/5654
+ */
+ if ( PHP_VERSION_ID < 70300 ) {
+ try {
+ $column_meta = $stmt->getColumnMeta( $i );
+ } catch ( Throwable $e ) {
+ $column_meta = false;
+ }
+ if ( false === $column_meta ) {
+ // Due to a PDO bug in PHP < 7.3, we get no column metadata
+ // when no rows are returned. In that case, no data will be
+ // inserted, so we can bail out using a simple translation.
+ return $this->translate( $node );
+ }
+ }
$select_list[] = $stmt->getColumnMeta( $i )['name'];
}
} else {
- // When inserting from a VALUES list, SQLite uses "columnN" naming.
+ // When inserting from a VALUES list, SQLite uses a "columnN" naming.
+ // This also applies to the SET syntax, which is converted to VALUES.
foreach ( array_keys( $insert_list ) as $position ) {
$select_list[] = 'column' . ( $position + 1 );
}
}
- // 5. Compose a new INSERT field list with all columns from the table.
+ // Compose a new INSERT column list with all columns from the table.
$fragment = '(';
foreach ( $columns as $i => $column ) {
$fragment .= $i > 0 ? ', ' : '';
@@ -4509,13 +4550,18 @@ function ( $column ) use ( $insert_list ) {
}
$fragment .= ')';
- // 6. Compose a wrapper SELECT statement emulating IMPLICIT DEFAULT values.
+ // Compose a wrapper SELECT statement emulating MySQL-like type casting,
+ // and, in non-strict mode, IMPLICIT DEFAULT values for omitted columns.
$fragment .= ' SELECT ';
foreach ( $columns as $i => $column ) {
- $is_omitted = ! in_array( $column['COLUMN_NAME'], $insert_list, true );
+ $is_omitted = ! isset( $insert_map[ $column['COLUMN_NAME'] ] );
$fragment .= $i > 0 ? ', ' : '';
if ( $is_omitted ) {
/*
+ * This path only applies to non-strict mode. In strict mode,
+ * omitted columns get no IMPLICIT DEFAULT values, and they were
+ * previously filtered out from the columns list.
+ *
* When a column is omitted from the INSERT list, we need to use
* an IMPLICIT DEFAULT value. Note that at this point, all omitted
* columns that will not get an implicit default are filtered out.
@@ -4527,15 +4573,11 @@ function ( $column ) use ( $insert_list ) {
// 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 .= sprintf(
- '%s AS %s',
- $this->cast_value_in_non_strict_mode( $column['DATA_TYPE'], $identifier ),
- $identifier
- );
+ $fragment .= $this->cast_value_for_saving( $column['DATA_TYPE'], $identifier );
}
}
- // 6. Wrap the original insert VALUES, SELECT, or SET list in a FROM clause.
+ // Wrap the original insert VALUES, SELECT, or SET list in a FROM clause.
if ( 'insertFromConstructor' === $node->rule_name ) {
// VALUES (...)
$from = $this->translate(
@@ -4568,25 +4610,51 @@ function ( $column ) use ( $insert_list ) {
}
/**
- * Translate UPDATE list, emulating MySQL implicit defaults in non-strict mode.
+ * Translate UPDATE statement SET value list to SQLite, while emulating
+ * MySQL column type casting and implicit default values when saving data.
*
* Rewrites an UPDATE statement list in the following form:
- * UPDATE table SET =
+ * UPDATE table SET =
* To a list with the following structure:
- * UPDATE table SET = COALESCE(, )
+ * UPDATE table SET =
*
* In MySQL, the behavior of INSERT and UPDATE statements depends on whether
* the STRICT_TRANS_TABLES (InnoDB) or STRICT_ALL_TABLES SQL mode is enabled.
*
- * When the strict mode is not enabled, executing an UPDATE statement that
- * sets a NOT NULL column value to NULL saves an IMPLICIT DEFAULT instead.
+ * This method applies relevant type casting and emulates IMPLICIT DEFAULT
+ * value behavior as follows:
+ * 1. In STRICT mode:
+ * - Apply relevant type casting based on the column data type.
+ * 2. In NON-STRICT mode:
+ * - Apply relevant type casting based on the column data type.
+ * - Replace invalid values with IMPLICIT DEFAULTs.
+ * - Replace NULL values without defaults with IMPLICIT DEFAULTs.
+ * (Updating a NOT NULL column to NULL saves as an IMPLICIT DEFAULT.)
+ *
+ * The strict SQL modes can be set per session, and can be changed at runtime.
+ * In SQLite, we can emulate this using the knowledge of the table structure.
+ *
+ * For more information about STRICT mode in MySQL, see:
+ * https://dev.mysql.com/doc/refman/8.4/en/sql-mode.html#sql-mode-strict
+ *
+ * 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.
*/
- private function translate_update_list_in_non_strict_mode( string $table_name, WP_Parser_Node $node ): string {
- // 1. Get column metadata from information schema.
+ private function translate_update_list( string $table_name, WP_Parser_Node $node ): string {
+ // This method is always used with the main database.
+ $database = $this->get_saved_db_name( $this->main_db_name );
+
+ // Check if strict mode is enabled.
+ $is_strict_mode = (
+ $this->is_sql_mode_active( 'STRICT_TRANS_TABLES' )
+ || $this->is_sql_mode_active( 'STRICT_ALL_TABLES' )
+ );
+
+ // Get column metadata from the information schema.
$is_temporary = $this->information_schema_builder->temporary_table_exists( $table_name );
$columns_table = $this->information_schema_builder->get_table_name( $is_temporary, 'columns' );
$columns = $this->execute_sqlite_query(
@@ -4596,11 +4664,23 @@ private function translate_update_list_in_non_strict_mode( string $table_name, W
WHERE table_schema = ?
AND table_name = ?
',
- array( $this->get_saved_db_name(), $table_name )
+ array( $database, $table_name )
)->fetchAll( PDO::FETCH_ASSOC );
- $column_map = array_combine( array_column( $columns, 'COLUMN_NAME' ), $columns );
- // 2. Translate UPDATE list, emulating implicit defaults for NULLs values.
+ // Check if the table exists.
+ if ( 0 === count( $columns ) ) {
+ throw $this->new_driver_exception(
+ sprintf(
+ "SQLSTATE[42S02]: Base table or view not found: 1146 Table '%s' doesn't exist",
+ $table_name
+ ),
+ '42S02'
+ );
+ }
+
+ $column_map = array_combine( array_column( $columns, 'COLUMN_NAME' ), $columns );
+
+ // Translate the UPDATE list, emulating IMPLICIT DEFAULTs for NULL values.
$fragment = '';
foreach ( $node->get_child_nodes() as $i => $update_element ) {
$column_ref = $update_element->get_first_child_node( 'columnRef' );
@@ -4609,7 +4689,17 @@ private function translate_update_list_in_non_strict_mode( string $table_name, W
// Get column info.
$column_name = $this->unquote_sqlite_identifier( $this->translate( end( $column_ref_parts ) ) );
- $column_info = $column_map[ strtolower( $column_name ) ];
+ $column_info = $column_map[ strtolower( $column_name ) ] ?? null;
+ if ( ! $column_info ) {
+ throw $this->new_driver_exception(
+ sprintf(
+ "SQLSTATE[42S22]: Column not found: 1054 Unknown column '%s' in 'field list'",
+ $column_name
+ ),
+ '42S22'
+ );
+ }
+
$data_type = $column_info['DATA_TYPE'];
$is_nullable = 'YES' === $column_info['IS_NULLABLE'];
$default = $column_info['COLUMN_DEFAULT'];
@@ -4623,11 +4713,12 @@ private function translate_update_list_in_non_strict_mode( string $table_name, W
}
// Apply type casting.
- $value = $this->cast_value_in_non_strict_mode( $data_type, $value );
+ $value = $this->cast_value_for_saving( $data_type, $value );
- // If the column is NOT NULL, a NULL value resolves to 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.
$implicit_default = self::DATA_TYPE_IMPLICIT_DEFAULT_MAP[ $data_type ] ?? null;
- if ( ! $is_nullable && null !== $implicit_default ) {
+ if ( ! $is_strict_mode && ! $is_nullable && null !== $implicit_default ) {
$value = sprintf( 'COALESCE(%s, %s)', $value, $this->connection->quote( $implicit_default ) );
}
@@ -4927,23 +5018,28 @@ private function create_table_reference_map( WP_Parser_Node $node ): array {
}
/**
- * Emulate MySQL type casting for INSERT or UPDATE value in non-strict mode.
+ * Emulate MySQL type casting for values to be saved to the database
+ * using INSERT, REPLACE, or UPDATE statements.
*
* @param string $mysql_data_type The MySQL data type.
* @param string $translated_value The original translated value.
* @return string The translated value.
*/
- private function cast_value_in_non_strict_mode(
+ private function cast_value_for_saving(
string $mysql_data_type,
string $translated_value
): string {
- $sqlite_data_type = self::DATA_TYPE_STRING_MAP[ $mysql_data_type ];
+ // TODO: This is also a good place to implement checks for maximum column
+ // lengths with truncating or bailing out depending on the SQL mode.
- // Get and quote the IMPLICIT DEFAULT value.
- $implicit_default = self::DATA_TYPE_IMPLICIT_DEFAULT_MAP[ $mysql_data_type ] ?? null;
- $quoted_implicit_default = null === $implicit_default
- ? 'NULL'
- : $this->connection->quote( $implicit_default );
+ // Check if strict mode is enabled.
+ $is_strict_mode = (
+ $this->is_sql_mode_active( 'STRICT_TRANS_TABLES' )
+ || $this->is_sql_mode_active( 'STRICT_ALL_TABLES' )
+ );
+
+ $mysql_data_type = strtolower( $mysql_data_type );
+ $sqlite_data_type = self::DATA_TYPE_STRING_MAP[ $mysql_data_type ];
/*
* In MySQL, when saving a value via INSERT or UPDATE in non-strict mode,
@@ -4977,21 +5073,72 @@ private function cast_value_in_non_strict_mode(
} elseif ( 'datetime' === $mysql_data_type || 'timestamp' === $mysql_data_type ) {
$function_call = sprintf( 'DATETIME(%s)', $translated_value );
} elseif ( 'year' === $mysql_data_type ) {
- $function_call = sprintf( "STRFTIME('%%Y', %s)", $translated_value );
+ /*
+ * The YEAR type in MySQL only uses 1 byte and therefore
+ * covers only 256 values from 1901 to 2155 included.
+ * Additionally:
+ * - Numbers from 0 to 69 correspond to years 2000 to 2069.
+ * - Numbers from 70 to 99 correspond to years 1970 to 1999.
+ */
+ return sprintf(
+ "(
+ SELECT CASE
+ WHEN value IS NULL THEN NULL
+ WHEN value = 0 THEN '0000'
+ WHEN value BETWEEN 1901 AND 2155 THEN value
+ WHEN value BETWEEN 1 AND 69 THEN 2000 + value
+ WHEN value BETWEEN 70 AND 99 THEN 1900 + value
+ ELSE %s
+ END
+ FROM (SELECT CAST(%s AS INTEGER) AS value)
+ )",
+ $is_strict_mode
+ ? sprintf( "THROW('Out of range value: ''' || %s || '''')", $translated_value )
+ : "'0000'",
+ $translated_value
+ );
}
- // When the function call evaluates to NULL (invalid date/time),
- // we need to fallback to the IMPLICIT DEFAULT value.
+ // In strict mode, invalid date/time values are rejected.
+ // In non-strict mode, they get an IMPLICIT DEFAULT value.
+ if ( $is_strict_mode ) {
+ $fallback = sprintf(
+ "THROW('Incorrect %s value: ''' || %s || '''')",
+ $mysql_data_type,
+ $translated_value
+ );
+ } else {
+ $implicit_default = self::DATA_TYPE_IMPLICIT_DEFAULT_MAP[ $mysql_data_type ] ?? null;
+ $fallback = null === $implicit_default
+ ? 'NULL'
+ : $this->connection->quote( $implicit_default );
+ }
return sprintf(
- 'IIF(%s IS NULL, NULL, COALESCE(%s, %s))',
+ "CASE
+ WHEN %s IS NULL THEN NULL
+ WHEN %s > '0' THEN %s
+ ELSE %s
+ END",
$translated_value,
$function_call,
- $quoted_implicit_default
+ $function_call,
+ $fallback
);
default:
- // For all other data types, use SQLite-native CAST expression.
- $mysql_data_type = strtolower( $mysql_data_type );
- return sprintf( 'CAST(%s AS %s)', $translated_value, $sqlite_data_type );
+ /*
+ * For all other data types, cast to the SQLite types as follows:
+ * 1. In strict mode, cast only values for TEXT and BLOB columns.
+ * Numeric types accept string notation in SQLite as well.
+ * 2. In non-strict mode, cast all values.
+ *
+ * TODO: While close to MySQL behavior, this doesn't exactly match
+ * all special cases. We may improve this further to accept
+ * BLOBs for numeric types, and other special behaviors.
+ */
+ if ( ! $is_strict_mode || 'TEXT' === $sqlite_data_type || 'BLOB' === $sqlite_data_type ) {
+ return sprintf( 'CAST(%s AS %s)', $translated_value, $sqlite_data_type );
+ }
+ return $translated_value;
}
}
diff --git a/wp-includes/sqlite/class-wp-sqlite-pdo-user-defined-functions.php b/wp-includes/sqlite/class-wp-sqlite-pdo-user-defined-functions.php
index d14978b0..a1e44fd4 100644
--- a/wp-includes/sqlite/class-wp-sqlite-pdo-user-defined-functions.php
+++ b/wp-includes/sqlite/class-wp-sqlite-pdo-user-defined-functions.php
@@ -44,6 +44,7 @@ public static function register_for( PDO $pdo ): self {
* @var array
*/
private $functions = array(
+ 'throw' => 'throw',
'month' => 'month',
'monthnum' => 'month',
'year' => 'year',
@@ -88,6 +89,18 @@ public static function register_for( PDO $pdo ): self {
'_helper_like_to_glob_pattern' => '_helper_like_to_glob_pattern',
);
+ /**
+ * A helper function to throw an error from SQLite expressions.
+ *
+ * @param string $message The error message.
+ *
+ * @throws Exception The error message.
+ * @return void
+ */
+ public function throw( $message ): void {
+ throw new Exception( $message );
+ }
+
/**
* Method to return the unix timestamp.
*