diff --git a/.gitignore b/.gitignore index d1502b08..0d54553e 100644 --- a/.gitignore +++ b/.gitignore @@ -1,2 +1,4 @@ vendor/ composer.lock +.idea/ +.phpunit.result.cache diff --git a/tests/WP_SQLite_Metadata_Tests.php b/tests/WP_SQLite_Metadata_Tests.php new file mode 100644 index 00000000..29bff89c --- /dev/null +++ b/tests/WP_SQLite_Metadata_Tests.php @@ -0,0 +1,322 @@ +suppress_errors = false; + $GLOBALS['wpdb']->show_errors = true; + } + } + + // Before each test, we create a new database + public function setUp(): void { + global $blog_tables; + $queries = explode( ';', $blog_tables ); + + $this->sqlite = new PDO( 'sqlite::memory:' ); + $this->engine = new WP_SQLite_Translator( $this->sqlite ); + + $translator = $this->engine; + + try { + $translator->begin_transaction(); + foreach ( $queries as $query ) { + $query = trim( $query ); + if ( empty( $query ) ) { + continue; + } + + $result = $translator->execute_sqlite_query( $query ); + if ( false === $result ) { + throw new PDOException( $translator->get_error_message() ); + } + } + $translator->commit(); + } catch ( PDOException $err ) { + $err_data = + $err->errorInfo; // phpcs:ignore WordPress.NamingConventions.ValidVariableName.UsedPropertyNotSnakeCase + $err_code = $err_data[1]; + $translator->rollback(); + $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] ); + wp_die( $message, 'Database Error!' ); + } + } + + public function testCountTables() { + $this->assertQuery( "SELECT count(*) FROM information_schema.tables WHERE table_schema = 'wpdata'" ); + + $actual = $this->engine->get_query_results(); + $count = array_values( get_object_vars( $actual[0] ) )[0]; + self::assertIsNumeric( $count ); + } + + private function assertQuery( $sql, $error_substring = null ) { + $retval = $this->engine->query( $sql ); + if ( null === $error_substring ) { + $this->assertEquals( + '', + $this->engine->get_error_message() + ); + $this->assertNotFalse( + $retval + ); + } else { + $this->assertStringContainsStringIgnoringCase( $error_substring, $this->engine->get_error_message() ); + } + + return $retval; + } + + public function testCheckTable() { + + /* a good table */ + $table_name = 'wp_options'; + $expected_result = array( + (object) array( + 'Table' => $table_name, + 'Op' => 'check', + 'Msg_type' => 'status', + 'Msg_text' => 'OK', + ), + ); + + $this->assertQuery( + "CHECK TABLE $table_name;" + ); + + $this->assertEquals( + $expected_result, + $this->engine->get_query_results() + ); + + /* a different good table */ + $table_name = 'wp_postmeta'; + $expected_result = array( + (object) array( + 'Table' => $table_name, + 'Op' => 'check', + 'Msg_type' => 'status', + 'Msg_text' => 'OK', + ), + ); + + $this->assertQuery( + "CHECK TABLE $table_name;" + ); + $this->assertEquals( + $expected_result, + $this->engine->get_query_results() + ); + + /* a bogus, missing, table */ + $table_name = 'wp_sqlite_rocks'; + $expected_result = array( + (object) array( + 'Table' => $table_name, + 'Op' => 'check', + 'Msg_type' => 'Error', + 'Msg_text' => "Table '$table_name' doesn't exist", + ), + (object) array( + 'Table' => $table_name, + 'Op' => 'check', + 'Msg_type' => 'status', + 'Msg_text' => 'Operation failed', + ), + ); + + $this->assertQuery( + "CHECK TABLE $table_name;" + ); + + $this->assertEquals( + $expected_result, + $this->engine->get_query_results() + ); + } + + public function testOptimizeTable() { + + /* a good table */ + $table_name = 'wp_options'; + + $this->assertQuery( + "OPTIMIZE TABLE $table_name;" + ); + + $actual = $this->engine->get_query_results(); + + array_map( + function ( $row ) { + $this->assertIsObject( $row ); + $row = (array) $row; + $this->assertIsString( $row['Table'] ); + $this->assertIsString( $row['Op'] ); + $this->assertIsString( $row['Msg_type'] ); + $this->assertIsString( $row['Msg_text'] ); + }, + $actual + ); + + $ok = array_filter( + $actual, + function ( $row ) { + $row = (array) $row; + + return strtolower( $row['Msg_type'] ) === 'status' && strtolower( $row['Msg_text'] ) === 'ok'; + } + ); + $this->assertIsArray( $ok ); + $this->assertGreaterThan( 0, count( $ok ) ); + } + + public function testRepairTable() { + + /* a good table */ + $table_name = 'wp_options'; + + $this->assertQuery( + "REPAIR TABLE $table_name;" + ); + + $actual = $this->engine->get_query_results(); + + array_map( + function ( $r ) { + $this->assertIsObject( $r ); + $row = $r; + $row = (array) $row; + $this->assertIsString( $row['Table'] ); + $this->assertIsString( $row['Op'] ); + $this->assertIsString( $row['Msg_type'] ); + $this->assertIsString( $row['Msg_text'] ); + }, + $actual + ); + + $ok = array_filter( + $actual, + function ( $row ) { + return strtolower( $row->Msg_type ) === 'status' && strtolower( $row->Msg_text ) === 'ok'; + } + ); + $this->assertIsArray( $ok ); + $this->assertGreaterThan( 0, count( $ok ) ); + } + + // this tests for successful rejection of a bad query + + public function testShowTableStatus() { + + $this->assertQuery( + "INSERT INTO wp_comments ( comment_author, comment_content ) VALUES ( 'PhpUnit', 'Testing' )" + ); + + $this->assertQuery( + "INSERT INTO wp_comments ( comment_author, comment_content ) VALUES ( 'PhpUnit0', 'Testing0' ), ( 'PhpUnit1', 'Testing1' ), ( 'PhpUnit2', 'Testing2' )" + ); + + $this->assertTableEmpty( 'wp_comments', false ); + + $this->assertQuery( + 'SHOW TABLE STATUS FROM wp;' + ); + + $actual = $this->engine->get_query_results(); + + $this->assertIsArray( $actual ); + $this->assertGreaterThanOrEqual( + 1, + count( $actual ) + ); + $this->assertIsObject( $actual[0] ); + + $rows = array_values( + array_filter( + $actual, + function ( $row ) { + $this->assertIsObject( $row ); + $this->assertIsString( $row->Name ); + $this->assertIsNumeric( $row->Rows ); + + return str_ends_with( $row->Name, 'comments' ); + } + ) + ); + $this->assertEquals( 'wp_comments', $rows[0]->Name ); + $this->assertEquals( 4, $rows[0]->Rows ); + } + + private function assertTableEmpty( $table_name, $empty ) { + + $this->assertQuery( + "SELECT COUNT(*) num FROM $table_name" + ); + + $actual = $this->engine->get_query_results(); + if ( $empty ) { + $this->assertEquals( 0, $actual[0]->num, "$table_name is not empty" ); + } else { + $this->assertGreaterThan( 0, $actual[0]->num, "$table_name is empty" ); + } + } + + public function testTruncateTable() { + + $this->assertQuery( + "INSERT INTO wp_comments ( comment_author, comment_content ) VALUES ( 'PhpUnit', 'Testing' )" + ); + + $this->assertQuery( + "INSERT INTO wp_comments ( comment_author, comment_content ) VALUES ( 'PhpUnit0', 'Testing0' ), ( 'PhpUnit1', 'Testing1' ), ( 'PhpUnit2', 'Testing2' )" + ); + + $this->assertTableEmpty( 'wp_comments', false ); + + $this->assertQuery( + 'TRUNCATE TABLE wp_comments;' + ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( + true, + $actual + ); + $this->assertTableEmpty( 'wp_comments', true ); + } + + public function testBogusQuery() { + + $this->assertQuery( + 'SELECT 1, BOGUS(1) FROM bogus;', + 'no such table: bogus' + ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( + null, + $actual + ); + } + +} diff --git a/tests/WP_SQLite_Query_Tests.php b/tests/WP_SQLite_Query_Tests.php new file mode 100644 index 00000000..3c06f1c6 --- /dev/null +++ b/tests/WP_SQLite_Query_Tests.php @@ -0,0 +1,537 @@ +suppress_errors = false; + $GLOBALS['wpdb']->show_errors = true; + } + } + + /** + * Before each test, we create a new volatile database and WordPress tables. + * + * @return void + * @throws Exception + */ + public function setUp(): void { + /* This is the DDL for WordPress tables in SQLite syntax. */ + global $blog_tables; + $queries = explode( ';', $blog_tables ); + + $this->sqlite = new PDO( 'sqlite::memory:' ); + $this->engine = new WP_SQLite_Translator( $this->sqlite ); + + $translator = $this->engine; + + try { + $translator->begin_transaction(); + foreach ( $queries as $query ) { + $query = trim( $query ); + if ( empty( $query ) ) { + continue; + } + + $result = $translator->execute_sqlite_query( $query ); + if ( false === $result ) { + throw new PDOException( $translator->get_error_message() ); + } + } + $translator->commit(); + } catch ( PDOException $err ) { + $err_data = + $err->errorInfo; // phpcs:ignore WordPress.NamingConventions.ValidVariableName.UsedPropertyNotSnakeCase + $err_code = $err_data[1]; + $translator->rollback(); + $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] ); + wp_die( $message, 'Database Error!' ); + } + + /* Mock up some metadata rows. When meta_key starts with _, the custom field isn't visible to the editor. */ + for ( $i = 1; $i <= 40; $i ++ ) { + $k1 = 'visible_meta_key_' . str_pad( $i, 2, '0', STR_PAD_LEFT ); + $k2 = '_invisible_meta_key_%_percent' . str_pad( $i, 2, '0', STR_PAD_LEFT ); + $this->assertQuery( + "INSERT INTO wp_postmeta (post_id, meta_key, meta_value) VALUES (1, '$k1', '$k1-value');" + ); + $this->assertQuery( + "INSERT INTO wp_postmeta (post_id, meta_key, meta_value) VALUES (1, '$k2', '$k2-value');" + ); + } + + /* Mock up some transients for testing. Site transients. Two expired, one in the future. */ + $time = - 90; + foreach ( array( 'tag1', 'tag2', 'tag3' ) as $tag ) { + $tv = '_site_transient_' . $tag; + $tt = '_site_transient_timeout_' . $tag; + $this->assertQuery( + "INSERT INTO wp_options (option_name, option_value, autoload) VALUES ('$tv', '$tag', 'no');" + ); + $this->assertQuery( + "INSERT INTO wp_options (option_name, option_value, autoload) VALUES ('$tt', UNIX_TIMESTAMP() + $time, 'no');" + ); + $time += 60; + } + /* Ordinary transients. */ + $time = - 90; + foreach ( array( 'tag4', 'tag5', 'tag6' ) as $tag ) { + $tv = '_transient_' . $tag; + $tt = '_transient_timeout_' . $tag; + $this->assertQuery( + "INSERT INTO wp_options (option_name, option_value, autoload) VALUES ('$tv', '$tag', 'no');" + ); + $this->assertQuery( + "INSERT INTO wp_options (option_name, option_value, autoload) VALUES ('$tt', UNIX_TIMESTAMP() + $time, 'no');" + ); + $time += 60; + } + } + + public function testGreatestLeast() { + $q = <<<'QUERY' +SELECT GREATEST('a', 'b') letter; +QUERY; + + $result = $this->assertQuery( $q ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( 1, count( $actual ) ); + $this->assertEquals( 'b', $actual[0]->letter ); + + $q = <<<'QUERY' +SELECT LEAST('a', 'b') letter; +QUERY; + + $result = $this->assertQuery( $q ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( 1, count( $actual ) ); + $this->assertEquals( 'a', $actual[0]->letter ); + + $q = <<<'QUERY' +SELECT GREATEST(2, 1.5) num; +QUERY; + + $result = $this->assertQuery( $q ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( 1, count( $actual ) ); + $this->assertEquals( 2, $actual[0]->num ); + + $q = <<<'QUERY' +SELECT LEAST(2, 1.5, 1.0) num; +QUERY; + + $result = $this->assertQuery( $q ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( 1, count( $actual ) ); + $this->assertEquals( 1, $actual[0]->num ); + } + + public function testLikeEscapingSimpleNoSemicolon() { + $q = <<<'QUERY' +SELECT DISTINCT meta_key FROM wp_postmeta WHERE meta_key LIKE '\_%' +QUERY; + + $result = $this->assertQuery( $q ); + + $actual = $this->engine->get_query_results(); + $this->assertEquals( 40, count( $actual ) ); + } + + public function testLikeEscapingPercent() { + $q = <<<'QUERY' +SELECT DISTINCT meta_key FROM wp_postmeta WHERE meta_key LIKE '%\_\%\_percent%' +QUERY; + + $result = $this->assertQuery( $q ); + + $actual = $this->engine->get_query_results(); + $this->assertEquals( 40, count( $actual ) ); + } + + public function testLikeEscapingSimpleSemicolon() { + $q = <<<'QUERY' +SELECT DISTINCT meta_key FROM wp_postmeta WHERE meta_key LIKE '\_%'; +QUERY; + + $result = $this->assertQuery( $q ); + + $actual = $this->engine->get_query_results(); + $this->assertEquals( 40, count( $actual ) ); + } + + public function testLikeEscapingBasic() { + $q = <<<'QUERY' +SELECT DISTINCT meta_key FROM wp_postmeta WHERE meta_key NOT BETWEEN '_' AND '_z' AND meta_key NOT LIKE '\_%' ORDER BY meta_key LIMIT 30 +QUERY; + + $result = $this->assertQuery( $q ); + + $actual = $this->engine->get_query_results(); + $this->assertEquals( 30, count( $actual ) ); + $last = $actual[ count( $actual ) - 1 ]->meta_key; + $this->assertEquals( 'visible_meta_key_30', $last ); + } + + public function testLikeEscapingParenAfterLike() { + $q = <<<'QUERY' + SELECT DISTINCT meta_key + FROM wp_postmeta + WHERE (meta_key != 'hello' AND meta_key NOT LIKE '\_%') AND meta_id > 0 +QUERY; + + $this->assertQuery( $q ); + + $actual = $this->engine->get_query_results(); + $this->assertEquals( 40, count( $actual ) ); + $last = $actual[ count( $actual ) - 1 ]->meta_key; + $this->assertEquals( 'visible_meta_key_40', $last ); + } + + public function testLikeEscapingWithConcatFunction() { + $q = <<<'QUERY' +SELECT DISTINCT meta_key FROM wp_postmeta WHERE meta_key NOT BETWEEN '_' AND '_z' AND meta_key NOT LIKE CONCAT('\_', '%') ORDER BY meta_key LIMIT 30 +QUERY; + + $result = $this->assertQuery( $q ); + + $actual = $this->engine->get_query_results(); + $this->assertEquals( 30, count( $actual ) ); + $last = $actual[ count( $actual ) - 1 ]->meta_key; + $this->assertEquals( 'visible_meta_key_30', $last ); + } + + // https://github.com/WordPress/sqlite-database-integration/issues/19 + + public function testHavingWithoutGroupBy() { + + $q = <<<'QUERY' +SELECT DISTINCT meta_key FROM wp_postmeta WHERE meta_key NOT BETWEEN '_' AND '_z' HAVING meta_key NOT LIKE '\_%' ORDER BY meta_key LIMIT 30 +QUERY; + + $result = $this->assertQuery( $q ); + + $actual = $this->engine->get_query_results(); + $this->assertEquals( 30, count( $actual ) ); + $last = $actual[ count( $actual ) - 1 ]->meta_key; + $this->assertEquals( 'visible_meta_key_30', $last ); + + $q = <<<'QUERY' +SELECT DISTINCT meta_key FROM wp_postmeta WHERE meta_key NOT BETWEEN '_' AND '_z' HAVING meta_key NOT LIKE CONCAT('\_', '%') ORDER BY meta_key LIMIT 30 +QUERY; + + $result = $this->assertQuery( $q ); + + $actual = $this->engine->get_query_results(); + $this->assertEquals( 30, count( $actual ) ); + $last = $actual[ count( $actual ) - 1 ]->meta_key; + $this->assertEquals( 'visible_meta_key_30', $last ); + } + + public function testCharLengthSimple() { + $query = <<<'QUERY' +SELECT * FROM wp_options WHERE LENGTH(option_name) != CHAR_LENGTH(option_name) +QUERY; + + $this->assertQuery( $query ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( 0, count( $actual ) ); + } + + public function testSubstringSimple() { + $query = <<<'QUERY' +SELECT SUBSTR(option_name, 1) ss1, SUBSTRING(option_name, 1) sstr1, + SUBSTR(option_name, -2) es1, SUBSTRING(option_name, -2) estr1 +FROM wp_options +WHERE SUBSTR(option_name, -2) != SUBSTRING(option_name, -2) + OR SUBSTR(option_name, 1) != SUBSTRING(option_name, 1) +QUERY; + + $this->assertQuery( $query ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( 0, count( $actual ) ); + } + + public function testCharLengthComplex() { + $query = <<<'QUERY' +SELECT option_name, + CHAR_LENGTH( + CASE WHEN option_name LIKE '\_site\_transient\_%' + THEN '_site_transient_' + WHEN option_name LIKE '\_transient\_%' + THEN '_transient_' + ELSE '' END + ) prefix_length, + + SUBSTR(option_name, CHAR_LENGTH( + CASE WHEN option_name LIKE '\_site\_transient\_%' + THEN '_site_transient_' + WHEN option_name LIKE '\_transient\_%' + THEN '_transient_' + ELSE '' END + ) + 1) suffix +FROM wp_options +WHERE option_name LIKE '\_%transient\_%' +AND option_name NOT LIKE '%\_transient\_timeout\_%' +QUERY; + + $this->assertQuery( $query ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( 6, count( $actual ) ); + foreach ( $actual as $row ) { + self::assertTrue( str_ends_with( $row->option_name, '_' . $row->suffix ) ); + } + } + + public function testAllTransients() { + $this->assertQuery( + "SELECT * FROM wp_options WHERE option_name LIKE '\_%transient\_%'" + ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( 12, count( $actual ) ); + } + + public function testExpiredTransients() { + $query = <<<'QUERY' +SELECT a.option_id, a.option_name, a.option_value as option_content, a.autoload, b.option_value as option_timeout, + UNIX_TIMESTAMP() - b.option_value as age, + CONCAT ( + CASE WHEN a.option_name LIKE '\_site\_transient\_%' + THEN '_site_transient_timeout_' + ELSE '_transient_timeout_' + END, + SUBSTRING(a.option_name, CHAR_LENGTH( + CASE WHEN a.option_name LIKE '\_site\_transient\_%' + THEN '_site_transient_' + ELSE '_transient_' + END + ) + 1)) AS timeout_name + + + FROM wp_options a LEFT JOIN wp_options b ON b.option_name = + CONCAT( + CASE WHEN a.option_name LIKE '\_site\_transient\_%' + THEN '_site_transient_timeout_' + ELSE '_transient_timeout_' + END + , + SUBSTRING(a.option_name, CHAR_LENGTH( + CASE WHEN a.option_name LIKE '\_site\_transient\_%' + THEN '_site_transient_' + ELSE '_transient_' + END + ) + 1) + ) + WHERE (a.option_name LIKE '\_transient\_%' OR a.option_name LIKE '\_site\_transient\_%') + AND a.option_name NOT LIKE '%\_transient\_timeout\_%' + AND b.option_value < UNIX_TIMESTAMP() +QUERY; + + $this->assertQuery( $query ); + $actual = $this->engine->get_query_results(); + $this->assertEquals( 4, count( $actual ) ); + foreach ( $actual as $row ) { + self::assertLessThan( time(), $row->option_timeout ); + } + } + + public function testDeleteExpiredNonSiteTransients() { + + $now = time(); + + /* option.php: delete_expired_transients is the source of this query. */ + $query = <<<'QUERY' +DELETE a, b FROM wp_options a, wp_options b +WHERE a.option_name LIKE '\_transient\_%' +AND a.option_name NOT LIKE '\_transient\_timeout_%' +AND b.option_name = CONCAT( '_transient_timeout_', SUBSTRING( a.option_name, 12 ) ) +AND b.option_value < UNIX_TIMESTAMP() +QUERY; + $this->assertQuery( $query ); + + /* are the expired transients gone? */ + $query = <<<'QUERY' +SELECT a.option_id, a.option_name, a.option_value as option_content, + a.autoload, b.option_value as option_timeout, + UNIX_TIMESTAMP() - b.option_value as age, + CONCAT ( + CASE WHEN a.option_name LIKE '\_site\_transient\_%' + THEN '_site_transient_timeout_' + ELSE '_transient_timeout_' + END, + SUBSTRING(a.option_name, CHAR_LENGTH( + CASE WHEN a.option_name LIKE '\_site\_transient\_%' + THEN '_site_transient_' + ELSE '_transient_' + END + ) + 1)) AS timeout_name + + + FROM wp_options a LEFT JOIN wp_options b ON b.option_name = + CONCAT( + CASE WHEN a.option_name LIKE '\_site\_transient\_%' + THEN '_site_transient_timeout_' + ELSE '_transient_timeout_' + END + , + SUBSTRING(a.option_name, CHAR_LENGTH( + CASE WHEN a.option_name LIKE '\_site\_transient\_%' + THEN '_site_transient_' + ELSE '_transient_' + END + ) + 1) + ) + WHERE (a.option_name LIKE '\_transient\_%' OR a.option_name LIKE '\_site\_transient\_%') + AND a.option_name NOT LIKE '%\_transient\_timeout\_%' +QUERY; + + $this->assertQuery( $query ); + $actual = $this->engine->get_query_results(); + $count_unexpired = 0; + foreach ( $actual as $row ) { + if ( str_starts_with( $row->option_name, '_transient' ) ) { + $count_unexpired ++; + $this->assertGreaterThan( $now, $row->option_timeout ); + } + } + $this->assertEquals( 1, $count_unexpired ); + } + + public function testUserCountsByRole() { + /* commas appear after the LIKE term sometimes, as here. */ + $query = <<<'QUERY' +SELECT COUNT(NULLIF(`meta_value` LIKE '%\"administrator\"%', false)), + COUNT(NULLIF(`meta_value` LIKE '%\"editor\"%', false)), + COUNT(NULLIF(`meta_value` LIKE '%\"author\"%', false)), + COUNT(NULLIF(`meta_value` LIKE '%\"contributor\"%', false)), + COUNT(NULLIF(`meta_value` LIKE '%\"subscriber\"%', false)), + COUNT(NULLIF(`meta_value` = 'a:0:{}', false)), + COUNT(*) +FROM wp_usermeta +INNER JOIN wp_users ON user_id = ID +WHERE meta_key = 'wp_capabilities' + +QUERY; + $this->assertQuery( $query ); + } + + public function testTranscendental() { + $this->markTestIncomplete( 'For some reason sqlite\'s transcendental functions are missing.' ); + $this->assertQuery( 'SELECT 2.0, SQRT(2.0) sqr, SIN(0.5) s;' ); + } + + public function testRecoverSerialized() { + + $obj = array( + 'this' => 'that', + 'that' => array( 'the', 'other', 'thing' ), + 'two' => 2, + 2 => 'two', + 'pi' => pi(), + 'moo' => "Mrs O'Leary's cow!", + ); + $option_name = 'serialized_option'; + $option_value = serialize( $obj ); + $option_value_escaped = $this->engine->get_pdo()->quote( $option_value ); + /* Note well: this is heredoc not nowdoc */ + $insert = <<assertQuery( $insert ); + $get = <<assertQuery( $get ); + + $actual = $this->engine->get_query_results(); + $retrieved_name = $actual[0]->option_name; + $retrieved_string = $actual[0]->option_value; + $this->assertEquals( $option_value, $retrieved_string ); + $unserialized = unserialize( $retrieved_string ); + $this->assertEquals( $obj, $unserialized ); + + $obj ['two'] ++; + $obj ['pi'] *= 2; + $option_value = serialize( $obj ); + $option_value_escaped = $this->engine->get_pdo()->quote( $option_value ); + /* Note well: this is heredoc not nowdoc */ + $insert = <<assertQuery( $insert ); + $get = <<assertQuery( $get ); + + $actual = $this->engine->get_query_results(); + $retrieved_string = $actual[0]->option_value; + $this->assertEquals( $option_value, $retrieved_string ); + $unserialized = unserialize( $retrieved_string ); + $this->assertEquals( $obj, $unserialized ); + } + + public function testShowColumns() { + + $query = 'SHOW COLUMNS FROM wp_posts'; + $this->assertQuery( $query ); + + $actual = $this->engine->get_query_results(); + foreach ( $actual as $row ) { + $this->assertIsObject( $row ); + $this->assertTrue( property_exists( $row, 'Field' ) ); + $this->assertTrue( property_exists( $row, 'Type' ) ); + $this->assertTrue( property_exists( $row, 'Null' ) ); + $this->assertTrue( ( 'NO' === $row->Null ) || ( 'YES' === $row->Null ) ); + $this->assertTrue( property_exists( $row, 'Key' ) ); + $this->assertTrue( property_exists( $row, 'Default' ) ); + } + } + + private function assertQuery( $sql ) { + $retval = $this->engine->query( $sql ); + $this->assertEquals( + '', + $this->engine->get_error_message() + ); + $this->assertNotFalse( + $retval + ); + + return $retval; + } + +} diff --git a/tests/WP_SQLite_Translator_Tests.php b/tests/WP_SQLite_Translator_Tests.php index 446f7693..c83fad3f 100644 --- a/tests/WP_SQLite_Translator_Tests.php +++ b/tests/WP_SQLite_Translator_Tests.php @@ -47,15 +47,20 @@ public function setUp(): void { ); } - private function assertQuery( $sql ) { + private function assertQuery( $sql, $error_substring = null ) { $retval = $this->engine->query( $sql ); - $this->assertEquals( - '', - $this->engine->get_error_message() - ); - $this->assertNotFalse( - $retval - ); + if ( null === $error_substring ) { + $this->assertEquals( + '', + $this->engine->get_error_message() + ); + $this->assertNotFalse( + $retval + ); + } else { + $this->assertStringContainsStringIgnoringCase( $error_substring, $this->engine->get_error_message() ); + } + return $retval; } @@ -683,12 +688,49 @@ public function testCaseInsensitiveUniqueIndex() { ); $this->assertEquals( 1, $result ); - $result1 = $this->engine->query( "INSERT INTO _tmp_table (name) VALUES ('first');" ); + $result1 = $this->engine->query( "INSERT INTO _tmp_table (name, lastname) VALUES ('first', 'last');" ); $this->assertEquals( 1, $result1 ); + $result1 = $this->engine->query( "SELECT COUNT(*) num FROM _tmp_table;" ); + $this->assertEquals( 1, $result1[0]->num ); + + // Unique keys should be case-insensitive: + $result2 = $this->assertQuery( + "INSERT INTO _tmp_table (name, lastname) VALUES ('FIRST', 'LAST' );", + 'UNIQUE constraint failed' + ); + + $this->assertEquals( false, $result2 ); + + + $result1 = $this->engine->query( "SELECT COUNT(*) num FROM _tmp_table;" ); + $this->assertEquals( 1, $result1[0]->num ); + + // Unique keys should be case-insensitive: + $result1 = $this->assertQuery( + "INSERT IGNORE INTO _tmp_table (name) VALUES ('FIRST');" + ); + + self::assertEquals( 0, $result1 ); + + $result2 = $this->engine->get_query_results(); + $this->assertEquals( 0, $result2 ); + + $result1 = $this->engine->query( "SELECT COUNT(*)num FROM _tmp_table;" ); + $this->assertEquals( 1, $result1[0]->num ); + // Unique keys should be case-insensitive: - $result2 = $this->engine->query( "INSERT INTO _tmp_table (name) VALUES ('FIRST');" ); - $this->assertFalse( $result2 ); + $result2 = $this->assertQuery( + "INSERT INTO _tmp_table (name, lastname) VALUES ('FIRSTname', 'LASTname' );" + ); + + $this->assertEquals( 1, $result2 ); + + + $result1 = $this->engine->query( "SELECT COUNT(*) num FROM _tmp_table;" ); + $this->assertEquals( 2, $result1[0]->num ); + + } public function testOnDuplicateUpdate() { @@ -883,7 +925,7 @@ public function testNestedTransactionWorkComplexModify() { // into multiple SQLite queries – some of them will // succeed, some will fail. $success = $this->engine->query( " - ALTER TABLE _options + ALTER TABLE _options ADD COLUMN test varchar(20), ADD COLUMN test varchar(20) " ); @@ -1417,6 +1459,23 @@ public function testStringToFloatComparison() { $this->markTestSkipped( 'Comparing a string and a float returns true in MySQL. In SQLite, they\'re different. Skipping. ' ); } $this->assertEquals( '1', $results[0]->cmp ); + + $this->assertQuery( "SELECT (0+'00.42' = 0.4200) as cmp;" ); + $results = $this->engine->get_query_results(); + $this->assertEquals( '1', $results[0]->cmp ); + + } + + public function testZeroPlusStringToFloatComparison() { + + $this->assertQuery( "SELECT (0+'00.42' = 0.4200) as cmp;" ); + $results = $this->engine->get_query_results(); + $this->assertEquals( '1', $results[0]->cmp ); + + $this->assertQuery( "SELECT 0+'1234abcd' = 1234 as cmp;" ); + $results = $this->engine->get_query_results(); + $this->assertEquals( '1', $results[0]->cmp ); + } public function testCalcFoundRows() { @@ -1548,7 +1607,7 @@ public function testFetchedDataIsStringified() { public function testCreateTableQuery() { $this->assertQuery( - <<<'Q' + <<<'QUERY' CREATE TABLE IF NOT EXISTS wptests_users ( ID bigint(20) unsigned NOT NULL auto_increment, user_login varchar(60) NOT NULL default '', @@ -1565,12 +1624,12 @@ public function testCreateTableQuery() { KEY user_nicename (user_nicename), KEY user_email (user_email) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci - Q +QUERY ); $this->assertQuery( - <<<'Q' + <<<'QUERY' INSERT INTO wptests_users VALUES (1,'admin','$P$B5ZQZ5ZQZ5ZQZ5ZQZ5ZQZ5ZQZ5ZQZ5','admin','admin@localhost', '', '2019-01-01 00:00:00', '', 0, 'admin'); - Q +QUERY ); $rows = $this->assertQuery( 'SELECT * FROM wptests_users' ); $this->assertCount( 1, $rows ); @@ -1605,8 +1664,8 @@ public function testTranslatesComplexDelete() { $result = $this->assertQuery( "DELETE a, b FROM wptests_dummy a, wptests_dummy b - WHERE a.option_name LIKE '_transient_%' - AND a.option_name NOT LIKE '_transient_timeout_%' + WHERE a.option_name LIKE '\_transient\_%' + AND a.option_name NOT LIKE '\_transient\_timeout_%' AND b.option_name = CONCAT( '_transient_timeout_', SUBSTRING( a.option_name, 12 ) );" ); $this->assertEquals( @@ -1617,7 +1676,7 @@ public function testTranslatesComplexDelete() { public function testTranslatesDoubleAlterTable() { $result = $this->assertQuery( - 'ALTER TABLE _options + 'ALTER TABLE _options ADD INDEX test_index(option_name(140),option_value(51)), DROP INDEX test_index, ADD INDEX test_index2(option_name(140),option_value(51)) @@ -1689,6 +1748,7 @@ public function testTranslatesUtf8Insert() { 1, $this->assertQuery('SELECT * FROM _options') ); + $this->assertQuery( "DELETE FROM _options"); } public function testTranslatesRandom() { @@ -1702,11 +1762,33 @@ public function testTranslatesRandom() { } public function testTranslatesUtf8SELECT() { - $this->engine->query( - "SELECT a as 'ą' FROM test WHERE b='ąłółźćę†'AND c='ąłółźćę†'" + $this->assertQuery( + "INSERT INTO _options VALUES(1,'ąłółźćę†','ąłółźćę†')" ); - // No exception is good enough of a test for now - $this->assertTrue(true); + $this->assertCount( + 1, + $this->assertQuery('SELECT * FROM _options') + ); + + $this->assertQuery( + "SELECT option_name as 'ą' FROM _options WHERE option_name='ąłółźćę†' AND option_value='ąłółźćę†'" + ); + + $this->assertEquals( + array( (object) array( 'ą' => 'ąłółźćę†' )), + $this->engine->get_query_results() + ); + + $this->assertQuery( + "SELECT option_name as 'ą' FROM _options WHERE option_name LIKE '%ółźć%'" + ); + + $this->assertEquals( + array( (object) array( 'ą' => 'ąłółźćę†' )), + $this->engine->get_query_results() + ); + + $this->assertQuery( "DELETE FROM _options"); } } diff --git a/tests/bootstrap.php b/tests/bootstrap.php index 2d9173ac..8f9bda57 100644 --- a/tests/bootstrap.php +++ b/tests/bootstrap.php @@ -1,7 +1,59 @@ 'dayofmonth', 'unix_timestamp' => 'unix_timestamp', 'now' => 'now', - 'char_length' => 'char_length', 'md5' => 'md5', 'curdate' => 'curdate', 'rand' => 'rand', @@ -135,17 +134,6 @@ public function curdate() { return gmdate( 'Y-m-d' ); } - /** - * Method to emulate MySQL CHAR_LENGTH() function. - * - * @param string $field The string to be measured. - * - * @return int unsigned integer for the length of the argument. - */ - public function char_length( $field ) { - return strlen( $field ); - } - /** * Method to emulate MySQL MD5() function. * @@ -574,7 +562,7 @@ public function log() { public function least() { $arg_list = func_get_args(); - return "min($arg_list)"; + return min( $arg_list ); } /** @@ -587,7 +575,7 @@ public function least() { public function greatest() { $arg_list = func_get_args(); - return "max($arg_list)"; + return max( $arg_list ); } /** diff --git a/wp-includes/sqlite/class-wp-sqlite-translator.php b/wp-includes/sqlite/class-wp-sqlite-translator.php index a1cd14f3..6226d6a7 100644 --- a/wp-includes/sqlite/class-wp-sqlite-translator.php +++ b/wp-includes/sqlite/class-wp-sqlite-translator.php @@ -23,6 +23,11 @@ class WP_SQLite_Translator { PRIMARY KEY(`table`, `column_or_index`) );'; + /** + * We use the ASCII SUB character to escape LIKE literal _ and % + */ + const LIKE_ESCAPE_CHAR = "\x1a"; + /** * Class variable to reference to the PDO instance. * @@ -272,6 +277,49 @@ class WP_SQLite_Translator { */ private $last_reserved_keyword; + /* + * True if a VACUUM operation should be done on shutdown, to handle OPTIMIZE TABLE and similar operations. + * + * @var bool + */ + private $vacuum_requested = false; + + /** + * True if the present query is metadata + * + * @var bool + */ + private $is_information_schema_query = false; + + /** + * True if a GROUP BY clause is detected. + * + * @var bool + */ + private $has_group_by = false; + + /** + * 0 if no LIKE is in progress, otherwise counts nested parentheses. + * + * @todo A generic stack of expression would scale better. There's already a call_stack in WP_SQLite_Query_Rewriter. + * @var int + */ + private $like_expression_nesting = 0; + + /** + * 0 if no LIKE is in progress, otherwise counts nested parentheses. + * + * @var int + */ + private $like_escape_count = 0; + + /** + * Associative array with list of system (non-WordPress) tables. + * + * @var array [tablename => tablename] + */ + private $sqlite_system_tables = array(); + /** * Constructor. * @@ -292,8 +340,14 @@ public function __construct( $pdo = null ) { $err_message = ''; do { try { + $options = array ( + PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION, + PDO::ATTR_STRINGIFY_FETCHES => true, + PDO::ATTR_TIMEOUT => 5 + ); + $dsn = 'sqlite:' . FQDB; - $pdo = new PDO( $dsn, null, null, array( PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION ) ); // phpcs:ignore WordPress.DB.RestrictedClasses + $pdo = new PDO( $dsn, null, null, $options ); // phpcs:ignore WordPress.DB.RestrictedClasses } catch ( PDOException $ex ) { $status = $ex->getCode(); if ( self::SQLITE_BUSY === $status || self::SQLITE_LOCKED === $status ) { @@ -322,6 +376,11 @@ public function __construct( $pdo = null ) { // MySQL data comes across stringified by default. $pdo->setAttribute( PDO::ATTR_STRINGIFY_FETCHES, true ); $pdo->query( WP_SQLite_Translator::CREATE_DATA_TYPES_CACHE_TABLE ); + /* A list of system tables lets us emulate information_schema + * queries without returning extra tables. + */ + $this->sqlite_system_tables ['sqlite_sequence'] = 'sqlite_sequence'; + $this->sqlite_system_tables [self::DATA_TYPES_CACHE_TABLE] = self::DATA_TYPES_CACHE_TABLE; $this->pdo = $pdo; @@ -330,6 +389,7 @@ public function __construct( $pdo = null ) { register_shutdown_function( array( $this, '__destruct' ) ); + // WordPress happens to use no foreign keys. $statement = $this->pdo->query( 'PRAGMA foreign_keys' ); if ( $statement->fetchColumn( 0 ) == '0' ) { // phpcs:ignore WordPress.PHP.StrictComparisons.LooseComparison $this->pdo->query( 'PRAGMA foreign_keys = ON' ); @@ -476,6 +536,36 @@ private function prepare_directory() { */ public function query( $statement, $mode = PDO::FETCH_OBJ, ...$fetch_mode_args ) { // phpcs:ignore WordPress.DB.RestrictedClasses $this->flush(); + if ( function_exists( 'apply_filters' ) ) { + /** + * Filters queries before they are translated and run. + * + * Return a non-null value to cause query() to return early with that result. + * Use this filter to intercept queries that don't work correctly in SQLite. + * + * From within the filter you can do + * function filter_sql ($result, $translator, $statement, $mode, $fetch_mode_args) { + * if ( intercepting this query ) { + * return $translator->execute_sqlite_query( $statement ); + * } + * return $result; + * } + * + * @param null|array $result Default null to continue with the query. + * @param object $translator The translator object. You can call $translator->execute_sqlite_query(). + * @param string $statement The statement passed. + * @param int $mode Fetch mode: PDO::FETCH_OBJ, PDO::FETCH_CLASS, etc. + * @param array $fetch_mode_args Variable arguments passed to query. + * + * @returns null|array Null to proceed, or an array containing a resultset. + * @since 2.1.0 + * + */ + $pre = apply_filters( 'pre_query_sqlite_db', null, $this, $statement, $mode, $fetch_mode_args ); + if ( null !== $pre ) { + return $pre; + } + } $this->pdo_fetch_mode = $mode; $this->mysql_query = $statement; if ( @@ -695,6 +785,16 @@ private function execute_mysql_query( $query ) { $this->execute_describe(); break; + case 'CHECK': + $this->execute_check(); + break; + + case 'OPTIMIZE': + case 'REPAIR': + case 'ANALYZE': + $this->execute_optimize( $query_type ); + break; + default: throw new Exception( 'Unknown query type: ' . $query_type ); } @@ -1221,9 +1321,9 @@ private function execute_delete() { } $query = ( - count( $ids_to_delete ) - ? "DELETE FROM {$table_name} WHERE {$pk_name} IN (" . implode( ',', $ids_to_delete ) . ')' - : "DELETE FROM {$table_name} WHERE 0=1" + count( $ids_to_delete ) + ? "DELETE FROM {$table_name} WHERE {$pk_name} IN (" . implode( ',', $ids_to_delete ) . ')' + : "DELETE FROM {$table_name} WHERE 0=1" ); $this->execute_sqlite_query( $query ); $this->set_result_from_affected_rows( @@ -1273,22 +1373,9 @@ private function execute_select() { $updated_query = $this->rewriter->get_updated_query(); if ( $table_name && str_starts_with( strtolower( $table_name ), 'information_schema' ) ) { - // @TODO: Actually rewrite the columns. - if ( str_contains( $updated_query, 'bytes' ) ) { - // Count rows per table. - $tables = $this->execute_sqlite_query( "SELECT name as `table` FROM sqlite_master WHERE type='table' ORDER BY name" )->fetchAll(); - $rows = '(CASE '; - foreach ( $tables as $table ) { - $table_name = $table['table']; - $count = $this->execute_sqlite_query( "SELECT COUNT(*) as `count` FROM $table_name" )->fetch(); - $rows .= " WHEN name = '$table_name' THEN {$count['count']} "; - } - $rows .= 'ELSE 0 END) '; - $updated_query = "SELECT name as `table`, $rows as `rows`, 0 as `bytes` FROM sqlite_master WHERE type='table' ORDER BY name"; - } else { - $updated_query = "SELECT name, 'myisam' as `engine`, 0 as `data`, 0 as `index` FROM sqlite_master WHERE type='table' ORDER BY name"; - } - $params = array(); + $this->is_information_schema_query = true; + $updated_query = $this->get_information_schema_query( $updated_query ); + $params = array(); } elseif ( strpos( $updated_query, '@@SESSION.sql_mode' ) !== false || strpos( $updated_query, 'CONVERT( ' ) !== false @@ -1318,9 +1405,17 @@ private function execute_select() { } $stmt = $this->execute_sqlite_query( $updated_query, $params ); - $this->set_results_from_fetched_data( - $stmt->fetchAll( $this->pdo_fetch_mode ) - ); + if ( $this->is_information_schema_query ) { + $this->set_results_from_fetched_data( + $this->strip_sqlite_system_tables( + $stmt->fetchAll( $this->pdo_fetch_mode ) + ) + ); + } else { + $this->set_results_from_fetched_data( + $stmt->fetchAll( $this->pdo_fetch_mode ) + ); + } } /** @@ -1577,6 +1672,29 @@ private function preprocess_string_literal( $value ) { return $value; } + private function preprocess_like_expr( &$token ) { + /* + * This code handles escaped wildcards in LIKE clauses. + * If we are within a LIKE experession, we look for \_ and \%, the + * escaped LIKE wildcards, the ones where we want a literal, not a + * wildcard match. We change the \ escape for an ASCII \x1a (SUB) character, + * so the \ characters won't get munged. + * These \_ and \% escape sequences are in the token name, because + * the lexer has already done stripcslashes on the value. + */ + if ( $this->like_expression_nesting > 0 ) { + /* Remove the quotes around the name. */ + $unescaped_value = mb_substr( $token->token, 1, -1, 'UTF-8' ); + if ( str_contains( $unescaped_value, '\_') || str_contains( $unescaped_value, '\%') ) { + $this->like_escape_count ++; + return str_replace( + array ( '\_', '\%' ), + array ( self::LIKE_ESCAPE_CHAR . '_', self::LIKE_ESCAPE_CHAR . '%' ), + $unescaped_value ); + } + } + return $token->value; + } /** * Translate CAST() function when we want to cast to BINARY. * @@ -1620,11 +1738,15 @@ private function translate_expression( $token ) { $this->skip_from_dual( $token ) || $this->translate_concat_function( $token ) || $this->translate_concat_comma_to_pipes( $token ) + || $this->translate_function_aliases( $token ) || $this->translate_cast_as_binary( $token ) || $this->translate_date_add_sub( $token ) || $this->translate_date_format( $token ) || $this->translate_interval( $token ) || $this->translate_regexp_functions( $token ) + || $this->capture_group_by( $token ) + || $this->translate_ungrouped_having( $token ) + || $this->translate_like_escape( $token ) ); } @@ -1727,16 +1849,18 @@ private function remember_last_reserved_keyword( $token ) { */ private function extract_bound_parameter( $token, &$params ) { if ( ! $token->matches( - WP_SQLite_Token::TYPE_STRING, - WP_SQLite_Token::FLAG_STRING_SINGLE_QUOTES - ) - || 'AS' === $this->last_reserved_keyword + WP_SQLite_Token::TYPE_STRING, + WP_SQLite_Token::FLAG_STRING_SINGLE_QUOTES + ) + || 'AS' === $this->last_reserved_keyword ) { return false; } $param_name = ':param' . count( $params ); - $params[ $param_name ] = $this->preprocess_string_literal( $token->value ); + $value = $this->preprocess_like_expr( $token ); + $value = $this->preprocess_string_literal( $value ); + $params[ $param_name ] = $value; $this->rewriter->skip(); $this->rewriter->add( new WP_SQLite_Token( $param_name, WP_SQLite_Token::TYPE_STRING, WP_SQLite_Token::FLAG_STRING_SINGLE_QUOTES ) ); $this->rewriter->add( new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ) ); @@ -1823,11 +1947,46 @@ private function translate_date_add_sub( $token ) { return true; } + /** + * Convert function aliases. + * + * @param object $token The current token. + * + * @return bool False when no match, true when this function consumes the token. + * + * @todo LENGTH and CHAR_LENGTH aren't always the same in MySQL for utf8 characters. They are in SQLite. + */ + private function translate_function_aliases( $token ) { + if ( ! $token->matches + ( + WP_SQLite_Token::TYPE_KEYWORD, + WP_SQLite_Token::FLAG_KEYWORD_FUNCTION, + array( 'SUBSTRING', 'CHAR_LENGTH' ) + ) + ) { + return false; + } + switch ( $token->value ) { + case 'SUBSTRING': + $name = 'SUBSTR'; + break; + case 'CHAR_LENGTH': + $name = 'LENGTH'; + break; + default: + $name = $token->value; + break; + } + $this->rewriter->skip(); + $this->rewriter->add( new WP_SQLite_Token( $name, $token->type, $token->flags ) ); + + return true; + } + /** * Translate VALUES() function. * * @param WP_SQLite_Token $token The token to translate. - * @param bool $is_in_duplicate_section Whether the VALUES() function is in a duplicate section. * * @return bool */ @@ -2076,6 +2235,180 @@ private function translate_regexp_functions( $token ) { return true; } + /** + * Detect GROUP BY. + * + * @todo edgecase Fails on a statement with GROUP BY nested in an outer HAVING without GROUP BY. + * + * @param WP_SQLite_Token $token The token to translate. + * + * @return bool + */ + private function capture_group_by( $token ) { + if ( + ! $token->matches( + WP_SQLite_Token::TYPE_KEYWORD, + WP_SQLite_Token::FLAG_KEYWORD_RESERVED, + array( 'GROUP' ) + ) + ) { + return false; + } + $next = $this->rewriter->peek_nth( 2 )->value; + if ( 'BY' !== strtoupper( $next ) ) { + return false; + } + + $this->has_group_by = true; + + return false; + } + + /** + * Translate WHERE something HAVING something to WHERE something AND something. + * + * @param WP_SQLite_Token $token The token to translate. + * + * @return bool + */ + private function translate_ungrouped_having( $token ) { + if ( + ! $token->matches( + WP_SQLite_Token::TYPE_KEYWORD, + WP_SQLite_Token::FLAG_KEYWORD_RESERVED, + array( 'HAVING' ) + ) + ) { + return false; + } + if ( $this->has_group_by ) { + return false; + } + $this->rewriter->skip(); + $this->rewriter->add( new WP_SQLite_Token( 'AND', WP_SQLite_Token::TYPE_KEYWORD ) ); + + return true; + } + + /** + * Rewrite LIKE '\_whatever' as LIKE '\_whatever' ESCAPE '\' . + * + * We look for keyword LIKE. On seeing it we set a flag. + * If the flag is set, we emit ESCAPE '\' before the next keyword. + * + * @param WP_SQLite_Token $token The token to translate. + * + * @return bool + */ + private function translate_like_escape( $token ) { + + if ( 0 === $this->like_expression_nesting ) { + $is_like = $token->matches( WP_SQLite_Token::TYPE_KEYWORD, null, array( 'LIKE' ) ); + /* is this the LIKE keyword? If so set the flag. */ + if ( $is_like ) { + $this->like_expression_nesting = 1; + } + } else { + /* open parenthesis during LIKE parameter, count it. */ + if ( $token->matches( WP_SQLite_Token::TYPE_OPERATOR, null, array( '(' ) ) ) { + $this->like_expression_nesting ++; + + return false; + } + + /* close parenthesis matching open parenthesis during LIKE parameter, count it. */ + if ( $this->like_expression_nesting > 1 && $token->matches( WP_SQLite_Token::TYPE_OPERATOR, null, array( ')' ) ) ) { + $this->like_expression_nesting --; + + return false; + } + + /* a keyword, a commo, a semicolon, the end of the statement, or a close parenthesis */ + $is_like_finished = $token->matches( WP_SQLite_Token::TYPE_KEYWORD ) + || $token->matches( WP_SQLite_Token::TYPE_DELIMITER, null, array( ';' ) ) || ( WP_SQLite_Token::TYPE_DELIMITER === $token->type && null === $token->value ) + || $token->matches( WP_SQLite_Token::TYPE_OPERATOR, null, array( ')', ',' ) ); + + if ( $is_like_finished ) { + /* Here we have another keyword encountered with the LIKE in progress. + * Emit the ESCAPE clause. + */ + if ( $this->like_escape_count > 0 ) { + /* If we need the ESCAPE clause emit it. */ + $this->rewriter->add( new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_DELIMITER ) ); + $this->rewriter->add( new WP_SQLite_Token( 'ESCAPE', WP_SQLite_Token::TYPE_KEYWORD ) ); + $this->rewriter->add( new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_DELIMITER ) ); + $this->rewriter->add( new WP_SQLite_Token( "'" . self::LIKE_ESCAPE_CHAR . "'", WP_SQLite_Token::TYPE_STRING ) ); + $this->rewriter->add( new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_DELIMITER ) ); + } + $this->like_escape_count = 0; + $this->like_expression_nesting = 0; + } + } + + return false; + } + + /** + * Rewrite a query from the MySQL information_schema. + * + * @param string $updated_query The query to rewrite + * + * @return string The query for use by SQLite + */ + private function get_information_schema_query( $updated_query ) { +// @TODO: Actually rewrite the columns. + $normalized_query = preg_replace('/\s+/', ' ', strtolower( $updated_query )); + if ( str_contains( $normalized_query, 'bytes' ) ) { + // Count rows per table. + $tables = + $this->execute_sqlite_query( "SELECT name as `table_name` FROM sqlite_master WHERE type='table' ORDER BY name" )->fetchAll(); + $tables = $this->strip_sqlite_system_tables( $tables ); + + $rows = '(CASE '; + foreach ( $tables as $table ) { + $table_name = $table['table_name']; + $count = $this->execute_sqlite_query( "SELECT COUNT(1) as `count` FROM $table_name" )->fetch(); + $rows .= " WHEN name = '$table_name' THEN {$count['count']} "; + } + $rows .= 'ELSE 0 END) '; + $updated_query = + "SELECT name as `table_name`, $rows as `rows`, 0 as `bytes` FROM sqlite_master WHERE type='table' ORDER BY name"; + } elseif (str_contains( $normalized_query, 'count(*)' ) && ! str_contains ( $normalized_query, 'table_name =') ) { + //@TODO This is a guess that the caller wants a count of tables. + $list = array (); + foreach ( $this->sqlite_system_tables as $system_table => $name) { + $list [] = "'" . $system_table . "'"; + } + $list = implode (', ', $list ); + $sql = "SELECT COUNT(*) FROM sqlite_master WHERE type='table' AND name NOT IN ($list)"; + $table_count = $this->execute_sqlite_query( $sql )->fetch(); + $updated_query = "SELECT " . $table_count[0] . " AS num"; + + $this->is_information_schema_query = false; + } else { + $updated_query = + "SELECT name as `table_name`, 'myisam' as `engine`, 0 as `data_length`, 0 as `index_length`, 0 as `data_free` FROM sqlite_master WHERE type='table' ORDER BY name"; + } + + return $updated_query; + } + + /** + * Remove system table rows from resultsets of information_schema tables. + * + * @param array $tables The result set. + * + * @return array The filtered result set. + */ + private function strip_sqlite_system_tables( $tables ) { + return array_values( + array_filter( $tables, function ( $table ) { + $table_name = property_exists( $table, 'Name' ) ? $table->Name : $table->table_name; + return ! array_key_exists( $table_name, $this->sqlite_system_tables); + }, ARRAY_FILTER_USE_BOTH ) + ); + } + /** * Translate the ON DUPLICATE KEY UPDATE clause. * @@ -2190,7 +2523,7 @@ private function get_primary_keys( $table_name ) { /** * Get the keys for a table. * - * @param string $table_name Table name. + * @param string $table_name Table name. * @param bool $only_unique Only return unique keys. * * @return array @@ -2608,9 +2941,35 @@ private function execute_show() { $stmt = $this->execute_sqlite_query( "PRAGMA table_info(\"$table_name\");" ); - $this->set_results_from_fetched_data( - $stmt->fetchAll( $this->pdo_fetch_mode ) + /* @todo we may need to add the Extra column if anybdy needs it. 'auto_increment' is the value */ + $name_map = array( + 'name' => 'Field', + 'type' => 'Type', + 'dflt_value' => 'Default', + 'cid' => null, + 'notnull' => null, + 'pk' => null, ); + $columns = $stmt->fetchAll( $this->pdo_fetch_mode ); + $columns = array_map( function ( $row ) use ( $name_map ) { + $new = array(); + $is_object = is_object( $row ); + $row = $is_object ? (array) $row : $row; + foreach ( $row as $k => $v ) { + $k = array_key_exists( $k, $name_map ) ? $name_map [ $k ] : $k; + if ( $k ) { + $new[ $k ] = $v; + } + } + if ( array_key_exists( 'notnull', $row ) ) { + $new['Null'] = ( '1' === $row ['notnull'] ) ? 'NO' : 'YES'; + } + if ( array_key_exists( 'pk', $row ) ) { + $new['Key'] = ( '1' === $row ['pk'] ) ? 'PRI' : ''; + } + return $is_object ? (object) $new : $new; + }, $columns ); + $this->set_results_from_fetched_data( $columns ); return; case 'INDEX FROM': @@ -2682,6 +3041,28 @@ private function execute_show() { $this->set_results_from_fetched_data( $results ); + + return; + + case 'TABLE STATUS': // FROM `database`. + $this->rewriter->skip(); + $database_expression = $this->rewriter->skip(); + $stmt = $this->execute_sqlite_query( + "SELECT name as `Name`, 'myisam' as `Engine`, 0 as `Data_length`, 0 as `Index_length`, 0 as `Data_free` FROM sqlite_master WHERE type='table' ORDER BY name" + ); + + $tables = $this->strip_sqlite_system_tables( $stmt->fetchAll( $this->pdo_fetch_mode ) ); + foreach ( $tables as $table ) { + $tableName = $table->Name; + $stmt = $this->execute_sqlite_query( "SELECT COUNT(1) as `Rows` FROM $tableName" ); + $rows = $stmt->fetchall( $this->pdo_fetch_mode ); + $table->Rows = $rows[0]->Rows; + } + + $this->set_results_from_fetched_data( + $this->strip_sqlite_system_tables( $tables ) + ); + return; case 'TABLES LIKE': @@ -2753,10 +3134,10 @@ private function skip_mysql_data_type() { // Skip the int keyword. $int_maybe = $this->rewriter->peek(); if ( $int_maybe && $int_maybe->matches( - WP_SQLite_Token::TYPE_KEYWORD, - null, - array( 'UNSIGNED' ) - ) + WP_SQLite_Token::TYPE_KEYWORD, + null, + array( 'UNSIGNED' ) + ) ) { $mysql_data_type .= ' ' . $this->rewriter->skip()->token; } @@ -2837,11 +3218,11 @@ private function normalize_mysql_index_type( $index_type ) { $index_type = preg_replace( '/INDEX$/', 'KEY', $index_type ); $index_type = preg_replace( '/ KEY$/', '', $index_type ); if ( - 'KEY' === $index_type - || 'PRIMARY' === $index_type - || 'UNIQUE' === $index_type - || 'FULLTEXT' === $index_type - || 'SPATIAL' === $index_type + 'KEY' === $index_type + || 'PRIMARY' === $index_type + || 'UNIQUE' === $index_type + || 'FULLTEXT' === $index_type + || 'SPATIAL' === $index_type ) { return $index_type; } @@ -2868,6 +3249,94 @@ private function mysql_index_type_to_sqlite_type( $normalized_mysql_index_type ) return 'INDEX'; } + /** + * Executes a CHECK statement. + */ + private function execute_check() { + $this->rewriter->skip(); // CHECK + $this->rewriter->skip(); // TABLE + $table_name = $this->rewriter->consume()->value; // table_name + + $tables = + $this->execute_sqlite_query( + "SELECT name as `table_name` FROM sqlite_master WHERE type='table' AND name = :table_name ORDER BY name", + array( $table_name ) + )->fetchAll(); + + if ( is_array( $tables ) && 1 === count( $tables ) && $table_name === $tables[0]['table_name'] ) { + + $this->set_results_from_fetched_data( array( + (object) + array( + 'Table' => $table_name, + 'Op' => 'check', + 'Msg_type' => 'status', + 'Msg_text' => 'OK', + ), + ) ); + } else { + + $this->set_results_from_fetched_data( array( + (object) array( + 'Table' => $table_name, + 'Op' => 'check', + 'Msg_type' => 'Error', + 'Msg_text' => "Table '$table_name' doesn't exist", + ), + (object) array( + 'Table' => $table_name, + 'Op' => 'check', + 'Msg_type' => 'status', + 'Msg_text' => 'Operation failed', + ), + ) ); + } + } + + /** + * Handle an OPTIMIZE / REPAIR / ANALYZE TABLE statement, by using VACUUM just once, at shutdown. + * + * @param string $query type + */ + private function execute_optimize( $query_type ) { // OPTIMIZE TABLE tablename + $this->rewriter->skip(); + $this->rewriter->skip(); + $table_name = $this->rewriter->skip()->value; + $status = ''; + + if ( ! $this->vacuum_requested ) { + $this->vacuum_requested = true; + if ( function_exists( 'add_action' ) ) { + $status = "SQLite does not support $query_type, doing VACUUM instead"; + add_action( + 'shutdown', + function () { + $this->execute_sqlite_query( 'VACUUM' ); + } + ); + } else { + /* add_action isn't available in the unit test environment, and we're deep in a transaction. */ + $status = "SQLite unit testing does not support $query_type."; + } + } + $resultset = array( + (object) array( + "Table" => $table_name, + "Op" => strtolower( $query_type ), + "Msg_type" => "note", + "Msg_text" => $status, + ), + (object) array( + "Table" => $table_name, + "Op" => strtolower( $query_type ), + "Msg_type" => "status", + "Msg_text" => "OK", + ), + ); + + $this->set_results_from_fetched_data( $resultset ); + } + /** * Error handler. * @@ -2876,9 +3345,8 @@ private function mysql_index_type_to_sqlite_type( $normalized_mysql_index_type ) * @return bool Always false. */ private function handle_error( Exception $err ) { - $message = $err->getMessage(); - $err_message = sprintf( 'Problem preparing the PDO SQL Statement. Error was: %s. trace: %s', $message, $err->getTraceAsString() ); - $this->set_error( __LINE__, __FUNCTION__, $err_message ); + $message = $err->getMessage(); + $this->set_error( __LINE__, __FUNCTION__, $message ); $this->return_value = false; return false; } @@ -2936,7 +3404,7 @@ public function get_error_message() { } $output = '
 
' . PHP_EOL; - $output .= '
' . PHP_EOL; + $output .= '
' . PHP_EOL; $output .= '

MySQL query:

' . PHP_EOL; $output .= '

' . $this->mysql_query . '

' . PHP_EOL; $output .= '

Queries made or created this session were:

' . PHP_EOL; @@ -2949,13 +3417,12 @@ public function get_error_message() { $output .= '' . PHP_EOL; $output .= '
' . PHP_EOL; foreach ( $this->error_messages as $num => $m ) { - $output .= '
' . PHP_EOL; + $output .= '
' . PHP_EOL; $output .= sprintf( 'Error occurred at line %1$d in Function %2$s. Error message was: %3$s.', - (int) $this->errors[ $num ]['line'], + (int) $this->errors[ $num ]['line'], '' . htmlspecialchars( $this->errors[ $num ]['function'] ) . '', - $m - ) . PHP_EOL; + $m ) . PHP_EOL; $output .= '
' . PHP_EOL; } @@ -2963,14 +3430,14 @@ public function get_error_message() { throw new Exception(); } catch ( Exception $e ) { $output .= '

Backtrace:

' . PHP_EOL; - $output .= '
' . htmlspecialchars( $e->getTraceAsString() ) . '
' . PHP_EOL; + $output .= '
' . $e->getTraceAsString() . '
' . PHP_EOL; } return $output; } /** - * Executes a query in SQLite – for internal use only. + * Executes a query in SQLite. * * @param mixed $sql The query to execute. * @param mixed $params The parameters to bind to the query. @@ -2982,14 +3449,27 @@ public function get_error_message() { * @type * $result The value returned by $stmt. * } */ - private function execute_sqlite_query( $sql, $params = array() ) { + public function execute_sqlite_query( $sql, $params = array() ) { $this->executed_sqlite_queries[] = array( 'sql' => $sql, 'params' => $params, ); - $stmt = $this->pdo->prepare( $sql ); - $this->last_exec_returned = $stmt->execute( $params ); + $stmt = $this->pdo->prepare( $sql ); + if ( false === $stmt || null === $stmt ) { + $this->last_exec_returned = null; + $info = $this->pdo->errorInfo(); + $this->last_sqlite_error = $info[0] . ' ' . $info[2]; + throw new PDOException( implode( ' ', array( 'Error:', $info[0], $info[2], 'SQLite:', $sql ) ), $info[1] ); + } + $returned = $stmt->execute( $params ); + $this->last_exec_returned = $returned; + if ( ! $returned ) { + $info = $stmt->errorInfo(); + $this->last_sqlite_error = $info[0] . ' ' . $info[2]; + throw new PDOException( implode( ' ', array( 'Error:', $info[0], $info[2], 'SQLite:', $sql ) ), $info[1] ); + } + return $stmt; } @@ -3025,18 +3505,21 @@ private function set_result_from_affected_rows( $override = null ) { * Method to clear previous data. */ private function flush() { - $this->mysql_query = ''; - $this->results = null; - $this->last_exec_returned = null; - $this->last_insert_id = null; - $this->affected_rows = null; - $this->column_data = array(); - $this->num_rows = null; - $this->return_value = null; - $this->error_messages = array(); - $this->is_error = false; - $this->executed_sqlite_queries = array(); - $this->last_exec_returned = null; + $this->mysql_query = ''; + $this->results = null; + $this->last_exec_returned = null; + $this->last_insert_id = null; + $this->affected_rows = null; + $this->column_data = array(); + $this->num_rows = null; + $this->return_value = null; + $this->error_messages = array(); + $this->is_error = false; + $this->executed_sqlite_queries = array(); + $this->like_expression_nesting = 0; + $this->like_escape_count = 0; + $this->is_information_schema_query = false; + $this->has_group_by = false; } /** diff --git a/wp-includes/sqlite/install-functions.php b/wp-includes/sqlite/install-functions.php index 1233c6b6..736034ca 100644 --- a/wp-includes/sqlite/install-functions.php +++ b/wp-includes/sqlite/install-functions.php @@ -40,9 +40,9 @@ function sqlite_make_db_sqlite() { continue; } - $result = $translator->query($query); - if( false === $result ) { - throw new PDOException($translator->get_error_message()); + $result = $translator->query( $query ); + if ( false === $result ) { + throw new PDOException( $translator->get_error_message() ); } } $translator->commit();