From aac00ceee4e00c66ecd5875589508f7160e05c50 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Wed, 13 Nov 2024 12:46:25 +0100 Subject: [PATCH 01/36] Split, cleanup, and reorganize the SQLite driver prototype --- .gitattributes | 2 +- tests/tools/dump-sqlite-query.php | 21 ++ wp-includes/mysql/class-wp-mysql-token.php | 4 + .../sqlite-ast/class-wp-sqlite-driver.php | 353 ++++++++---------- .../sqlite-ast/class-wp-sqlite-expression.php | 36 ++ .../class-wp-sqlite-query-builder.php | 38 ++ .../class-wp-sqlite-token-factory.php | 178 +-------- .../sqlite-ast/class-wp-sqlite-token.php | 16 + 8 files changed, 290 insertions(+), 358 deletions(-) create mode 100644 tests/tools/dump-sqlite-query.php rename wip/run-mysql-driver.php => wp-includes/sqlite-ast/class-wp-sqlite-driver.php (51%) create mode 100644 wp-includes/sqlite-ast/class-wp-sqlite-expression.php create mode 100644 wp-includes/sqlite-ast/class-wp-sqlite-query-builder.php rename wip/SQLiteDriver.php => wp-includes/sqlite-ast/class-wp-sqlite-token-factory.php (64%) create mode 100644 wp-includes/sqlite-ast/class-wp-sqlite-token.php diff --git a/.gitattributes b/.gitattributes index e1ddbbb2..5a8431ea 100644 --- a/.gitattributes +++ b/.gitattributes @@ -7,7 +7,7 @@ phpcs.xml.dist export-ignore phpunit.xml.dist export-ignore /grammar-tools export-ignore /tests export-ignore -/wip export-ignore /wp-includes/mysql export-ignore /wp-includes/parser export-ignore +/wp-includes/sqlite-ast export-ignore wp-includes/sqlite/class-wp-sqlite-crosscheck-db.php export-ignore diff --git a/tests/tools/dump-sqlite-query.php b/tests/tools/dump-sqlite-query.php new file mode 100644 index 00000000..4cf4fdc1 --- /dev/null +++ b/tests/tools/dump-sqlite-query.php @@ -0,0 +1,21 @@ +run_query( $query ); diff --git a/wp-includes/mysql/class-wp-mysql-token.php b/wp-includes/mysql/class-wp-mysql-token.php index 52512645..ba112a76 100644 --- a/wp-includes/mysql/class-wp-mysql-token.php +++ b/wp-includes/mysql/class-wp-mysql-token.php @@ -29,6 +29,10 @@ public function get_name() { return WP_MySQL_Lexer::get_token_name( $this->type ); } + public function extract_value() { + return $this->get_text(); + } + public function __toString() { return $this->text . '<' . $this->type . ',' . $this->get_name() . '>'; } diff --git a/wip/run-mysql-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php similarity index 51% rename from wip/run-mysql-driver.php rename to wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 7f257d74..9f53f91f 100644 --- a/wip/run-mysql-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -1,54 +1,7 @@ -parse(); -// print_r($parse_tree); -// die(); -// echo 'a'; - -$query = <<run_query( $query ); -die(); -// $transformer = new SQLTransformer($parse_tree, 'sqlite'); -// $expression = $transformer->transform(); -// print_r($expression); - -class MySQLonSQLiteDriver { - private $grammar = false; +has_found_rows_call = false; $this->last_calc_rows_result = null; - $parser = new WP_MySQL_Parser( $this->grammar, tokenize_query( $query ) ); - $parse_tree = $parser->parse(); - $expr = $this->translate_query( $parse_tree ); - $expr = $this->rewrite_sql_calc_found_rows( $expr ); + $lexer = new WP_MySQL_Lexer( $query ); + $tokens = $lexer->remaining_tokens(); + + $parser = new WP_MySQL_Parser( $this->grammar, $tokens ); + $ast = $parser->parse(); + $expr = $this->translate_query( $ast ); + $expr = $this->rewrite_sql_calc_found_rows( $expr ); - $sqlite_query = SQLiteQueryBuilder::stringify( $expr ) . ''; + $sqlite_query = WP_SQLite_Query_Builder::stringify( $expr ); - // Returning the expery just for now for testing. In the end, we'll + // Returning the query just for now for testing. In the end, we'll // run it and return the SQLite interaction result. return $sqlite_query; } - private function rewrite_sql_calc_found_rows( SQLiteExpression $expr ) { + private function rewrite_sql_calc_found_rows( WP_SQLite_Expression $expr ) { if ( $this->has_found_rows_call && ! $this->has_sql_calc_found_rows && null === $this->last_calc_rows_result ) { throw new Exception( 'FOUND_ROWS() called without SQL_CALC_FOUND_ROWS' ); } @@ -82,11 +38,11 @@ private function rewrite_sql_calc_found_rows( SQLiteExpression $expr ) { if ( $this->has_sql_calc_found_rows ) { $expr_to_run = $expr; if ( $this->has_found_rows_call ) { - $expr_without_found_rows = new SQLiteExpression( array() ); + $expr_without_found_rows = new WP_SQLite_Expression( array() ); foreach ( $expr->elements as $k => $element ) { - if ( SQLiteToken::TYPE_IDENTIFIER === $element->type && 'FOUND_ROWS' === $element->value ) { + if ( WP_SQLite_Token::TYPE_IDENTIFIER === $element->type && 'FOUND_ROWS' === $element->value ) { $expr_without_found_rows->add_token( - SQLiteTokenFactory::value( 0 ) + WP_SQLite_Token_Factory::value( 0 ) ); } else { $expr_without_found_rows->add_token( $element ); @@ -96,23 +52,22 @@ private function rewrite_sql_calc_found_rows( SQLiteExpression $expr ) { } // ...remove the LIMIT clause... - $query = 'SELECT COUNT(*) as cnt FROM (' . SQLiteQueryBuilder::stringify( $expr_to_run ) . ');'; + $query = 'SELECT COUNT(*) as cnt FROM (' . WP_SQLite_Query_Builder::stringify( $expr_to_run ) . ');'; // ...run $query... // $result = ... - - $this->last_calc_rows_result = $result['cnt']; + // $this->last_calc_rows_result = $result['cnt']; } if ( ! $this->has_found_rows_call ) { return $expr; } - $expr_with_found_rows_result = new SQLiteExpression( array() ); + $expr_with_found_rows_result = new WP_SQLite_Expression( array() ); foreach ( $expr->elements as $k => $element ) { - if ( SQLiteToken::TYPE_IDENTIFIER === $element->type && 'FOUND_ROWS' === $element->value ) { + if ( WP_SQLite_Token::TYPE_IDENTIFIER === $element->type && 'FOUND_ROWS' === $element->value ) { $expr_with_found_rows_result->add_token( - SQLiteTokenFactory::value( $this->last_calc_rows_result ) + WP_SQLite_Token_Factory::value( $this->last_calc_rows_result ) ); } else { $expr_with_found_rows_result->add_token( $element ); @@ -121,55 +76,54 @@ private function rewrite_sql_calc_found_rows( SQLiteExpression $expr ) { return $expr_with_found_rows_result; } - private function translate_query( $parse_tree ) { - if ( null === $parse_tree ) { + private function translate_query( $ast ) { + if ( null === $ast ) { return null; } - if ( $parse_tree instanceof WP_MySQL_Token ) { - $token = $parse_tree; + if ( $ast instanceof WP_MySQL_Token ) { + $token = $ast; switch ( $token->type ) { case WP_MySQL_Lexer::EOF: - return new SQLiteExpression( array() ); + return new WP_SQLite_Expression( array() ); case WP_MySQL_Lexer::IDENTIFIER: - return new SQLiteExpression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::identifier( + WP_SQLite_Token_Factory::identifier( trim( $token->text, '`"' ) ), ) ); default: - return new SQLiteExpression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( $token->text ), + WP_SQLite_Token_Factory::raw( $token->text ), ) ); } } - if ( ! ( $parse_tree instanceof WP_Parser_Node ) ) { - throw new Exception( 'translateQuery only accepts MySQLToken and ParseTree instances' ); + if ( ! ( $ast instanceof WP_Parser_Node ) ) { + throw new Exception( 'translate_query only accepts WP_MySQL_Token and WP_Parser_Node instances' ); } - $rule_name = $parse_tree->rule_name; + $rule_name = $ast->rule_name; switch ( $rule_name ) { case 'indexHintList': - // SQLite doesn't support index hints. Let's - // skip them. + // SQLite doesn't support index hints. Let's skip them. return null; case 'querySpecOption': - $token = $parse_tree->get_token(); + $token = $ast->get_token(); switch ( $token->type ) { case WP_MySQL_Lexer::ALL_SYMBOL: case WP_MySQL_Lexer::DISTINCT_SYMBOL: - return new SQLiteExpression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( $token->text ), + WP_SQLite_Token_Factory::raw( $token->text ), ) ); case WP_MySQL_Lexer::SQL_CALC_FOUND_ROWS_SYMBOL: @@ -179,7 +133,7 @@ private function translate_query( $parse_tree ) { // we'll need to run the current SQL query without any // LIMIT clause, and then substitute the FOUND_ROWS() // function with a literal number of rows found. - return new SQLiteExpression( array() ); + return new WP_SQLite_Expression( array() ); } // Otherwise, fall through. @@ -188,8 +142,8 @@ private function translate_query( $parse_tree ) { // FROM DUAL statement, as FROM mytable, DUAL is a syntax // error. if ( - $parse_tree->has_token( WP_MySQL_Lexer::DUAL_SYMBOL ) && - ! $parse_tree->has_child( 'tableReferenceList' ) + $ast->has_token( WP_MySQL_Lexer::DUAL_SYMBOL ) && + ! $ast->has_child( 'tableReferenceList' ) ) { return null; } @@ -228,6 +182,7 @@ private function translate_query( $parse_tree ) { case 'queryExpressionParens': case 'queryPrimary': case 'querySpecification': + case 'queryTerm': case 'selectAlias': case 'selectItem': case 'selectItemList': @@ -264,26 +219,26 @@ private function translate_query( $parse_tree ) { case 'direction': case 'orderExpression': $child_expressions = array(); - foreach ( $parse_tree->children as $child ) { + foreach ( $ast->children as $child ) { $child_expressions[] = $this->translate_query( $child ); } - return new SQLiteExpression( $child_expressions ); + return new WP_SQLite_Expression( $child_expressions ); case 'textStringLiteral': - return new SQLiteExpression( + return new WP_SQLite_Expression( array( - $parse_tree->has_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT ) ? - SQLiteTokenFactory::double_quoted_value( $parse_tree->get_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT )->text ) : false, - $parse_tree->has_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT ) ? - SQLiteTokenFactory::raw( $parse_tree->get_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT )->text ) : false, + $ast->has_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT ) ? + WP_SQLite_Token_Factory::double_quoted_value( $ast->get_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT )->text ) : false, + $ast->has_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT ) ? + WP_SQLite_Token_Factory::raw( $ast->get_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT )->text ) : false, ) ); case 'functionCall': - return $this->translate_function_call( $parse_tree ); + return $this->translate_function_call( $ast ); case 'runtimeFunctionCall': - return $this->translate_runtime_function_call( $parse_tree ); + return $this->translate_runtime_function_call( $ast ); default: // var_dump(count($ast->children)); @@ -292,9 +247,9 @@ private function translate_query( $parse_tree ) { // echo $child->getText(); // echo "\n\n"; // } - return new SQLiteExpression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( + WP_SQLite_Token_Factory::raw( $rule_name ), ) @@ -302,33 +257,33 @@ private function translate_query( $parse_tree ) { } } - private function translate_runtime_function_call( $parse_tree ): SQLiteExpression { - $name_token = $parse_tree->children[0]; + private function translate_runtime_function_call( $ast ): WP_SQLite_Expression { + $name_token = $ast->children[0]; switch ( strtoupper( $name_token->text ) ) { case 'ADDDATE': case 'DATE_ADD': - $args = $parse_tree->get_children( 'expr' ); - $interval = $parse_tree->get_child( 'interval' ); + $args = $ast->get_children( 'expr' ); + $interval = $ast->get_child( 'interval' ); $timespan = $interval->get_child( 'intervalTimeStamp' )->get_token()->text; - return SQLiteTokenFactory::create_function( + return WP_SQLite_Token_Factory::create_function( 'DATETIME', array( $this->translate_query( $args[0] ), - new SQLiteExpression( + new WP_SQLite_Expression( array( - SQLiteTokenFactory::value( '+' ), - SQLiteTokenFactory::raw( '||' ), + WP_SQLite_Token_Factory::value( '+' ), + WP_SQLite_Token_Factory::raw( '||' ), $this->translate_query( $args[1] ), - SQLiteTokenFactory::raw( '||' ), - SQLiteTokenFactory::value( $timespan ), + WP_SQLite_Token_Factory::raw( '||' ), + WP_SQLite_Token_Factory::value( $timespan ), ) ), ) ); case 'DATE_SUB': - // return new Expression([ + // return new WP_SQLite_Expression([ // SQLiteTokenFactory::raw("DATETIME("), // $args[0], // SQLiteTokenFactory::raw(", '-'"), @@ -337,16 +292,16 @@ private function translate_runtime_function_call( $parse_tree ): SQLiteExpressio // ]); case 'VALUES': - $column = $parse_tree->get_child()->get_descendant( 'pureIdentifier' ); + $column = $ast->get_child()->get_descendant( 'pureIdentifier' ); if ( ! $column ) { throw new Exception( 'VALUES() calls without explicit column names are unsupported' ); } - $colname = $column->get_token()->extractValue(); - return new SQLiteExpression( + $colname = $column->get_token()->extract_value(); + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( 'excluded.' ), - SQLiteTokenFactory::identifier( $colname ), + WP_SQLite_Token_Factory::raw( 'excluded.' ), + WP_SQLite_Token_Factory::identifier( $colname ), ) ); default: @@ -354,7 +309,7 @@ private function translate_runtime_function_call( $parse_tree ): SQLiteExpressio } } - private function translate_function_call( $function_call_tree ): SQLiteExpression { + private function translate_function_call( $function_call_tree ): WP_SQLite_Expression { $name = $function_call_tree->get_child( 'pureIdentifier' )->get_token()->text; $args = array(); foreach ( $function_call_tree->get_child( 'udfExprList' )->get_children() as $node ) { @@ -383,27 +338,27 @@ private function translate_function_call( $function_call_tree ): SQLiteExpressio case 'PI': case 'LTRIM': case 'RTRIM': - return SQLiteTokenFactory::create_function( $name, $args ); + return WP_SQLite_Token_Factory::create_function( $name, $args ); case 'CEIL': case 'CEILING': - return SQLiteTokenFactory::create_function( 'CEIL', $args ); + return WP_SQLite_Token_Factory::create_function( 'CEIL', $args ); case 'COT': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( '1 / ' ), - SQLiteTokenFactory::create_function( 'TAN', $args ), + WP_SQLite_Token_Factory::raw( '1 / ' ), + WP_SQLite_Token_Factory::create_function( 'TAN', $args ), ) ); case 'LN': case 'LOG': case 'LOG2': - return SQLiteTokenFactory::create_function( 'LOG', $args ); + return WP_SQLite_Token_Factory::create_function( 'LOG', $args ); case 'LOG10': - return SQLiteTokenFactory::create_function( 'LOG10', $args ); + return WP_SQLite_Token_Factory::create_function( 'LOG10', $args ); // case 'MOD': // return $this->transformBinaryOperation([ @@ -414,26 +369,26 @@ private function translate_function_call( $function_call_tree ): SQLiteExpressio case 'POW': case 'POWER': - return SQLiteTokenFactory::create_function( 'POW', $args ); + return WP_SQLite_Token_Factory::create_function( 'POW', $args ); // String functions case 'ASCII': - return SQLiteTokenFactory::create_function( 'UNICODE', $args ); + return WP_SQLite_Token_Factory::create_function( 'UNICODE', $args ); case 'CHAR_LENGTH': case 'LENGTH': - return SQLiteTokenFactory::create_function( 'LENGTH', $args ); + return WP_SQLite_Token_Factory::create_function( 'LENGTH', $args ); case 'CONCAT': - $concated = array( SQLiteTokenFactory::raw( '(' ) ); + $concated = array( WP_SQLite_Token_Factory::raw( '(' ) ); foreach ( $args as $k => $arg ) { $concated[] = $arg; if ( $k < count( $args ) - 1 ) { - $concated[] = SQLiteTokenFactory::raw( '||' ); + $concated[] = WP_SQLite_Token_Factory::raw( '||' ); } } - $concated[] = SQLiteTokenFactory::raw( ')' ); - return new SQLiteExpression( $concated ); + $concated[] = WP_SQLite_Token_Factory::raw( ')' ); + return new WP_SQLite_Expression( $concated ); // case 'CONCAT_WS': - // return new Expression([ + // return new WP_SQLite_Expression([ // SQLiteTokenFactory::raw("REPLACE("), // implode(" || ", array_slice($args, 1)), // SQLiteTokenFactory::raw(", '', "), @@ -441,12 +396,12 @@ private function translate_function_call( $function_call_tree ): SQLiteExpressio // SQLiteTokenFactory::raw(")") // ]); case 'INSTR': - return SQLiteTokenFactory::create_function( 'INSTR', $args ); + return WP_SQLite_Token_Factory::create_function( 'INSTR', $args ); case 'LCASE': case 'LOWER': - return SQLiteTokenFactory::create_function( 'LOWER', $args ); + return WP_SQLite_Token_Factory::create_function( 'LOWER', $args ); case 'LEFT': - return SQLiteTokenFactory::create_function( + return WP_SQLite_Token_Factory::create_function( 'SUBSTR', array( $args[0], @@ -455,7 +410,7 @@ private function translate_function_call( $function_call_tree ): SQLiteExpressio ) ); case 'LOCATE': - return SQLiteTokenFactory::create_function( + return WP_SQLite_Token_Factory::create_function( 'INSTR', array( $args[1], @@ -463,44 +418,44 @@ private function translate_function_call( $function_call_tree ): SQLiteExpressio ) ); case 'REPEAT': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( "REPLACE(CHAR(32), ' ', " ), + WP_SQLite_Token_Factory::raw( "REPLACE(CHAR(32), ' ', " ), $args[0], - SQLiteTokenFactory::raw( ')' ), + WP_SQLite_Token_Factory::raw( ')' ), ) ); case 'REPLACE': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( 'REPLACE(' ), + WP_SQLite_Token_Factory::raw( 'REPLACE(' ), implode( ', ', $args ), - SQLiteTokenFactory::raw( ')' ), + WP_SQLite_Token_Factory::raw( ')' ), ) ); case 'RIGHT': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( 'SUBSTR(' ), + WP_SQLite_Token_Factory::raw( 'SUBSTR(' ), $args[0], - SQLiteTokenFactory::raw( ', -(' ), + WP_SQLite_Token_Factory::raw( ', -(' ), $args[1], - SQLiteTokenFactory::raw( '))' ), + WP_SQLite_Token_Factory::raw( '))' ), ) ); case 'SPACE': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( "REPLACE(CHAR(32), ' ', '')" ), + WP_SQLite_Token_Factory::raw( "REPLACE(CHAR(32), ' ', '')" ), ) ); case 'SUBSTRING': case 'SUBSTR': - return SQLiteTokenFactory::create_function( 'SUBSTR', $args ); + return WP_SQLite_Token_Factory::create_function( 'SUBSTR', $args ); case 'UCASE': case 'UPPER': - return SQLiteTokenFactory::create_function( 'UPPER', $args ); + return WP_SQLite_Token_Factory::create_function( 'UPPER', $args ); case 'DATE_FORMAT': $mysql_date_format_to_sqlite_strftime = array( @@ -540,113 +495,113 @@ private function translate_function_call( $function_call_tree ): SQLiteExpressio $format = $args[1]->elements[0]->value; $new_format = strtr( $format, $mysql_date_format_to_sqlite_strftime ); - return SQLiteTokenFactory::create_function( + return WP_SQLite_Token_Factory::create_function( 'STRFTIME', array( - new Expression( array( SQLiteTokenFactory::raw( $new_format ) ) ), - new Expression( array( $args[0] ) ), + new WP_SQLite_Expression( array( WP_SQLite_Token_Factory::raw( $new_format ) ) ), + new WP_SQLite_Expression( array( $args[0] ) ), ) ); case 'DATEDIFF': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::create_function( 'JULIANDAY', array( $args[0] ) ), - SQLiteTokenFactory::raw( ' - ' ), - SQLiteTokenFactory::create_function( 'JULIANDAY', array( $args[1] ) ), + WP_SQLite_Token_Factory::create_function( 'JULIANDAY', array( $args[0] ) ), + WP_SQLite_Token_Factory::raw( ' - ' ), + WP_SQLite_Token_Factory::create_function( 'JULIANDAY', array( $args[1] ) ), ) ); case 'DAYNAME': - return SQLiteTokenFactory::create_function( + return WP_SQLite_Token_Factory::create_function( 'STRFTIME', - array( '%w', ...$args ) + array_merge( array( '%w' ), $args ) ); case 'DAY': case 'DAYOFMONTH': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( "CAST('" ), - SQLiteTokenFactory::create_function( 'STRFTIME', array( '%d', ...$args ) ), - SQLiteTokenFactory::raw( ") AS INTEGER'" ), + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%d' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), ) ); case 'DAYOFWEEK': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( "CAST('" ), - SQLiteTokenFactory::create_function( 'STRFTIME', array( '%w', ...$args ) ), - SQLiteTokenFactory::raw( ") + 1 AS INTEGER'" ), + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%w' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") + 1 AS INTEGER'" ), ) ); case 'DAYOFYEAR': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( "CAST('" ), - SQLiteTokenFactory::create_function( 'STRFTIME', array( '%j', ...$args ) ), - SQLiteTokenFactory::raw( ") AS INTEGER'" ), + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%j' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), ) ); case 'HOUR': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( "CAST('" ), - SQLiteTokenFactory::create_function( 'STRFTIME', array( '%H', ...$args ) ), - SQLiteTokenFactory::raw( ") AS INTEGER'" ), + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%H' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), ) ); case 'MINUTE': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( "CAST('" ), - SQLiteTokenFactory::create_function( 'STRFTIME', array( '%M', ...$args ) ), - SQLiteTokenFactory::raw( ") AS INTEGER'" ), + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%M' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), ) ); case 'MONTH': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( "CAST('" ), - SQLiteTokenFactory::create_function( 'STRFTIME', array( '%m', ...$args ) ), - SQLiteTokenFactory::raw( ") AS INTEGER'" ), + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%m' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), ) ); case 'MONTHNAME': - return SQLiteTokenFactory::create_function( 'STRFTIME', array( '%m', ...$args ) ); + return WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%m' ), $args ) ); case 'NOW': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( 'CURRENT_TIMESTAMP()' ), + WP_SQLite_Token_Factory::raw( 'CURRENT_TIMESTAMP()' ), ) ); case 'SECOND': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( "CAST('" ), - SQLiteTokenFactory::create_function( 'STRFTIME', array( '%S', ...$args ) ), - SQLiteTokenFactory::raw( ") AS INTEGER'" ), + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%S' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), ) ); case 'TIMESTAMP': - return new Expression( - array( - SQLiteTokenFactory::raw( 'DATETIME(' ), - ...$args, - SQLiteTokenFactory::raw( ')' ), + return new WP_SQLite_Expression( + array_merge( + array( WP_SQLite_Token_Factory::raw( 'DATETIME(' ) ), + $args, + array( WP_SQLite_Token_Factory::raw( ')' ) ) ) ); case 'YEAR': - return new Expression( + return new WP_SQLite_Expression( array( - SQLiteTokenFactory::raw( "CAST('" ), - SQLiteTokenFactory::create_function( 'STRFTIME', array( '%Y', ...$args ) ), - SQLiteTokenFactory::raw( ") AS INTEGER'" ), + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%Y' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), ) ); case 'FOUND_ROWS': $this->has_found_rows_call = true; - return new Expression( + return new WP_SQLite_Expression( array( // Post-processed in handleSqlCalcFoundRows() - SQLiteTokenFactory::raw( 'FOUND_ROWS' ), + WP_SQLite_Token_Factory::raw( 'FOUND_ROWS' ), ) ); default: diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-expression.php b/wp-includes/sqlite-ast/class-wp-sqlite-expression.php new file mode 100644 index 00000000..99a947b6 --- /dev/null +++ b/wp-includes/sqlite-ast/class-wp-sqlite-expression.php @@ -0,0 +1,36 @@ +elements ); + } else { + $new_elements[] = $element; + } + } + $this->elements = $new_elements; + } + + public function get_tokens() { + return $this->elements; + } + + public function add_token( WP_SQLite_Token $token ) { + $this->elements[] = $token; + } + + public function add_tokens( array $tokens ) { + foreach ( $tokens as $token ) { + $this->add_token( $token ); + } + } + + public function add_expression( $expression ) { + $this->add_token( $expression ); + } +} diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-query-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-query-builder.php new file mode 100644 index 00000000..6c0906d8 --- /dev/null +++ b/wp-includes/sqlite-ast/class-wp-sqlite-query-builder.php @@ -0,0 +1,38 @@ +build_query(); + } + + public function __construct( WP_SQLite_Expression $expression ) { + $this->expression = $expression; + } + + public function build_query(): string { + $query_parts = array(); + foreach ( $this->expression->get_tokens() as $element ) { + if ( $element instanceof WP_SQLite_Token ) { + $query_parts[] = $this->process_token( $element ); + } elseif ( $element instanceof WP_SQLite_Expression ) { + $query_parts[] = '(' . ( new self( $element ) )->build_query() . ')'; + } + } + return implode( ' ', $query_parts ); + } + + private function process_token( WP_SQLite_Token $token ): string { + switch ( $token->type ) { + case WP_SQLite_Token::TYPE_OPERATOR: + case WP_SQLite_Token::TYPE_RAW: + case WP_SQLite_Token::TYPE_VALUE: + return $token->value; + case WP_SQLite_Token::TYPE_IDENTIFIER: + return '"' . str_replace( '"', '""', $token->value ) . '"'; + default: + throw new InvalidArgumentException( 'Unknown token type: ' . $token->type ); + } + } +} diff --git a/wip/SQLiteDriver.php b/wp-includes/sqlite-ast/class-wp-sqlite-token-factory.php similarity index 64% rename from wip/SQLiteDriver.php rename to wp-includes/sqlite-ast/class-wp-sqlite-token-factory.php index b5cad10a..b803ae66 100644 --- a/wip/SQLiteDriver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-token-factory.php @@ -1,11 +1,11 @@ -type = $type; - $this->value = $value; - } -} - -class SQLiteQueryBuilder { - private Expression $expression; - - public static function stringify( Expression $expression ) { - return ( new SQLiteQueryBuilder( $expression ) )->build_query(); - } - - public function __construct( Expression $expression ) { - $this->expression = $expression; - } - - public function build_query(): string { - $query_parts = array(); - foreach ( $this->expression->get_tokens() as $element ) { - if ( $element instanceof SQLiteToken ) { - $query_parts[] = $this->process_token( $element ); - } elseif ( $element instanceof Expression ) { - $query_parts[] = '(' . ( new self( $element ) )->build_query() . ')'; - } - } - return implode( ' ', $query_parts ); - } - - private function process_token( SQLiteToken $token ): string { - switch ( $token->type ) { - case SQLiteToken::TYPE_RAW: - case SQLiteToken::TYPE_OPERATOR: - return $token->value; - case SQLiteToken::TYPE_IDENTIFIER: - return '"' . str_replace( '"', '""', $token->value ) . '"'; - case SQLiteToken::TYPE_VALUE: - return $token->value; - default: - throw new InvalidArgumentException( 'Unknown token type: ' . $token->type ); - } - } -} - -class Expression { - - public $elements; - - public function __construct( array $elements = array() ) { - $new_elements = array(); - $elements = array_filter( $elements, fn( $x ) => $x ); - foreach ( $elements as $element ) { - if ( is_object( $element ) && $element instanceof Expression ) { - $new_elements = array_merge( $new_elements, $element->elements ); - } else { - $new_elements[] = $element; - } - } - $this->elements = $new_elements; - } - - public function get_tokens() { - return $this->elements; - } - - public function add_token( SQLiteToken $token ) { - $this->elements[] = $token; - } - - public function add_tokens( array $tokens ) { - foreach ( $tokens as $token ) { - $this->add_token( $token ); - } - } - - public function add_expression( $expression ) { - $this->add_token( $expression ); - } -} - -class SQLiteExpression extends Expression {} - -class MySQLToSQLiteDriver { - - private $pdo; - - public function __construct( $dsn, $username = null, $password = null, $options = array() ) { - /* phpcs:ignore WordPress.DB.RestrictedClasses.mysql__PDO */ - $this->pdo = new PDO( $dsn, $username, $password, $options ); - } - - public function query( array $mysql_ast ) { - $transformer = new SQLTransformer( $mysql_ast, 'sqlite' ); - $expression = $transformer->transform(); - if ( null !== $expression ) { - $query_string = (string) $expression; - return $this->pdo->query( $query_string ); - } else { - throw new Exception( 'Failed to transform query.' ); - } - } -} - -// Example usage: - -// Sample parsed MySQL AST (Abstract Syntax Tree) -// $ast = [ -// 'type' => 'select', -// 'columns' => [ -// ['name' => '*', 'type' => 'ALL'], -// ['name' => 'created_at', 'type' => 'DATETIME'] -// ], -// 'from' => 'users', -// 'keywords' => ['SELECT', 'FROM'], -// 'options' => ['DISTINCT'] -// ]; - -// try { -// $driver = new MySQLToSQLiteDriver('sqlite::memory:'); -// $result = $driver->query($ast); -// foreach ($result as $row) { -// print_r($row); -// } -// } catch (Exception $e) { -// echo $e->getMessage(); -// } diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-token.php b/wp-includes/sqlite-ast/class-wp-sqlite-token.php new file mode 100644 index 00000000..8f5e3a09 --- /dev/null +++ b/wp-includes/sqlite-ast/class-wp-sqlite-token.php @@ -0,0 +1,16 @@ +type = $type; + $this->value = $value; + } +} From 44641e14c1a79d5d18e3571bb1feee444c19192f Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 14 Nov 2024 14:54:28 +0100 Subject: [PATCH 02/36] Namespace-prefix the WIP SQLite driver for now to avoid naming conflicts --- tests/tools/dump-sqlite-query.php | 2 ++ wp-includes/sqlite-ast/class-wp-sqlite-driver.php | 11 +++++++++++ wp-includes/sqlite-ast/class-wp-sqlite-expression.php | 3 +++ .../sqlite-ast/class-wp-sqlite-query-builder.php | 5 +++++ .../sqlite-ast/class-wp-sqlite-token-factory.php | 5 +++++ wp-includes/sqlite-ast/class-wp-sqlite-token.php | 3 +++ 6 files changed, 29 insertions(+) diff --git a/tests/tools/dump-sqlite-query.php b/tests/tools/dump-sqlite-query.php index 4cf4fdc1..a4594bd3 100644 --- a/tests/tools/dump-sqlite-query.php +++ b/tests/tools/dump-sqlite-query.php @@ -12,6 +12,8 @@ require_once __DIR__ . '/../../wp-includes/sqlite-ast/class-wp-sqlite-token.php'; require_once __DIR__ . '/../../wp-includes/sqlite-ast/class-wp-sqlite-query-builder.php'; +use WIP\WP_SQLite_Driver; + $grammar_data = include __DIR__ . '/../../wp-includes/mysql/mysql-grammar.php'; $grammar = new WP_Parser_Grammar( $grammar_data ); $driver = new WP_SQLite_Driver( $grammar ); diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 9f53f91f..5ada9621 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -1,5 +1,16 @@ Date: Thu, 14 Nov 2024 15:37:45 +0100 Subject: [PATCH 03/36] Copy WP_SQLite_Translator_Tests and run them against the SQLite driver --- tests/WP_SQLite_Driver_Tests.php | 3374 +++++++++++++++++ tests/tools/dump-sqlite-query.php | 6 +- .../sqlite-ast/class-wp-sqlite-driver.php | 52 +- 3 files changed, 3424 insertions(+), 8 deletions(-) create mode 100644 tests/WP_SQLite_Driver_Tests.php diff --git a/tests/WP_SQLite_Driver_Tests.php b/tests/WP_SQLite_Driver_Tests.php new file mode 100644 index 00000000..bee50ae6 --- /dev/null +++ b/tests/WP_SQLite_Driver_Tests.php @@ -0,0 +1,3374 @@ +suppress_errors = false; + $GLOBALS['wpdb']->show_errors = true; + } + return; + } + + // Before each test, we create a new database + public function setUp(): void { + $this->sqlite = new PDO( 'sqlite::memory:' ); + + $this->engine = new WP_SQLite_Driver( $this->sqlite ); + $this->engine->query( + "CREATE TABLE _options ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + $this->engine->query( + "CREATE TABLE _dates ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value DATE NOT NULL + );" + ); + } + + 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 testRegexp() { + $this->assertQuery( + "INSERT INTO _options (option_name, option_value) VALUES ('rss_0123456789abcdef0123456789abcdef', '1');" + ); + $this->assertQuery( + "INSERT INTO _options (option_name, option_value) VALUES ('transient', '1');" + ); + + $this->assertQuery( "DELETE FROM _options WHERE option_name REGEXP '^rss_.+$'" ); + $this->assertQuery( 'SELECT * FROM _options' ); + $this->assertCount( 1, $this->engine->get_query_results() ); + } + + /** + * @dataProvider regexpOperators + */ + public function testRegexps( $operator, $regexp, $expected_result ) { + $this->assertQuery( + "INSERT INTO _options (option_name) VALUES ('rss_123'), ('RSS_123'), ('transient');" + ); + + $this->assertQuery( "SELECT ID, option_name FROM _options WHERE option_name $operator '$regexp' ORDER BY id LIMIT 1" ); + $this->assertEquals( + array( $expected_result ), + $this->engine->get_query_results() + ); + } + + public static function regexpOperators() { + $lowercase_rss = (object) array( + 'ID' => '1', + 'option_name' => 'rss_123', + ); + $uppercase_rss = (object) array( + 'ID' => '2', + 'option_name' => 'RSS_123', + ); + $lowercase_transient = (object) array( + 'ID' => '3', + 'option_name' => 'transient', + ); + return array( + array( 'REGEXP', '^RSS_.+$', $lowercase_rss ), + array( 'RLIKE', '^RSS_.+$', $lowercase_rss ), + array( 'REGEXP BINARY', '^RSS_.+$', $uppercase_rss ), + array( 'RLIKE BINARY', '^RSS_.+$', $uppercase_rss ), + array( 'NOT REGEXP', '^RSS_.+$', $lowercase_transient ), + array( 'NOT RLIKE', '^RSS_.+$', $lowercase_transient ), + array( 'NOT REGEXP BINARY', '^RSS_.+$', $lowercase_rss ), + array( 'NOT RLIKE BINARY', '^RSS_.+$', $lowercase_rss ), + ); + } + + public function testInsertDateNow() { + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', now());" + ); + + $this->assertQuery( 'SELECT YEAR(option_value) as y FROM _dates' ); + + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( gmdate( 'Y' ), $results[0]->y ); + } + + public function testUpdateWithLimit() { + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 00:00:45');" + ); + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('second', '2003-05-28 00:00:45');" + ); + + $this->assertQuery( + "UPDATE _dates SET option_value = '2001-05-27 10:08:48' WHERE option_name = 'first' ORDER BY option_name LIMIT 1;" + ); + + $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( '2001-05-27 10:08:48', $result1[0]->option_value ); + $this->assertEquals( '2003-05-28 00:00:45', $result2[0]->option_value ); + + $this->assertQuery( + "UPDATE _dates SET option_value = '2001-05-27 10:08:49' WHERE option_name = 'first';" + ); + $result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first';" ); + $this->assertEquals( '2001-05-27 10:08:49', $result1[0]->option_value ); + + $this->assertQuery( + "UPDATE _dates SET option_value = '2001-05-12 10:00:40' WHERE option_name in ( SELECT option_name from _dates );" + ); + $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( '2001-05-12 10:00:40', $result1[0]->option_value ); + $this->assertEquals( '2001-05-12 10:00:40', $result2[0]->option_value ); + } + + public function testUpdateWithLimitNoEndToken() { + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 00:00:45')" + ); + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('second', '2003-05-28 00:00:45')" + ); + + $this->assertQuery( + "UPDATE _dates SET option_value = '2001-05-27 10:08:48' WHERE option_name = 'first' ORDER BY option_name LIMIT 1" + ); + $results = $this->engine->get_query_results(); + + $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( '2001-05-27 10:08:48', $result1[0]->option_value ); + $this->assertEquals( '2003-05-28 00:00:45', $result2[0]->option_value ); + + $this->assertQuery( + "UPDATE _dates SET option_value = '2001-05-27 10:08:49' WHERE option_name = 'first'" + ); + $result1 = $this->engine->query( "SELECT option_value FROM _dates WHERE option_name='first'" ); + $this->assertEquals( '2001-05-27 10:08:49', $result1[0]->option_value ); + + $this->assertQuery( + "UPDATE _dates SET option_value = '2001-05-12 10:00:40' WHERE option_name in ( SELECT option_name from _dates )" + ); + $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( '2001-05-12 10:00:40', $result1[0]->option_value ); + $this->assertEquals( '2001-05-12 10:00:40', $result2[0]->option_value ); + } + + public function testUpdateWithoutWhereButWithSubSelect() { + $this->assertQuery( + "INSERT INTO _options (option_name, option_value) VALUES ('User 0000019', 'second');" + ); + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 10:08:48');" + ); + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('second', '2003-05-27 10:08:48');" + ); + $return = $this->assertQuery( + "UPDATE _dates SET option_value = (SELECT option_value from _options WHERE option_name = 'User 0000019')" + ); + $this->assertSame( 2, $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( 'second', $result2[0]->option_value ); + } + + public function testUpdateWithoutWhereButWithLimit() { + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 10:08:48');" + ); + $this->assertQuery( + "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" + ); + $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( '2003-05-27 10:08:48', $result2[0]->option_value ); + } + + public function testCastAsBinary() { + $this->assertQuery( + // Use a confusing alias to make sure it replaces only the correct token + "SELECT CAST('ABC' AS BINARY) as binary;" + ); + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( 'ABC', $results[0]->binary ); + } + + public function testSelectFromDual() { + $result = $this->assertQuery( + 'SELECT 1 as output FROM DUAL' + ); + $this->assertEquals( 1, $result[0]->output ); + } + + public function testShowCreateTableNotFound() { + $this->assertQuery( + 'SHOW CREATE TABLE _no_such_table;' + ); + $results = $this->engine->get_query_results(); + $this->assertCount( 0, $results ); + } + + public function testShowCreateTable1() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name VARCHAR(255) default '', + option_value TEXT NOT NULL, + UNIQUE KEY option_name (option_name), + KEY composite (option_name, option_value) + );" + ); + + $this->assertQuery( + 'SHOW CREATE TABLE _tmp_table;' + ); + $results = $this->engine->get_query_results(); + # TODO: Should we fix mismatch with original `option_value` text NOT NULL,` without default? + $this->assertEquals( + "CREATE TABLE `_tmp_table` ( + `ID` bigint NOT NULL AUTO_INCREMENT, + `option_name` varchar(255) DEFAULT '', + `option_value` text NOT NULL DEFAULT '', + PRIMARY KEY (`ID`), + KEY `composite` (`option_name`, `option_value`), + UNIQUE KEY `option_name` (`option_name`) +);", + $results[0]->{'Create Table'} + ); + } + + public function testShowCreateTableQuoted() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name VARCHAR(255) default '', + option_value TEXT NOT NULL, + UNIQUE KEY option_name (option_name), + KEY composite (option_name, option_value) + );" + ); + + $this->assertQuery( + 'SHOW CREATE TABLE `_tmp_table`;' + ); + $results = $this->engine->get_query_results(); + # TODO: Should we fix mismatch with original `option_value` text NOT NULL,` without default? + $this->assertEquals( + "CREATE TABLE `_tmp_table` ( + `ID` bigint NOT NULL AUTO_INCREMENT, + `option_name` varchar(255) DEFAULT '', + `option_value` text NOT NULL DEFAULT '', + PRIMARY KEY (`ID`), + KEY `composite` (`option_name`, `option_value`), + UNIQUE KEY `option_name` (`option_name`) +);", + $results[0]->{'Create Table'} + ); + } + + public function testShowCreateTableSimpleTable() { + $this->assertQuery( + 'CREATE TABLE _tmp_table ( + ID BIGINT NOT NULL + );' + ); + + $this->assertQuery( + 'SHOW CREATE TABLE _tmp_table;' + ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + 'CREATE TABLE `_tmp_table` ( + `ID` bigint NOT NULL DEFAULT 0 +);', + $results[0]->{'Create Table'} + ); + } + + public function testShowCreateTableWithAlterAndCreateIndex() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name VARCHAR(255) default '', + option_value TEXT NOT NULL + );" + ); + + $this->assertQuery( + 'ALTER TABLE _tmp_table CHANGE COLUMN option_name option_name SMALLINT NOT NULL default 14' + ); + + $this->assertQuery( + 'ALTER TABLE _tmp_table ADD INDEX option_name (option_name);' + ); + + $this->assertQuery( + 'SHOW CREATE TABLE _tmp_table;' + ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + 'CREATE TABLE `_tmp_table` ( + `ID` bigint NOT NULL AUTO_INCREMENT, + `option_name` smallint NOT NULL DEFAULT 14, + `option_value` text NOT NULL DEFAULT \'\', + PRIMARY KEY (`ID`), + KEY `option_name` (`option_name`) +);', + $results[0]->{'Create Table'} + ); + } + + public function testCreateTablseWithIdenticalIndexNames() { + $this->assertQuery( + "CREATE TABLE _tmp_table_a ( + ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name VARCHAR(255) default '', + option_value TEXT NOT NULL, + KEY `option_name` (`option_name`), + KEY `double__underscores` (`option_name`, `ID`) + );" + ); + + $this->assertQuery( + "CREATE TABLE _tmp_table_b ( + ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name VARCHAR(255) default '', + option_value TEXT NOT NULL, + KEY `option_name` (`option_name`), + KEY `double__underscores` (`option_name`, `ID`) + );" + ); + } + + public function testShowCreateTablePreservesDoubleUnderscoreKeyNames() { + $this->assertQuery( + "CREATE TABLE _tmp__table ( + ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name VARCHAR(255) default '', + option_value TEXT NOT NULL, + KEY `option_name` (`option_name`), + KEY `double__underscores` (`option_name`, `ID`) + );" + ); + + $this->assertQuery( + 'SHOW CREATE TABLE _tmp__table;' + ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + 'CREATE TABLE `_tmp__table` ( + `ID` bigint NOT NULL AUTO_INCREMENT, + `option_name` varchar(255) DEFAULT \'\', + `option_value` text NOT NULL DEFAULT \'\', + PRIMARY KEY (`ID`), + KEY `double__underscores` (`option_name`, `ID`), + KEY `option_name` (`option_name`) +);', + $results[0]->{'Create Table'} + ); + } + + public function testShowCreateTableWithPrimaryKeyColumnsReverseOrdered() { + $this->assertQuery( + 'CREATE TABLE `_tmp_table` ( + `ID_A` BIGINT NOT NULL, + `ID_B` BIGINT NOT NULL, + `ID_C` BIGINT NOT NULL, + PRIMARY KEY (`ID_B`, `ID_A`, `ID_C`) + );' + ); + + $this->assertQuery( + 'SHOW CREATE TABLE _tmp_table;' + ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + 'CREATE TABLE `_tmp_table` ( + `ID_A` bigint NOT NULL DEFAULT 0, + `ID_B` bigint NOT NULL DEFAULT 0, + `ID_C` bigint NOT NULL DEFAULT 0, + PRIMARY KEY (`ID_B`, `ID_A`, `ID_C`) +);', + $results[0]->{'Create Table'} + ); + } + + public function testShowCreateTableWithColumnKeys() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + `ID` bigint PRIMARY KEY AUTO_INCREMENT NOT NULL, + `option_name` varchar(255) DEFAULT '', + `option_value` text NOT NULL DEFAULT '', + KEY _tmp_table__composite (option_name, option_value), + UNIQUE KEY _tmp_table__option_name (option_name) );" + ); + } + + public function testShowCreateTableWithCorrectDefaultValues() { + $this->assertQuery( + "CREATE TABLE _tmp__table ( + ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, + default_empty_string VARCHAR(255) default '', + null_no_default VARCHAR(255), + );" + ); + + $this->assertQuery( + 'SHOW CREATE TABLE _tmp__table;' + ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + 'CREATE TABLE `_tmp__table` ( + `ID` bigint NOT NULL AUTO_INCREMENT, + `default_empty_string` varchar(255) DEFAULT \'\', + `null_no_default` varchar(255), + PRIMARY KEY (`ID`) +);', + $results[0]->{'Create Table'} + ); + } + + public function testSelectIndexHintForce() { + $this->assertQuery( "INSERT INTO _options (option_name) VALUES ('first');" ); + $result = $this->assertQuery( + 'SELECT 1 as output FROM _options FORCE INDEX (PRIMARY, post_parent) WHERE 1=1' + ); + $this->assertEquals( 1, $result[0]->output ); + } + + public function testSelectIndexHintUseGroup() { + $this->assertQuery( "INSERT INTO _options (option_name) VALUES ('first');" ); + $result = $this->assertQuery( + 'SELECT 1 as output FROM _options USE KEY FOR GROUP BY (PRIMARY, post_parent) WHERE 1=1' + ); + $this->assertEquals( 1, $result[0]->output ); + } + + public function testLeftFunction1Char() { + $result = $this->assertQuery( + 'SELECT LEFT("abc", 1) as output' + ); + $this->assertEquals( 'a', $result[0]->output ); + } + + public function testLeftFunction5Chars() { + $result = $this->assertQuery( + 'SELECT LEFT("Lorem ipsum", 5) as output' + ); + $this->assertEquals( 'Lorem', $result[0]->output ); + } + + public function testLeftFunctionNullString() { + $result = $this->assertQuery( + 'SELECT LEFT(NULL, 5) as output' + ); + $this->assertEquals( null, $result[0]->output ); + } + + public function testLeftFunctionNullLength() { + $result = $this->assertQuery( + 'SELECT LEFT("Test", NULL) as output' + ); + $this->assertEquals( null, $result[0]->output ); + } + + public function testInsertSelectFromDual() { + $result = $this->assertQuery( + 'INSERT INTO _options (option_name, option_value) SELECT "A", "b" FROM DUAL WHERE ( SELECT NULL FROM DUAL ) IS NULL' + ); + $this->assertEquals( 1, $result ); + } + + public function testCreateTemporaryTable() { + $this->assertQuery( + "CREATE TEMPORARY TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + $this->assertQuery( + 'DROP TEMPORARY TABLE _tmp_table;' + ); + } + + public function testShowTablesLike() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + $this->assertQuery( + "CREATE TABLE _tmp_table_2 ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + + $this->assertQuery( + "SHOW TABLES LIKE '_tmp_table';" + ); + $this->assertEquals( + array( + (object) array( + 'Tables_in_db' => '_tmp_table', + ), + ), + $this->engine->get_query_results() + ); + } + + public function testShowTableStatusFrom() { + // Created in setUp() function + $this->assertQuery( 'DROP TABLE _options' ); + $this->assertQuery( 'DROP TABLE _dates' ); + + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + + $this->assertQuery( + "SHOW TABLE STATUS FROM 'mydb';" + ); + + $this->assertCount( + 1, + $this->engine->get_query_results() + ); + } + + public function testShowTableStatusIn() { + // Created in setUp() function + $this->assertQuery( 'DROP TABLE _options' ); + $this->assertQuery( 'DROP TABLE _dates' ); + + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + + $this->assertQuery( + "SHOW TABLE STATUS IN 'mydb';" + ); + + $this->assertCount( + 1, + $this->engine->get_query_results() + ); + } + + public function testShowTableStatusInTwoTables() { + // Created in setUp() function + $this->assertQuery( 'DROP TABLE _options' ); + $this->assertQuery( 'DROP TABLE _dates' ); + + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + + $this->assertQuery( + "CREATE TABLE _tmp_table2 ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + $this->assertQuery( + "SHOW TABLE STATUS IN 'mydb';" + ); + + $this->assertCount( + 2, + $this->engine->get_query_results() + ); + } + + public function testShowTableStatusLike() { + // Created in setUp() function + $this->assertQuery( 'DROP TABLE _options' ); + $this->assertQuery( 'DROP TABLE _dates' ); + + $this->assertQuery( + "CREATE TABLE _tmp_table1 ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + + $this->assertQuery( + "CREATE TABLE _tmp_table2 ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + + $this->assertQuery( + "SHOW TABLE STATUS LIKE '_tmp_table%';" + ); + $this->assertCount( + 2, + $this->engine->get_query_results() + ); + $this->assertEquals( + '_tmp_table1', + $this->engine->get_query_results()[0]->Name + ); + } + + public function testCreateTable() { + $result = $this->assertQuery( + "CREATE TABLE wptests_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) + ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci" + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $this->assertQuery( 'DESCRIBE wptests_users;' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + array( + (object) array( + 'Field' => 'ID', + 'Type' => 'bigint(20) unsigned', + 'Null' => 'NO', + 'Key' => 'PRI', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'user_login', + 'Type' => 'varchar(60)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'user_pass', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'user_nicename', + 'Type' => 'varchar(50)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'user_email', + 'Type' => 'varchar(100)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'user_url', + 'Type' => 'varchar(100)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'user_registered', + 'Type' => 'datetime', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0000-00-00 00:00:00', + 'Extra' => '', + ), + (object) array( + 'Field' => 'user_activation_key', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'user_status', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'display_name', + 'Type' => 'varchar(250)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + ), + $results + ); + } + + public function testCreateTableWithTrailingComma() { + $result = $this->assertQuery( + 'CREATE TABLE wptests_users ( + ID bigint(20) unsigned NOT NULL auto_increment, + PRIMARY KEY (ID), + ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + } + + public function testCreateTableSpatialIndex() { + $result = $this->assertQuery( + 'CREATE TABLE wptests_users ( + ID bigint(20) unsigned NOT NULL auto_increment, + UNIQUE KEY (ID), + )' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + } + + public function testCreateTableWithMultiValueColumnTypeModifiers() { + $result = $this->assertQuery( + "CREATE TABLE wptests_users ( + ID bigint(20) unsigned NOT NULL auto_increment, + decimal_column DECIMAL(10,2) NOT NULL DEFAULT 0, + float_column FLOAT(10,2) NOT NULL DEFAULT 0, + enum_column ENUM('a', 'b', 'c') NOT NULL DEFAULT 'a', + PRIMARY KEY (ID), + )" + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $this->assertQuery( 'DESCRIBE wptests_users;' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + array( + (object) array( + 'Field' => 'ID', + 'Type' => 'bigint(20) unsigned', + 'Null' => 'NO', + 'Key' => 'PRI', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'decimal_column', + 'Type' => 'decimal(10,2)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => 0, + 'Extra' => '', + ), + (object) array( + 'Field' => 'float_column', + 'Type' => 'float(10,2)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => 0, + 'Extra' => '', + ), + (object) array( + 'Field' => 'enum_column', + 'Type' => "enum('a','b','c')", + 'Null' => 'NO', + 'Key' => '', + 'Default' => 'a', + 'Extra' => '', + ), + ), + $results + ); + } + + public function testAlterTableAddAndDropColumn() { + $result = $this->assertQuery( + "CREATE TABLE _tmp_table ( + name varchar(20) NOT NULL default '' + );" + ); + + $result = $this->assertQuery( 'ALTER TABLE _tmp_table ADD COLUMN `column` int;' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + array( + (object) array( + 'Field' => 'name', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'column', + 'Type' => 'int', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + ), + $results + ); + + $result = $this->assertQuery( 'ALTER TABLE _tmp_table ADD `column2` int;' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + array( + (object) array( + 'Field' => 'name', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'column', + 'Type' => 'int', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + (object) array( + 'Field' => 'column2', + 'Type' => 'int', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + ), + $results + ); + + $result = $this->assertQuery( 'ALTER TABLE _tmp_table DROP COLUMN `column`;' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + array( + (object) array( + 'Field' => 'name', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'column2', + 'Type' => 'int', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + ), + $results + ); + + $result = $this->assertQuery( 'ALTER TABLE _tmp_table DROP `column2`;' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + array( + (object) array( + 'Field' => 'name', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + ), + $results + ); + } + + public function testAlterTableAddNotNullVarcharColumn() { + $result = $this->assertQuery( + "CREATE TABLE _tmp_table ( + name varchar(20) NOT NULL default '' + );" + ); + + $result = $this->assertQuery( "ALTER TABLE _tmp_table ADD COLUMN `column` VARCHAR(20) NOT NULL DEFAULT 'foo';" ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + array( + (object) array( + 'Field' => 'name', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'column', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => 'foo', + 'Extra' => '', + ), + ), + $results + ); + } + + public function testColumnWithOnUpdate() { + // CREATE TABLE with ON UPDATE + $this->assertQuery( + 'CREATE TABLE _tmp_table ( + id int(11) NOT NULL, + created_at timestamp NULL ON UPDATE CURRENT_TIMESTAMP + );' + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'created_at', + 'Type' => 'timestamp', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + ), + $results + ); + + // ADD COLUMN with ON UPDATE + $this->assertQuery( + 'ALTER TABLE _tmp_table ADD COLUMN updated_at timestamp NULL ON UPDATE CURRENT_TIMESTAMP' + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'created_at', + 'Type' => 'timestamp', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + (object) array( + 'Field' => 'updated_at', + 'Type' => 'timestamp', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + ), + $results + ); + + // assert ON UPDATE triggers + $results = $this->assertQuery( "SELECT * FROM sqlite_master WHERE type = 'trigger'" ); + $this->assertEquals( + array( + (object) array( + 'type' => 'trigger', + 'name' => '___tmp_table_created_at_on_update__', + 'tbl_name' => '_tmp_table', + 'rootpage' => '0', + 'sql' => "CREATE TRIGGER \"___tmp_table_created_at_on_update__\"\n\t\t\tAFTER UPDATE ON \"_tmp_table\"\n\t\t\tFOR EACH ROW\n\t\t\tBEGIN\n\t\t\t UPDATE \"_tmp_table\" SET \"created_at\" = CURRENT_TIMESTAMP WHERE rowid = NEW.rowid;\n\t\t\tEND", + ), + (object) array( + 'type' => 'trigger', + 'name' => '___tmp_table_updated_at_on_update__', + 'tbl_name' => '_tmp_table', + 'rootpage' => '0', + 'sql' => "CREATE TRIGGER \"___tmp_table_updated_at_on_update__\"\n\t\t\tAFTER UPDATE ON \"_tmp_table\"\n\t\t\tFOR EACH ROW\n\t\t\tBEGIN\n\t\t\t UPDATE \"_tmp_table\" SET \"updated_at\" = CURRENT_TIMESTAMP WHERE rowid = NEW.rowid;\n\t\t\tEND", + ), + ), + $results + ); + + // on INSERT, no timestamps are expected + $this->assertQuery( 'INSERT INTO _tmp_table (id) VALUES (1)' ); + $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE id = 1' ); + $this->assertNull( $result[0]->created_at ); + $this->assertNull( $result[0]->updated_at ); + + // on UPDATE, we expect timestamps in form YYYY-MM-DD HH:MM:SS + $this->assertQuery( 'UPDATE _tmp_table SET id = 2 WHERE id = 1' ); + $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE id = 2' ); + $this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $result[0]->created_at ); + $this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $result[0]->updated_at ); + + // drop ON UPDATE + $this->assertQuery( + 'ALTER TABLE _tmp_table + CHANGE created_at created_at timestamp NULL, + CHANGE COLUMN updated_at updated_at timestamp NULL' + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'created_at', + 'Type' => 'timestamp', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + (object) array( + 'Field' => 'updated_at', + 'Type' => 'timestamp', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + ), + $results + ); + + // assert ON UPDATE triggers are removed + $results = $this->assertQuery( "SELECT * FROM sqlite_master WHERE type = 'trigger'" ); + $this->assertEquals( array(), $results ); + + // now, no timestamps are expected + $this->assertQuery( 'INSERT INTO _tmp_table (id) VALUES (10)' ); + $this->assertQuery( 'UPDATE _tmp_table SET id = 11 WHERE id = 10' ); + $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE id = 11' ); + $this->assertNull( $result[0]->created_at ); + $this->assertNull( $result[0]->updated_at ); + } + + public function testColumnWithOnUpdateAndNoIdField() { + // CREATE TABLE with ON UPDATE + $this->assertQuery( + 'CREATE TABLE _tmp_table ( + name varchar(20) NOT NULL, + created_at timestamp NULL ON UPDATE CURRENT_TIMESTAMP + );' + ); + + // on INSERT, no timestamps are expected + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('aaa')" ); + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name = 'aaa'" ); + $this->assertNull( $result[0]->created_at ); + + // on UPDATE, we expect timestamps in form YYYY-MM-DD HH:MM:SS + $this->assertQuery( "UPDATE _tmp_table SET name = 'bbb' WHERE name = 'aaa'" ); + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name = 'bbb'" ); + $this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $result[0]->created_at ); + } + + public function testChangeColumnWithOnUpdate() { + // CREATE TABLE with ON UPDATE + $this->assertQuery( + 'CREATE TABLE _tmp_table ( + id int(11) NOT NULL, + created_at timestamp NULL + );' + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'created_at', + 'Type' => 'timestamp', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + ), + $results + ); + + // no ON UPDATE is set + $this->assertQuery( 'INSERT INTO _tmp_table (id) VALUES (1)' ); + $this->assertQuery( 'UPDATE _tmp_table SET id = 1 WHERE id = 1' ); + $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE id = 1' ); + $this->assertNull( $result[0]->created_at ); + + // CHANGE COLUMN to add ON UPDATE + $this->assertQuery( + 'ALTER TABLE _tmp_table CHANGE COLUMN created_at created_at timestamp NULL ON UPDATE CURRENT_TIMESTAMP' + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'created_at', + 'Type' => 'timestamp', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + ), + $results + ); + + // now, ON UPDATE SHOULD BE SET + $this->assertQuery( 'UPDATE _tmp_table SET id = 1 WHERE id = 1' ); + $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE id = 1' ); + $this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $result[0]->created_at ); + + // change column to remove ON UPDATE + $this->assertQuery( + 'ALTER TABLE _tmp_table CHANGE COLUMN created_at created_at timestamp NULL' + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'created_at', + 'Type' => 'timestamp', + 'Null' => 'YES', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + ), + $results + ); + + // now, no timestamp is expected + $this->assertQuery( 'INSERT INTO _tmp_table (id) VALUES (2)' ); + $this->assertQuery( 'UPDATE _tmp_table SET id = 2 WHERE id = 2' ); + $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE id = 2' ); + $this->assertNull( $result[0]->created_at ); + } + + public function testAlterTableWithColumnFirstAndAfter() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + id int(11) NOT NULL, + name varchar(20) NOT NULL default '' + );" + ); + + // ADD COLUMN with FIRST + $this->assertQuery( + "ALTER TABLE _tmp_table ADD COLUMN new_first_column VARCHAR(255) NOT NULL DEFAULT '' FIRST" + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'name', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + (object) array( + 'Field' => 'new_first_column', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + ), + $results + ); + + // ADD COLUMN with AFTER + $this->assertQuery( + "ALTER TABLE _tmp_table ADD COLUMN new_column VARCHAR(255) NOT NULL DEFAULT '' AFTER id" + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'name', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + (object) array( + 'Field' => 'new_first_column', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'new_column', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + ), + $results + ); + + // CHANGE with FIRST + $this->assertQuery( + "ALTER TABLE _tmp_table CHANGE id id int(11) NOT NULL DEFAULT '0' FIRST" + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'name', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + (object) array( + 'Field' => 'new_first_column', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'new_column', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + ), + $results + ); + + // CHANGE with AFTER + $this->assertQuery( + "ALTER TABLE _tmp_table CHANGE id id int(11) NOT NULL DEFAULT '0' AFTER name" + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'name', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + (object) array( + 'Field' => 'new_first_column', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'new_column', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + ), + $results + ); + } + + public function testAlterTableWithMultiColumnFirstAndAfter() { + $this->assertQuery( + 'CREATE TABLE _tmp_table ( + id int(11) NOT NULL + );' + ); + + // ADD COLUMN + $this->assertQuery( + 'ALTER TABLE _tmp_table + ADD COLUMN new1 varchar(255) NOT NULL, + ADD COLUMN new2 varchar(255) NOT NULL FIRST, + ADD COLUMN new3 varchar(255) NOT NULL AFTER new1' + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'new1', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + (object) array( + 'Field' => 'new2', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'new3', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + ), + $results + ); + + // CHANGE + $this->assertQuery( + 'ALTER TABLE _tmp_table + CHANGE new1 new1 int(11) NOT NULL FIRST, + CHANGE new2 new2 int(11) NOT NULL, + CHANGE new3 new3 int(11) NOT NULL AFTER new2' + ); + $results = $this->assertQuery( 'DESCRIBE _tmp_table;' ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'id', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'new1', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + (object) array( + 'Field' => 'new2', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'new3', + 'Type' => 'int(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + ), + $results + ); + } + + public function testAlterTableAddIndex() { + $result = $this->assertQuery( + "CREATE TABLE _tmp_table ( + name varchar(20) NOT NULL default '' + );" + ); + + $result = $this->assertQuery( 'ALTER TABLE _tmp_table ADD INDEX name (name);' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $this->assertQuery( 'SHOW INDEX FROM _tmp_table;' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + array( + (object) array( + 'Table' => '_tmp_table', + 'Non_unique' => '1', + 'Key_name' => 'name', + 'Seq_in_index' => '0', + 'Column_name' => 'name', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'BTREE', + 'Comment' => '', + 'Index_comment' => '', + ), + ), + $results + ); + } + + public function testAlterTableAddUniqueIndex() { + $result = $this->assertQuery( + "CREATE TABLE _tmp_table ( + name varchar(20) NOT NULL default '' + );" + ); + + $result = $this->assertQuery( 'ALTER TABLE _tmp_table ADD UNIQUE INDEX name (name(20));' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $this->assertQuery( 'SHOW INDEX FROM _tmp_table;' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + array( + (object) array( + 'Table' => '_tmp_table', + 'Non_unique' => '0', + 'Key_name' => 'name', + 'Seq_in_index' => '0', + 'Column_name' => 'name', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'BTREE', + 'Comment' => '', + 'Index_comment' => '', + ), + ), + $results + ); + } + + public function testAlterTableAddFulltextIndex() { + $result = $this->assertQuery( + "CREATE TABLE _tmp_table ( + name varchar(20) NOT NULL default '' + );" + ); + + $result = $this->assertQuery( 'ALTER TABLE _tmp_table ADD FULLTEXT INDEX name (name);' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $this->assertQuery( 'SHOW INDEX FROM _tmp_table;' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + array( + (object) array( + 'Table' => '_tmp_table', + 'Non_unique' => '1', + 'Key_name' => 'name', + 'Seq_in_index' => '0', + 'Column_name' => 'name', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'FULLTEXT', + 'Comment' => '', + 'Index_comment' => '', + ), + ), + $results + ); + } + + public function testAlterTableModifyColumn() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + name varchar(20) NOT NULL default '', + lastname varchar(20) NOT NULL default '', + KEY composite (name, lastname), + UNIQUE KEY name (name) + );" + ); + // Insert a record + $result = $this->assertQuery( "INSERT INTO _tmp_table (ID, name, lastname) VALUES (1, 'Johnny', 'Appleseed');" ); + $this->assertEquals( 1, $result ); + + // Primary key violation: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, name, lastname) VALUES (1, 'Mike', 'Pearseed');" ); + $this->assertEquals( false, $result ); + + // Unique constraint violation: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, name, lastname) VALUES (2, 'Johnny', 'Appleseed');" ); + $this->assertEquals( false, $result ); + + // Rename the "name" field to "firstname": + $result = $this->engine->query( "ALTER TABLE _tmp_table CHANGE column name firstname varchar(50) NOT NULL default 'mark';" ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + // Confirm the original data is still there: + $result = $this->engine->query( 'SELECT * FROM _tmp_table;' ); + $this->assertCount( 1, $result ); + $this->assertEquals( 1, $result[0]->ID ); + $this->assertEquals( 'Johnny', $result[0]->firstname ); + $this->assertEquals( 'Appleseed', $result[0]->lastname ); + + // Confirm the primary key is intact: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, firstname, lastname) VALUES (1, 'Mike', 'Pearseed');" ); + $this->assertEquals( false, $result ); + + // Confirm the unique key is intact: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, firstname, lastname) VALUES (2, 'Johnny', 'Appleseed');" ); + $this->assertEquals( false, $result ); + + // Confirm the autoincrement still works: + $result = $this->engine->query( "INSERT INTO _tmp_table (firstname, lastname) VALUES ('John', 'Doe');" ); + $this->assertEquals( true, $result ); + $result = $this->engine->query( "SELECT * FROM _tmp_table WHERE firstname='John';" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 2, $result[0]->ID ); + } + + + public function testAlterTableModifyColumnWithSkippedColumnKeyword() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + name varchar(20) NOT NULL default '', + lastname varchar(20) NOT NULL default '', + KEY composite (name, lastname), + UNIQUE KEY name (name) + );" + ); + // Insert a record + $result = $this->assertQuery( "INSERT INTO _tmp_table (ID, name, lastname) VALUES (1, 'Johnny', 'Appleseed');" ); + $this->assertEquals( 1, $result ); + + // Primary key violation: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, name, lastname) VALUES (1, 'Mike', 'Pearseed');" ); + $this->assertEquals( false, $result ); + + // Unique constraint violation: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, name, lastname) VALUES (2, 'Johnny', 'Appleseed');" ); + $this->assertEquals( false, $result ); + + // Rename the "name" field to "firstname": + $result = $this->engine->query( "ALTER TABLE _tmp_table CHANGE name firstname varchar(50) NOT NULL default 'mark';" ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + // Confirm the original data is still there: + $result = $this->engine->query( 'SELECT * FROM _tmp_table;' ); + $this->assertCount( 1, $result ); + $this->assertEquals( 1, $result[0]->ID ); + $this->assertEquals( 'Johnny', $result[0]->firstname ); + $this->assertEquals( 'Appleseed', $result[0]->lastname ); + + // Confirm the primary key is intact: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, firstname, lastname) VALUES (1, 'Mike', 'Pearseed');" ); + $this->assertEquals( false, $result ); + + // Confirm the unique key is intact: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, firstname, lastname) VALUES (2, 'Johnny', 'Appleseed');" ); + $this->assertEquals( false, $result ); + + // Confirm the autoincrement still works: + $result = $this->engine->query( "INSERT INTO _tmp_table (firstname, lastname) VALUES ('John', 'Doe');" ); + $this->assertEquals( true, $result ); + $result = $this->engine->query( "SELECT * FROM _tmp_table WHERE firstname='John';" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 2, $result[0]->ID ); + } + + public function testAlterTableModifyColumnWithHyphens() { + $result = $this->assertQuery( + 'CREATE TABLE wptests_dbdelta_test2 ( + `foo-bar` varchar(255) DEFAULT NULL + )' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $result = $this->assertQuery( + 'ALTER TABLE wptests_dbdelta_test2 CHANGE COLUMN `foo-bar` `foo-bar` text DEFAULT NULL' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $result = $this->assertQuery( 'DESCRIBE wptests_dbdelta_test2;' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertNotFalse( $result ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'foo-bar', + 'Type' => 'text', + 'Null' => 'YES', + 'Key' => '', + 'Default' => 'NULL', + 'Extra' => '', + ), + ), + $result + ); + } + + public function testAlterTableModifyColumnComplexChange() { + $result = $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER NOT NULL, + name varchar(20) NOT NULL default '', + lastname varchar(20) default '', + date_as_string varchar(20) default '', + PRIMARY KEY (ID, name) + );" + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + // Add a unique index + $result = $this->assertQuery( + 'ALTER TABLE _tmp_table ADD UNIQUE INDEX "test_unique_composite" (name, lastname);' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + // Add a regular index + $result = $this->assertQuery( + 'ALTER TABLE _tmp_table ADD INDEX "test_regular" (lastname);' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + // Confirm the table is well-behaved so far: + + // Insert a few records + $result = $this->assertQuery( + " + INSERT INTO _tmp_table (ID, name, lastname, date_as_string) + VALUES + (1, 'Johnny', 'Appleseed', '2002-01-01 12:53:13'), + (2, 'Mike', 'Foo', '2003-01-01 12:53:13'), + (3, 'Kate', 'Bar', '2004-01-01 12:53:13'), + (4, 'Anna', 'Pear', '2005-01-01 12:53:13') + ;" + ); + $this->assertEquals( 4, $result ); + + // Primary key violation: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, name) VALUES (1, 'Johnny');" ); + $this->assertEquals( false, $result ); + + // Unique constraint violation: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, name, lastname) VALUES (5, 'Kate', 'Bar');" ); + $this->assertEquals( false, $result ); + + // No constraint violation: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, name, lastname) VALUES (5, 'Joanna', 'Bar');" ); + $this->assertEquals( 1, $result ); + + // Now – let's change a few columns: + $result = $this->engine->query( 'ALTER TABLE _tmp_table CHANGE COLUMN name firstname varchar(20)' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $result = $this->engine->query( 'ALTER TABLE _tmp_table CHANGE COLUMN date_as_string datetime datetime NOT NULL' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + // Finally, let's confirm our data is intact and the table is still well-behaved: + $result = $this->engine->query( 'SELECT * FROM _tmp_table ORDER BY ID;' ); + $this->assertCount( 5, $result ); + $this->assertEquals( 1, $result[0]->ID ); + $this->assertEquals( 'Johnny', $result[0]->firstname ); + $this->assertEquals( 'Appleseed', $result[0]->lastname ); + $this->assertEquals( '2002-01-01 12:53:13', $result[0]->datetime ); + + // Primary key violation: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, firstname, datetime) VALUES (1, 'Johnny', '2010-01-01 12:53:13');" ); + $this->assertEquals( false, $result ); + + // Unique constraint violation: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, firstname, lastname, datetime) VALUES (6, 'Kate', 'Bar', '2010-01-01 12:53:13');" ); + $this->assertEquals( false, $result ); + + // No constraint violation: + $result = $this->engine->query( "INSERT INTO _tmp_table (ID, firstname, lastname, datetime) VALUES (6, 'Sophie', 'Bar', '2010-01-01 12:53:13');" ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + } + + public function testCaseInsensitiveUniqueIndex() { + $result = $this->engine->query( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + name varchar(20) NOT NULL default '', + lastname varchar(20) NOT NULL default '', + KEY name (name), + UNIQUE KEY uname (name), + UNIQUE KEY last (lastname) + );" + ); + $this->assertEquals( 1, $result ); + + $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->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() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + name varchar(20) NOT NULL default '', + UNIQUE KEY myname (name) + );" + ); + + // $result1 = $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('first');" ); + // $this->assertEquals( '', $this->engine->get_error_message() ); + // $this->assertEquals( 1, $result1 ); + + $result2 = $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('FIRST') ON DUPLICATE KEY UPDATE `name` = VALUES(`name`);" ); + $this->assertEquals( 1, $result2 ); + + $this->assertQuery( 'SELECT * FROM _tmp_table;' ); + $this->assertCount( 1, $this->engine->get_query_results() ); + $this->assertEquals( + array( + (object) array( + 'name' => 'FIRST', + 'ID' => 1, + ), + ), + $this->engine->get_query_results() + ); + } + + public function testTruncatesInvalidDates() { + $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');" ); + + $this->assertQuery( 'SELECT * FROM _dates;' ); + $results = $this->engine->get_query_results(); + $this->assertCount( 2, $results ); + $this->assertEquals( '2022-01-01 14:24:12', $results[0]->option_value ); + $this->assertEquals( '0000-00-00 00:00:00', $results[1]->option_value ); + } + + public function testCaseInsensitiveSelect() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + name varchar(20) NOT NULL default '' + );" + ); + $this->assertQuery( + "INSERT INTO _tmp_table (name) VALUES ('first');" + ); + $this->assertQuery( "SELECT name FROM _tmp_table WHERE name = 'FIRST';" ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertCount( 1, $this->engine->get_query_results() ); + $this->assertEquals( + array( + (object) array( + 'name' => 'first', + ), + ), + $this->engine->get_query_results() + ); + } + + public function testSelectBetweenDates() { + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2016-01-15T00:00:00Z');" ); + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('second', '2016-01-16T00:00:00Z');" ); + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('third', '2016-01-17T00:00:00Z');" ); + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('fourth', '2016-01-18T00:00:00Z');" ); + + $this->assertQuery( "SELECT * FROM _dates WHERE option_value BETWEEN '2016-01-15T00:00:00Z' AND '2016-01-17T00:00:00Z' ORDER BY ID;" ); + $results = $this->engine->get_query_results(); + $this->assertCount( 3, $results ); + $this->assertEquals( 'first', $results[0]->option_name ); + $this->assertEquals( 'second', $results[1]->option_name ); + $this->assertEquals( 'third', $results[2]->option_name ); + } + + public function testSelectFilterByDatesGtLt() { + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2016-01-15T00:00:00Z');" ); + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('second', '2016-01-16T00:00:00Z');" ); + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('third', '2016-01-17T00:00:00Z');" ); + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('fourth', '2016-01-18T00:00:00Z');" ); + + $this->assertQuery( + " + SELECT * FROM _dates + WHERE option_value > '2016-01-15 00:00:00' + AND option_value < '2016-01-17 00:00:00' + ORDER BY ID + " + ); + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( 'second', $results[0]->option_name ); + } + + public function testSelectFilterByDatesZeroHour() { + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2014-10-21 00:42:29');" ); + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('second', '2014-10-21 01:42:29');" ); + + $this->assertQuery( + ' + SELECT * FROM _dates + WHERE YEAR(option_value) = 2014 + AND MONTHNUM(option_value) = 10 + AND DAY(option_value) = 21 + AND HOUR(option_value) = 0 + AND MINUTE(option_value) = 42 + ' + ); + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( 'first', $results[0]->option_name ); + } + + public function testCorrectlyInsertsDatesAndStrings() { + $this->assertQuery( "INSERT INTO _dates (option_name, option_value) VALUES ('2016-01-15T00:00:00Z', '2016-01-15T00:00:00Z');" ); + + $this->assertQuery( 'SELECT * FROM _dates' ); + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( '2016-01-15 00:00:00', $results[0]->option_value ); + if ( '2016-01-15T00:00:00Z' !== $results[0]->option_name ) { + $this->markTestSkipped( 'A datetime-like string was rewritten to an SQLite format even though it was used as a text and not as a datetime.' ); + } + $this->assertEquals( '2016-01-15T00:00:00Z', $results[0]->option_name ); + } + + public function testTransactionRollback() { + $this->assertQuery( 'BEGIN' ); + $this->assertQuery( "INSERT INTO _options (option_name) VALUES ('first');" ); + $this->assertQuery( 'SELECT * FROM _options;' ); + $this->assertCount( 1, $this->engine->get_query_results() ); + $this->assertQuery( 'ROLLBACK' ); + + $this->assertQuery( 'SELECT * FROM _options;' ); + $this->assertCount( 0, $this->engine->get_query_results() ); + } + + public function testTransactionCommit() { + $this->assertQuery( 'BEGIN' ); + $this->assertQuery( "INSERT INTO _options (option_name) VALUES ('first');" ); + $this->assertQuery( 'SELECT * FROM _options;' ); + $this->assertCount( 1, $this->engine->get_query_results() ); + $this->assertQuery( 'COMMIT' ); + + $this->assertQuery( 'SELECT * FROM _options;' ); + $this->assertCount( 1, $this->engine->get_query_results() ); + } + + public function testStartTransactionCommand() { + $this->assertQuery( 'START TRANSACTION' ); + $this->assertQuery( "INSERT INTO _options (option_name) VALUES ('first');" ); + $this->assertQuery( 'SELECT * FROM _options;' ); + $this->assertCount( 1, $this->engine->get_query_results() ); + $this->assertQuery( 'ROLLBACK' ); + + $this->assertQuery( 'SELECT * FROM _options;' ); + $this->assertCount( 0, $this->engine->get_query_results() ); + } + + public function testNestedTransactionWork() { + $this->assertQuery( 'BEGIN' ); + $this->assertQuery( "INSERT INTO _options (option_name) VALUES ('first');" ); + $this->assertQuery( 'START TRANSACTION' ); + $this->assertQuery( "INSERT INTO _options (option_name) VALUES ('second');" ); + $this->assertQuery( 'START TRANSACTION' ); + $this->assertQuery( "INSERT INTO _options (option_name) VALUES ('third');" ); + $this->assertQuery( 'SELECT * FROM _options;' ); + $this->assertCount( 3, $this->engine->get_query_results() ); + + $this->assertQuery( 'ROLLBACK' ); + $this->assertQuery( 'SELECT * FROM _options;' ); + $this->assertCount( 2, $this->engine->get_query_results() ); + + $this->assertQuery( 'ROLLBACK' ); + $this->assertQuery( 'SELECT * FROM _options;' ); + $this->assertCount( 1, $this->engine->get_query_results() ); + + $this->assertQuery( 'COMMIT' ); + $this->assertQuery( 'SELECT * FROM _options;' ); + $this->assertCount( 1, $this->engine->get_query_results() ); + } + + public function testNestedTransactionWorkComplexModify() { + $this->assertQuery( 'BEGIN' ); + // Create a complex ALTER Table query where the first + // column is added successfully, but the second fails. + // Behind the scenes, this single MySQL query is split + // into multiple SQLite queries – some of them will + // succeed, some will fail. + $success = $this->engine->query( + ' + ALTER TABLE _options + ADD COLUMN test varchar(20), + ADD COLUMN test varchar(20) + ' + ); + $this->assertFalse( $success ); + // Commit the transaction. + $this->assertQuery( 'COMMIT' ); + + // Confirm the entire query failed atomically and no column was + // added to the table. + $this->assertQuery( 'DESCRIBE _options;' ); + $fields = $this->engine->get_query_results(); + + $this->assertEquals( + $fields, + array( + (object) array( + 'Field' => 'ID', + 'Type' => 'integer', + 'Null' => 'NO', + 'Key' => 'PRI', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'option_name', + 'Type' => 'text', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + (object) array( + 'Field' => 'option_value', + 'Type' => 'text', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '', + 'Extra' => '', + ), + ) + ); + } + + public function testCount() { + $this->assertQuery( "INSERT INTO _options (option_name) VALUES ('first');" ); + $this->assertQuery( "INSERT INTO _options (option_name) VALUES ('second');" ); + $this->assertQuery( 'SELECT COUNT(*) as count FROM _options;' ); + + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertSame( '2', $results[0]->count ); + } + + public function testUpdateDate() { + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 10:08:48');" + ); + + $this->assertQuery( 'SELECT option_value FROM _dates' ); + + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( '2003-05-27 10:08:48', $results[0]->option_value ); + + $this->assertQuery( + "UPDATE _dates SET option_value = DATE_SUB(option_value, INTERVAL '2' YEAR);" + ); + + $this->assertQuery( 'SELECT option_value FROM _dates' ); + + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( '2001-05-27 10:08:48', $results[0]->option_value ); + } + + public function testInsertDateLiteral() { + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 10:08:48');" + ); + + $this->assertQuery( 'SELECT option_value FROM _dates' ); + + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( '2003-05-27 10:08:48', $results[0]->option_value ); + } + + public function testSelectDate1() { + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2000-05-27 10:08:48');" + ); + + $this->assertQuery( + 'SELECT + YEAR( _dates.option_value ) as year, + MONTH( _dates.option_value ) as month, + DAYOFMONTH( _dates.option_value ) as dayofmonth, + MONTHNUM( _dates.option_value ) as monthnum, + WEEKDAY( _dates.option_value ) as weekday, + WEEK( _dates.option_value, 1 ) as week1, + HOUR( _dates.option_value ) as hour, + MINUTE( _dates.option_value ) as minute, + SECOND( _dates.option_value ) as second + FROM _dates' + ); + + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( '2000', $results[0]->year ); + $this->assertEquals( '5', $results[0]->month ); + $this->assertEquals( '27', $results[0]->dayofmonth ); + $this->assertEquals( '5', $results[0]->weekday ); + $this->assertEquals( '21', $results[0]->week1 ); + $this->assertEquals( '5', $results[0]->monthnum ); + $this->assertEquals( '10', $results[0]->hour ); + $this->assertEquals( '8', $results[0]->minute ); + $this->assertEquals( '48', $results[0]->second ); + } + + public function testSelectDate24HourFormat() { + $this->assertQuery( + " + INSERT INTO _dates (option_name, option_value) + VALUES + ('second', '2003-05-27 14:08:48'), + ('first', '2003-05-27 00:08:48'); + " + ); + + // HOUR(14:08) should yield 14 in the 24 hour format + $this->assertQuery( "SELECT HOUR( _dates.option_value ) as hour FROM _dates WHERE option_name = 'second'" ); + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( '14', $results[0]->hour ); + + // HOUR(00:08) should yield 0 in the 24 hour format + $this->assertQuery( "SELECT HOUR( _dates.option_value ) as hour FROM _dates WHERE option_name = 'first'" ); + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( '0', $results[0]->hour ); + + // Lookup by HOUR(00:08) = 0 should yield the right record + $this->assertQuery( + 'SELECT HOUR( _dates.option_value ) as hour FROM _dates + WHERE HOUR(_dates.option_value) = 0 ' + ); + + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + $this->assertEquals( '0', $results[0]->hour ); + } + + public function testSelectByDateFunctions() { + $this->assertQuery( + " + INSERT INTO _dates (option_name, option_value) + VALUES ('second', '2014-10-21 00:42:29'); + " + ); + + // HOUR(14:08) should yield 14 in the 24 hour format + $this->assertQuery( + ' + SELECT * FROM _dates WHERE + year(option_value) = 2014 + AND monthnum(option_value) = 10 + AND day(option_value) = 21 + AND hour(option_value) = 0 + AND minute(option_value) = 42 + ' + ); + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + } + + public function testSelectByDateFormat() { + $this->assertQuery( + " + INSERT INTO _dates (option_name, option_value) + VALUES ('second', '2014-10-21 00:42:29'); + " + ); + + // HOUR(14:08) should yield 14 in the 24 hour format + $this->assertQuery( + " + SELECT * FROM _dates WHERE DATE_FORMAT(option_value, '%H.%i') = 0.42 + " + ); + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + } + + public function testInsertOnDuplicateKey() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + name varchar(20) NOT NULL default '', + UNIQUE KEY name (name) + );" + ); + $result1 = $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('first');" ); + $this->assertEquals( 1, $result1 ); + + $result2 = $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('FIRST') ON DUPLICATE KEY SET name=VALUES(`name`);" ); + $this->assertEquals( 1, $result2 ); + + $this->assertQuery( 'SELECT COUNT(*) as cnt FROM _tmp_table' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( 1, $results[0]->cnt ); + } + + public function testCreateTableCompositePk() { + $this->assertQuery( + 'CREATE TABLE wptests_term_relationships ( + object_id bigint(20) unsigned NOT NULL default 0, + term_taxonomy_id bigint(20) unsigned NOT NULL default 0, + term_order int(11) NOT NULL default 0, + PRIMARY KEY (object_id,term_taxonomy_id), + KEY term_taxonomy_id (term_taxonomy_id) + ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci' + ); + $result1 = $this->engine->query( 'INSERT INTO wptests_term_relationships VALUES (1,2,1),(1,3,2);' ); + $this->assertEquals( 2, $result1 ); + + $result2 = $this->engine->query( 'INSERT INTO wptests_term_relationships VALUES (1,2,2),(1,3,1);' ); + $this->assertEquals( false, $result2 ); + } + + public function testDescribeAccurate() { + $result = $this->assertQuery( + 'CREATE TABLE wptests_term_relationships ( + object_id bigint(20) unsigned NOT NULL default 0, + term_taxonomy_id bigint(20) unsigned NOT NULL default 0, + term_name varchar(11) NOT NULL default 0, + PRIMARY KEY (object_id,term_taxonomy_id), + KEY term_taxonomy_id (term_taxonomy_id), + KEY compound_key (object_id(20),term_taxonomy_id(20)), + FULLTEXT KEY term_name (term_name) + ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertNotFalse( $result ); + + $result = $this->assertQuery( 'DESCRIBE wptests_term_relationships;' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertNotFalse( $result ); + + $fields = $this->engine->get_query_results(); + + $this->assertEquals( + array( + (object) array( + 'Field' => 'object_id', + 'Type' => 'bigint(20) unsigned', + 'Null' => 'NO', + 'Key' => 'PRI', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'term_taxonomy_id', + 'Type' => 'bigint(20) unsigned', + 'Null' => 'NO', + 'Key' => 'PRI', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'term_name', + 'Type' => 'varchar(11)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + ), + $fields + ); + } + + public function testAlterTableAddColumnChangesMySQLDataType() { + $result = $this->assertQuery( + 'CREATE TABLE _test ( + object_id bigint(20) unsigned NOT NULL default 0 + )' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertNotFalse( $result ); + + $result = $this->assertQuery( "ALTER TABLE `_test` ADD COLUMN object_name varchar(255) NOT NULL DEFAULT 'adb';" ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertNotFalse( $result ); + + $result = $this->assertQuery( 'DESCRIBE _test;' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertNotFalse( $result ); + $fields = $this->engine->get_query_results(); + + $this->assertEquals( + array( + (object) array( + 'Field' => 'object_id', + 'Type' => 'bigint(20) unsigned', + 'Null' => 'NO', + 'Key' => '', + 'Default' => '0', + 'Extra' => '', + ), + (object) array( + 'Field' => 'object_name', + 'Type' => 'varchar(255)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => 'adb', + 'Extra' => '', + ), + ), + $fields + ); + } + public function testShowGrantsFor() { + $result = $this->assertQuery( 'SHOW GRANTS FOR current_user();' ); + $this->assertEquals( + $result, + array( + (object) array( + 'Grants for root@localhost' => 'GRANT SELECT, INSERT, UPDATE, DELETE, CREATE, DROP, RELOAD, SHUTDOWN, PROCESS, FILE, REFERENCES, INDEX, ALTER, SHOW DATABASES, SUPER, CREATE TEMPORARY TABLES, LOCK TABLES, EXECUTE, REPLICATION SLAVE, REPLICATION CLIENT, CREATE VIEW, SHOW VIEW, CREATE ROUTINE, ALTER ROUTINE, CREATE USER, EVENT, TRIGGER, CREATE TABLESPACE, CREATE ROLE, DROP ROLE ON *.* TO `root`@`localhost` WITH GRANT OPTION', + ), + ) + ); + } + + public function testShowIndex() { + $result = $this->assertQuery( + 'CREATE TABLE wptests_term_relationships ( + object_id bigint(20) unsigned NOT NULL default 0, + term_taxonomy_id bigint(20) unsigned NOT NULL default 0, + term_name varchar(11) NOT NULL default 0, + FULLTEXT KEY term_name_fulltext (term_name), + FULLTEXT INDEX term_name_fulltext2 (`term_name`), + SPATIAL KEY term_name_spatial (term_name), + PRIMARY KEY (object_id,term_taxonomy_id), + KEY term_taxonomy_id (term_taxonomy_id), + KEY compound_key (object_id(20),term_taxonomy_id(20)) + ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertNotFalse( $result ); + + $result = $this->assertQuery( 'SHOW INDEX FROM wptests_term_relationships;' ); + $this->assertNotFalse( $result ); + + $this->assertEquals( + array( + (object) array( + 'Table' => 'wptests_term_relationships', + 'Non_unique' => '0', + 'Key_name' => 'PRIMARY', + 'Seq_in_index' => '0', + 'Column_name' => 'object_id', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'BTREE', + 'Comment' => '', + 'Index_comment' => '', + ), + (object) array( + 'Table' => 'wptests_term_relationships', + 'Non_unique' => '0', + 'Key_name' => 'PRIMARY', + 'Seq_in_index' => '0', + 'Column_name' => 'term_taxonomy_id', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'BTREE', + 'Comment' => '', + 'Index_comment' => '', + ), + (object) array( + 'Table' => 'wptests_term_relationships', + 'Non_unique' => '1', + 'Key_name' => 'compound_key', + 'Seq_in_index' => '0', + 'Column_name' => 'object_id', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'BTREE', + 'Comment' => '', + 'Index_comment' => '', + ), + (object) array( + 'Table' => 'wptests_term_relationships', + 'Non_unique' => '1', + 'Key_name' => 'compound_key', + 'Seq_in_index' => '0', + 'Column_name' => 'term_taxonomy_id', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'BTREE', + 'Comment' => '', + 'Index_comment' => '', + ), + (object) array( + 'Table' => 'wptests_term_relationships', + 'Non_unique' => '1', + 'Key_name' => 'term_taxonomy_id', + 'Seq_in_index' => '0', + 'Column_name' => 'term_taxonomy_id', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'BTREE', + 'Comment' => '', + 'Index_comment' => '', + ), + (object) array( + 'Table' => 'wptests_term_relationships', + 'Non_unique' => '1', + 'Key_name' => 'term_name_spatial', + 'Seq_in_index' => '0', + 'Column_name' => 'term_name', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'SPATIAL', + 'Comment' => '', + 'Index_comment' => '', + ), + (object) array( + 'Table' => 'wptests_term_relationships', + 'Non_unique' => '1', + 'Key_name' => 'term_name_fulltext2', + 'Seq_in_index' => '0', + 'Column_name' => 'term_name', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'FULLTEXT', + 'Comment' => '', + 'Index_comment' => '', + ), + (object) array( + 'Table' => 'wptests_term_relationships', + 'Non_unique' => '1', + 'Key_name' => 'term_name_fulltext', + 'Seq_in_index' => '0', + 'Column_name' => 'term_name', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'FULLTEXT', + 'Comment' => '', + 'Index_comment' => '', + ), + (object) array( + 'Table' => 'wptests_term_relationships', + 'Non_unique' => '0', + 'Key_name' => 'wptests_term_relationships', + 'Seq_in_index' => '0', + 'Column_name' => 'object_id', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'BTREE', + 'Comment' => '', + 'Index_comment' => '', + ), + (object) array( + 'Table' => 'wptests_term_relationships', + 'Non_unique' => '0', + 'Key_name' => 'wptests_term_relationships', + 'Seq_in_index' => '0', + 'Column_name' => 'term_taxonomy_id', + 'Collation' => 'A', + 'Cardinality' => '0', + 'Sub_part' => null, + 'Packed' => null, + 'Null' => '', + 'Index_type' => 'BTREE', + 'Comment' => '', + 'Index_comment' => '', + ), + ), + $this->engine->get_query_results() + ); + } + + public function testInsertOnDuplicateKeyCompositePk() { + $result = $this->assertQuery( + 'CREATE TABLE wptests_term_relationships ( + object_id bigint(20) unsigned NOT NULL default 0, + term_taxonomy_id bigint(20) unsigned NOT NULL default 0, + term_order int(11) NOT NULL default 0, + PRIMARY KEY (object_id,term_taxonomy_id), + KEY term_taxonomy_id (term_taxonomy_id) + ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertNotFalse( $result ); + + $result1 = $this->assertQuery( 'INSERT INTO wptests_term_relationships VALUES (1,2,1),(1,3,2);' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 2, $result1 ); + + $result2 = $this->assertQuery( 'INSERT INTO wptests_term_relationships VALUES (1,2,2),(1,3,1) ON DUPLICATE KEY SET term_order = VALUES(term_order);' ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 2, $result2 ); + + $this->assertQuery( 'SELECT COUNT(*) as cnt FROM wptests_term_relationships' ); + $results = $this->engine->get_query_results(); + $this->assertEquals( 2, $results[0]->cnt ); + } + + public function testStringToFloatComparison() { + $this->assertQuery( "SELECT ('00.42' = 0.4200) as cmp;" ); + $results = $this->engine->get_query_results(); + if ( 1 !== $results[0]->cmp ) { + $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() { + $result = $this->assertQuery( + "CREATE TABLE wptests_dummy ( + ID INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, + user_login TEXT NOT NULL default '' + );" + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertNotFalse( $result ); + + $result = $this->assertQuery( + "INSERT INTO wptests_dummy (user_login) VALUES ('test');" + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 1, $result ); + + $result = $this->assertQuery( + 'SELECT SQL_CALC_FOUND_ROWS * FROM wptests_dummy' + ); + $this->assertNotFalse( $result ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( 'test', $result[0]->user_login ); + } + + public function testComplexSelectBasedOnDates() { + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 10:08:48');" + ); + + $this->assertQuery( + 'SELECT SQL_CALC_FOUND_ROWS _dates.ID + FROM _dates + WHERE YEAR( _dates.option_value ) = 2003 AND MONTH( _dates.option_value ) = 5 AND DAYOFMONTH( _dates.option_value ) = 27 + ORDER BY _dates.option_value DESC + LIMIT 0, 10' + ); + + $results = $this->engine->get_query_results(); + $this->assertCount( 1, $results ); + } + + public function testUpdateReturnValue() { + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', '2003-05-27 10:08:48');" + ); + + $return = $this->assertQuery( + "UPDATE _dates SET option_value = '2001-05-27 10:08:48'" + ); + $this->assertSame( 1, $return, 'UPDATE query did not return 1 when one row was changed' ); + + $return = $this->assertQuery( + "UPDATE _dates SET option_value = '2001-05-27 10:08:48'" + ); + if ( 1 === $return ) { + $this->markTestIncomplete( + 'SQLite UPDATE query returned 1 when no rows were changed. ' . + 'This is a database compatibility issue – MySQL would return 0 ' . + 'in the same scenario.' + ); + } + $this->assertSame( 0, $return, 'UPDATE query did not return 0 when no rows were changed' ); + } + + public function testOrderByField() { + $this->assertQuery( + "INSERT INTO _options (option_name, option_value) VALUES ('User 0000019', 'second');" + ); + $this->assertQuery( + "INSERT INTO _options (option_name, option_value) VALUES ('User 0000020', 'third');" + ); + $this->assertQuery( + "INSERT INTO _options (option_name, option_value) VALUES ('User 0000018', 'first');" + ); + + $this->assertQuery( 'SELECT FIELD(option_name, "User 0000018", "User 0000019", "User 0000020") as sorting_order FROM _options ORDER BY FIELD(option_name, "User 0000018", "User 0000019", "User 0000020")' ); + + $this->assertEquals( + array( + (object) array( + 'sorting_order' => '1', + ), + (object) array( + 'sorting_order' => '2', + ), + (object) array( + 'sorting_order' => '3', + ), + ), + $this->engine->get_query_results() + ); + + $this->assertQuery( 'SELECT option_value FROM _options ORDER BY FIELD(option_name, "User 0000018", "User 0000019", "User 0000020")' ); + + $this->assertEquals( + array( + (object) array( + 'option_value' => 'first', + ), + (object) array( + 'option_value' => 'second', + ), + (object) array( + 'option_value' => 'third', + ), + ), + $this->engine->get_query_results() + ); + } + + public function testFetchedDataIsStringified() { + $this->assertQuery( + "INSERT INTO _options (option_name, option_value) VALUES ('rss_0123456789abcdef0123456789abcdef', '1');" + ); + + $this->assertQuery( 'SELECT ID FROM _options' ); + + $this->assertEquals( + array( + (object) array( + 'ID' => '1', + ), + ), + $this->engine->get_query_results() + ); + } + + public function testCreateTableQuery() { + $this->assertQuery( + <<<'QUERY' + CREATE TABLE IF NOT EXISTS wptests_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) + ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci +QUERY + ); + $this->assertQuery( + <<<'QUERY' + INSERT INTO wptests_users VALUES (1,'admin','$P$B5ZQZ5ZQZ5ZQZ5ZQZ5ZQZ5ZQZ5ZQZ5','admin','admin@localhost', '', '2019-01-01 00:00:00', '', 0, 'admin'); +QUERY + ); + $rows = $this->assertQuery( 'SELECT * FROM wptests_users' ); + $this->assertCount( 1, $rows ); + + $this->assertQuery( 'SELECT SQL_CALC_FOUND_ROWS * FROM wptests_users' ); + $result = $this->assertQuery( 'SELECT FOUND_ROWS()' ); + $this->assertEquals( + array( + (object) array( + 'FOUND_ROWS()' => '1', + ), + ), + $result + ); + } + + public function testTranslatesComplexDelete() { + $this->sqlite->query( + "CREATE TABLE wptests_dummy ( + ID INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, + user_login TEXT NOT NULL default '', + option_name TEXT NOT NULL default '', + option_value TEXT NOT NULL default '' + );" + ); + $this->sqlite->query( + "INSERT INTO wptests_dummy (user_login, option_name, option_value) VALUES ('admin', '_transient_timeout_test', '1675963960');" + ); + $this->sqlite->query( + "INSERT INTO wptests_dummy (user_login, option_name, option_value) VALUES ('admin', '_transient_test', '1675963960');" + ); + + $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_%' + AND b.option_name = CONCAT( '_transient_timeout_', SUBSTRING( a.option_name, 12 ) );" + ); + $this->assertEquals( + 2, + $result + ); + } + + public function testTranslatesDoubleAlterTable() { + $result = $this->assertQuery( + '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)) + ' + ); + $this->assertEquals( '', $this->engine->get_error_message() ); + $this->assertEquals( + 1, + $result + ); + $result = $this->assertQuery( + 'SHOW INDEX FROM _options' + ); + $this->assertCount( 3, $result ); + $this->assertEquals( 'PRIMARY', $result[0]->Key_name ); + $this->assertEquals( 'test_index2', $result[1]->Key_name ); + $this->assertEquals( 'test_index2', $result[2]->Key_name ); + } + + public function testTranslatesComplexSelect() { + $this->assertQuery( + "CREATE TABLE wptests_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)) + ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci" + ); + $this->assertQuery( + "CREATE TABLE wptests_posts ( + ID bigint(20) unsigned NOT NULL auto_increment, + post_status varchar(20) NOT NULL default 'open', + post_type varchar(20) NOT NULL default 'post', + post_date varchar(20) NOT NULL default 'post', + PRIMARY KEY (ID) + ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci" + ); + $result = $this->assertQuery( + "SELECT SQL_CALC_FOUND_ROWS wptests_posts.ID + FROM wptests_posts INNER JOIN wptests_postmeta ON ( wptests_posts.ID = wptests_postmeta.post_id ) + WHERE 1=1 + AND ( + NOT EXISTS ( + SELECT 1 FROM wptests_postmeta mt1 + WHERE mt1.post_ID = wptests_postmeta.post_ID + LIMIT 1 + ) + ) + AND ( + (wptests_posts.post_type = 'post' AND (wptests_posts.post_status = 'publish')) + ) + GROUP BY wptests_posts.ID + ORDER BY wptests_posts.post_date DESC + LIMIT 0, 10" + ); + + // No exception is good enough of a test for now + $this->assertTrue( true ); + } + + public function testTranslatesUtf8Insert() { + $this->assertQuery( + "INSERT INTO _options VALUES(1,'ąłółźćę†','ąłółźćę†')" + ); + $this->assertCount( + 1, + $this->assertQuery( 'SELECT * FROM _options' ) + ); + $this->assertQuery( 'DELETE FROM _options' ); + } + + public function testTranslatesRandom() { + $this->assertIsNumeric( + $this->sqlite->query( 'SELECT RAND() AS rand' )->fetchColumn() + ); + + $this->assertIsNumeric( + $this->sqlite->query( 'SELECT RAND(5) AS rand' )->fetchColumn() + ); + } + + public function testTranslatesUtf8SELECT() { + $this->assertQuery( + "INSERT INTO _options VALUES(1,'ąłółźćę†','ąłółźćę†')" + ); + $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' ); + } + + public function testTranslateLikeBinaryAndGlob() { + // Create a temporary table for testing + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, + name varchar(20) NOT NULL default '' + );" + ); + + // Insert data into the table + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('first');" ); + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('FIRST');" ); + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('second');" ); + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('');" ); + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('%special%');" ); + $this->assertQuery( 'INSERT INTO _tmp_table (name) VALUES (NULL);' ); + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('special%chars');" ); + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('special_chars');" ); + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('special\\chars');" ); + + // Test case-sensitive LIKE BINARY + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'first'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'first', $result[0]->name ); + + // Test case-sensitive LIKE BINARY with wildcard % + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f%'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'first', $result[0]->name ); + + // Test case-sensitive LIKE BINARY with wildcard _ + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f_rst'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'first', $result[0]->name ); + + // Test case-insensitive LIKE + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE 'FIRST'" ); + $this->assertCount( 2, $result ); // Should match both 'first' and 'FIRST' + + // Test mixed case with LIKE BINARY + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'First'" ); + $this->assertCount( 0, $result ); + + // Test no matches with LIKE BINARY + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'third'" ); + $this->assertCount( 0, $result ); + + // Test GLOB equivalent for case-sensitive matching with wildcard + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'f*'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'first', $result[0]->name ); + + // Test GLOB with single character wildcard + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'f?rst'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'first', $result[0]->name ); + + // Test GLOB with no matches + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'S*'" ); + $this->assertCount( 0, $result ); + + // Test GLOB case sensitivity with LIKE and GLOB + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'first';" ); + $this->assertCount( 1, $result ); // Should only match 'first' + + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'FIRST';" ); + $this->assertCount( 1, $result ); // Should only match 'FIRST' + + // Test NULL comparison with LIKE BINARY + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'first';" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'first', $result[0]->name ); + + $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE name LIKE BINARY NULL;' ); + $this->assertCount( 0, $result ); // NULL comparison should return no results + + // Test pattern with special characters using LIKE BINARY + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY '%special%';" ); + $this->assertCount( 4, $result ); + $this->assertEquals( '%special%', $result[0]->name ); + $this->assertEquals( 'special%chars', $result[1]->name ); + $this->assertEquals( 'special_chars', $result[2]->name ); + $this->assertEquals( 'specialchars', $result[3]->name ); + } + + public function testOnConflictReplace() { + $this->assertQuery( + "CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, + name varchar(20) NOT NULL default 'default-value', + unique_name varchar(20) NOT NULL default 'unique-default-value', + inline_unique_name varchar(20) NOT NULL default 'inline-unique-default-value', + no_default varchar(20) NOT NULL, + UNIQUE KEY unique_name (unique_name) + );" + ); + + $this->assertQuery( + "INSERT INTO _tmp_table VALUES (1, null, null, null, '');" + ); + $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE ID = 1' ); + $this->assertEquals( + array( + (object) array( + 'ID' => '1', + 'name' => 'default-value', + 'unique_name' => 'unique-default-value', + 'inline_unique_name' => 'inline-unique-default-value', + 'no_default' => '', + ), + ), + $result + ); + + $this->assertQuery( + "INSERT INTO _tmp_table VALUES (2, '1', '2', '3', '4');" + ); + $this->assertQuery( + 'UPDATE _tmp_table SET name = null WHERE ID = 2;' + ); + + $result = $this->assertQuery( 'SELECT name FROM _tmp_table WHERE ID = 2' ); + $this->assertEquals( + array( + (object) array( + 'name' => 'default-value', + ), + ), + $result + ); + + // This should fail because of the UNIQUE constraint + $this->assertQuery( + 'UPDATE _tmp_table SET unique_name = NULL WHERE ID = 2;', + 'UNIQUE constraint failed: _tmp_table.unique_name' + ); + + // Inline unique constraint aren't supported currently, so this should pass + $this->assertQuery( + 'UPDATE _tmp_table SET inline_unique_name = NULL WHERE ID = 2;', + '' + ); + + // WPDB allows for NULL values in columns that don't have a default value and a NOT NULL constraint + $this->assertQuery( + 'UPDATE _tmp_table SET no_default = NULL WHERE ID = 2;', + '' + ); + + $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE ID = 2' ); + $this->assertEquals( + array( + (object) array( + 'ID' => '2', + 'name' => 'default-value', + 'unique_name' => '2', + 'inline_unique_name' => 'inline-unique-default-value', + 'no_default' => '', + ), + ), + $result + ); + } + + public function testDefaultNullValue() { + $this->assertQuery( + 'CREATE TABLE _tmp_table ( + name varchar(20) NOT NULL default NULL, + no_default varchar(20) NOT NULL + );' + ); + + $result = $this->assertQuery( + 'DESCRIBE _tmp_table;' + ); + $this->assertEquals( + array( + (object) array( + 'Field' => 'name', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => 'NULL', + 'Extra' => '', + ), + (object) array( + 'Field' => 'no_default', + 'Type' => 'varchar(20)', + 'Null' => 'NO', + 'Key' => '', + 'Default' => null, + 'Extra' => '', + ), + ), + $result + ); + } + + public function testCurrentTimestamp() { + // SELECT + $results = $this->assertQuery( + 'SELECT + current_timestamp AS t1, + CURRENT_TIMESTAMP AS t2, + current_timestamp() AS t3, + CURRENT_TIMESTAMP() AS t4' + ); + $this->assertIsArray( $results ); + $this->assertCount( 1, $results ); + $this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $results[0]->t1 ); + $this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $results[0]->t2 ); + $this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $results[0]->t3 ); + + // INSERT + $this->assertQuery( + "INSERT INTO _dates (option_name, option_value) VALUES ('first', 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 ); + + // UPDATE + $this->assertQuery( 'UPDATE _dates SET option_value = NULL' ); + $results = $this->assertQuery( 'SELECT option_value AS t FROM _dates' ); + $this->assertCount( 1, $results ); + $this->assertEmpty( $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 ); + + // DELETE + // We can only assert that the query passes. It is not guaranteed that we'll actually + // delete the existing record, as the delete query could fall into a different second. + $this->assertQuery( 'DELETE FROM _dates WHERE option_value = CURRENT_TIMESTAMP()' ); + } + + public function testGroupByHaving() { + $this->assertQuery( + 'CREATE TABLE _tmp_table ( + name varchar(20) + );' + ); + + $this->assertQuery( + "INSERT INTO _tmp_table VALUES ('a'), ('b'), ('b'), ('c'), ('c'), ('c')" + ); + + $result = $this->assertQuery( + 'SELECT name, COUNT(*) as count FROM _tmp_table GROUP BY name HAVING COUNT(*) > 1' + ); + $this->assertEquals( + array( + (object) array( + 'name' => 'b', + 'count' => '2', + ), + (object) array( + 'name' => 'c', + 'count' => '3', + ), + ), + $result + ); + } + + public function testHavingWithoutGroupBy() { + $this->assertQuery( + 'CREATE TABLE _tmp_table ( + name varchar(20) + );' + ); + + $this->assertQuery( + "INSERT INTO _tmp_table VALUES ('a'), ('b'), ('b'), ('c'), ('c'), ('c')" + ); + + // HAVING condition satisfied + $result = $this->assertQuery( + "SELECT 'T' FROM _tmp_table HAVING COUNT(*) > 1" + ); + $this->assertEquals( + array( + (object) array( + ':param0' => 'T', + ), + ), + $result + ); + + // HAVING condition not satisfied + $result = $this->assertQuery( + "SELECT 'T' FROM _tmp_table HAVING COUNT(*) > 100" + ); + $this->assertEquals( + array(), + $result + ); + + // DISTINCT ... HAVING, where only some results meet the HAVING condition + $result = $this->assertQuery( + 'SELECT DISTINCT name FROM _tmp_table HAVING COUNT(*) > 1' + ); + $this->assertEquals( + array( + (object) array( + 'name' => 'b', + ), + (object) array( + 'name' => 'c', + ), + ), + $result + ); + } + + /** + * @dataProvider mysqlVariablesToTest + */ + public function testSelectVariable( $variable_name ) { + // Make sure the query does not error + $this->assertQuery( "SELECT $variable_name;" ); + } + + public static function mysqlVariablesToTest() { + return array( + // NOTE: This list was derived from the variables used by the UpdraftPlus plugin. + // We will start here and plan to expand supported variables over time. + array( '@@character_set_client' ), + array( '@@character_set_results' ), + array( '@@collation_connection' ), + array( '@@GLOBAL.gtid_purged' ), + array( '@@GLOBAL.log_bin' ), + array( '@@GLOBAL.log_bin_trust_function_creators' ), + array( '@@GLOBAL.sql_mode' ), + array( '@@SESSION.max_allowed_packet' ), + array( '@@SESSION.sql_mode' ), + + // Intentionally mix letter casing to help demonstrate case-insensitivity + array( '@@cHarActer_Set_cLient' ), + array( '@@gLoBAL.gTiD_purGed' ), + array( '@@sEssIOn.sqL_moDe' ), + ); + } +} diff --git a/tests/tools/dump-sqlite-query.php b/tests/tools/dump-sqlite-query.php index a4594bd3..555b454e 100644 --- a/tests/tools/dump-sqlite-query.php +++ b/tests/tools/dump-sqlite-query.php @@ -14,10 +14,8 @@ use WIP\WP_SQLite_Driver; -$grammar_data = include __DIR__ . '/../../wp-includes/mysql/mysql-grammar.php'; -$grammar = new WP_Parser_Grammar( $grammar_data ); -$driver = new WP_SQLite_Driver( $grammar ); +$driver = new WP_SQLite_Driver( new PDO( 'sqlite::memory:' ) ); $query = "SELECT * FROM t1 LEFT JOIN t2 ON t1.id = t2.t1_id WHERE t1.name = 'abc'"; -echo $driver->run_query( $query ); +echo $driver->query( $query ); diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 5ada9621..cd7e36fb 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -11,17 +11,36 @@ use WP_Parser_Grammar; use WP_Parser_Node; +$grammar = new WP_Parser_Grammar( require __DIR__ . '/../../wp-includes/mysql/mysql-grammar.php' ); + class WP_SQLite_Driver { + /** + * @var WP_Parser_Grammar + */ private $grammar; + + /** + * @var PDO + */ + private $pdo; + + private $results; + private $has_sql_calc_found_rows = false; private $has_found_rows_call = false; private $last_calc_rows_result = null; - public function __construct( $grammar ) { + public function __construct( PDO $pdo ) { + global $grammar; + $this->pdo = $pdo; $this->grammar = $grammar; + + $pdo->setAttribute( PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION ); + $pdo->setAttribute( PDO::ATTR_STRINGIFY_FETCHES, true ); + $pdo->setAttribute( PDO::ATTR_TIMEOUT, 5 ); } - public function run_query( $query ) { + public function query( $query ) { $this->has_sql_calc_found_rows = false; $this->has_found_rows_call = false; $this->last_calc_rows_result = null; @@ -32,13 +51,37 @@ public function run_query( $query ) { $parser = new WP_MySQL_Parser( $this->grammar, $tokens ); $ast = $parser->parse(); $expr = $this->translate_query( $ast ); - $expr = $this->rewrite_sql_calc_found_rows( $expr ); + //$expr = $this->rewrite_sql_calc_found_rows( $expr ); + + if ( null === $expr ) { + return false; + } $sqlite_query = WP_SQLite_Query_Builder::stringify( $expr ); // Returning the query just for now for testing. In the end, we'll // run it and return the SQLite interaction result. - return $sqlite_query; + //return $sqlite_query; + + if ( ! $sqlite_query ) { + return false; + } + + $is_select = (bool) $ast->get_descendant( 'selectStatement' ); + $statement = $this->pdo->prepare( $sqlite_query ); + $return_value = $statement->execute(); + $this->results = $return_value; + if ( $is_select ) { + $this->results = $statement->fetchAll( PDO::FETCH_OBJ ); + } + return $return_value; + } + + public function get_error_message() { + } + + public function get_query_results() { + return $this->results; } private function rewrite_sql_calc_found_rows( WP_SQLite_Expression $expr ) { @@ -252,6 +295,7 @@ private function translate_query( $ast ) { return $this->translate_runtime_function_call( $ast ); default: + return null; // var_dump(count($ast->children)); // foreach($ast->children as $child) { // var_dump(get_class($child)); From c8ea8557cc9e64099043250ee1004f6efdc6b21f Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Mon, 18 Nov 2024 21:16:47 +0100 Subject: [PATCH 04/36] Copy the core of WP_SQLite_Translator to WP_SQLite_Driver Additionally, move the current SQLite driver prototype to a temporary class WP_SQLite_Driver_Prototype to be gradually moved to the new driver. --- tests/tools/dump-sqlite-query.php | 1 + .../class-wp-sqlite-driver-prototype.php | 670 +++++++++ .../sqlite-ast/class-wp-sqlite-driver.php | 1298 +++++++++-------- 3 files changed, 1378 insertions(+), 591 deletions(-) create mode 100644 wp-includes/sqlite-ast/class-wp-sqlite-driver-prototype.php diff --git a/tests/tools/dump-sqlite-query.php b/tests/tools/dump-sqlite-query.php index 555b454e..8b2ada80 100644 --- a/tests/tools/dump-sqlite-query.php +++ b/tests/tools/dump-sqlite-query.php @@ -6,6 +6,7 @@ require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-lexer.php'; require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-token.php'; require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-parser.php'; +require_once __DIR__ . '/../../wp-includes/sqlite/class-wp-sqlite-pdo-user-defined-functions.php'; require_once __DIR__ . '/../../wp-includes/sqlite-ast/class-wp-sqlite-expression.php'; require_once __DIR__ . '/../../wp-includes/sqlite-ast/class-wp-sqlite-driver.php'; require_once __DIR__ . '/../../wp-includes/sqlite-ast/class-wp-sqlite-token-factory.php'; diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver-prototype.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver-prototype.php new file mode 100644 index 00000000..98e732a2 --- /dev/null +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver-prototype.php @@ -0,0 +1,670 @@ +pdo = $pdo; + $this->grammar = $grammar; + + $pdo->setAttribute( PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION ); + $pdo->setAttribute( PDO::ATTR_STRINGIFY_FETCHES, true ); + $pdo->setAttribute( PDO::ATTR_TIMEOUT, 5 ); + } + + public function query( $query ) { + $this->has_sql_calc_found_rows = false; + $this->has_found_rows_call = false; + $this->last_calc_rows_result = null; + + $lexer = new WP_MySQL_Lexer( $query ); + $tokens = $lexer->remaining_tokens(); + + $parser = new WP_MySQL_Parser( $this->grammar, $tokens ); + $ast = $parser->parse(); + $expr = $this->translate_query( $ast ); + //$expr = $this->rewrite_sql_calc_found_rows( $expr ); + + if ( null === $expr ) { + return false; + } + + $sqlite_query = WP_SQLite_Query_Builder::stringify( $expr ); + + // Returning the query just for now for testing. In the end, we'll + // run it and return the SQLite interaction result. + //return $sqlite_query; + + if ( ! $sqlite_query ) { + return false; + } + + $is_select = (bool) $ast->get_descendant( 'selectStatement' ); + $statement = $this->pdo->prepare( $sqlite_query ); + $return_value = $statement->execute(); + $this->results = $return_value; + if ( $is_select ) { + $this->results = $statement->fetchAll( PDO::FETCH_OBJ ); + } + return $return_value; + } + + public function get_error_message() { + } + + public function get_query_results() { + return $this->results; + } + + private function rewrite_sql_calc_found_rows( WP_SQLite_Expression $expr ) { + if ( $this->has_found_rows_call && ! $this->has_sql_calc_found_rows && null === $this->last_calc_rows_result ) { + throw new Exception( 'FOUND_ROWS() called without SQL_CALC_FOUND_ROWS' ); + } + + if ( $this->has_sql_calc_found_rows ) { + $expr_to_run = $expr; + if ( $this->has_found_rows_call ) { + $expr_without_found_rows = new WP_SQLite_Expression( array() ); + foreach ( $expr->elements as $k => $element ) { + if ( WP_SQLite_Token::TYPE_IDENTIFIER === $element->type && 'FOUND_ROWS' === $element->value ) { + $expr_without_found_rows->add_token( + WP_SQLite_Token_Factory::value( 0 ) + ); + } else { + $expr_without_found_rows->add_token( $element ); + } + } + $expr_to_run = $expr_without_found_rows; + } + + // ...remove the LIMIT clause... + $query = 'SELECT COUNT(*) as cnt FROM (' . WP_SQLite_Query_Builder::stringify( $expr_to_run ) . ');'; + + // ...run $query... + // $result = ... + // $this->last_calc_rows_result = $result['cnt']; + } + + if ( ! $this->has_found_rows_call ) { + return $expr; + } + + $expr_with_found_rows_result = new WP_SQLite_Expression( array() ); + foreach ( $expr->elements as $k => $element ) { + if ( WP_SQLite_Token::TYPE_IDENTIFIER === $element->type && 'FOUND_ROWS' === $element->value ) { + $expr_with_found_rows_result->add_token( + WP_SQLite_Token_Factory::value( $this->last_calc_rows_result ) + ); + } else { + $expr_with_found_rows_result->add_token( $element ); + } + } + return $expr_with_found_rows_result; + } + + private function translate_query( $ast ) { + if ( null === $ast ) { + return null; + } + + if ( $ast instanceof WP_MySQL_Token ) { + $token = $ast; + switch ( $token->type ) { + case WP_MySQL_Lexer::EOF: + return new WP_SQLite_Expression( array() ); + + case WP_MySQL_Lexer::IDENTIFIER: + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::identifier( + trim( $token->text, '`"' ) + ), + ) + ); + + default: + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( $token->text ), + ) + ); + } + } + + if ( ! ( $ast instanceof WP_Parser_Node ) ) { + throw new Exception( 'translate_query only accepts WP_MySQL_Token and WP_Parser_Node instances' ); + } + + $rule_name = $ast->rule_name; + + switch ( $rule_name ) { + case 'indexHintList': + // SQLite doesn't support index hints. Let's skip them. + return null; + + case 'querySpecOption': + $token = $ast->get_token(); + switch ( $token->type ) { + case WP_MySQL_Lexer::ALL_SYMBOL: + case WP_MySQL_Lexer::DISTINCT_SYMBOL: + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( $token->text ), + ) + ); + case WP_MySQL_Lexer::SQL_CALC_FOUND_ROWS_SYMBOL: + $this->has_sql_calc_found_rows = true; + // Fall through to default. + default: + // we'll need to run the current SQL query without any + // LIMIT clause, and then substitute the FOUND_ROWS() + // function with a literal number of rows found. + return new WP_SQLite_Expression( array() ); + } + // Otherwise, fall through. + + case 'fromClause': + // Skip `FROM DUAL`. We only care about a singular + // FROM DUAL statement, as FROM mytable, DUAL is a syntax + // error. + if ( + $ast->has_token( WP_MySQL_Lexer::DUAL_SYMBOL ) && + ! $ast->has_child( 'tableReferenceList' ) + ) { + return null; + } + // Otherwise, fall through. + + case 'selectOption': + case 'interval': + case 'intervalTimeStamp': + case 'bitExpr': + case 'boolPri': + case 'lockStrengh': + case 'orderList': + case 'simpleExpr': + case 'columnRef': + case 'exprIs': + case 'exprAnd': + case 'primaryExprCompare': + case 'fieldIdentifier': + case 'dotIdentifier': + case 'identifier': + case 'literal': + case 'joinedTable': + case 'nullLiteral': + case 'boolLiteral': + case 'numLiteral': + case 'textLiteral': + case 'predicate': + case 'predicateExprBetween': + case 'primaryExprPredicate': + case 'pureIdentifier': + case 'unambiguousIdentifier': + case 'qualifiedIdentifier': + case 'query': + case 'queryExpression': + case 'queryExpressionBody': + case 'queryExpressionParens': + case 'queryPrimary': + case 'querySpecification': + case 'queryTerm': + case 'selectAlias': + case 'selectItem': + case 'selectItemList': + case 'selectStatement': + case 'simpleExprColumnRef': + case 'simpleExprFunction': + case 'outerJoinType': + case 'simpleExprSubQuery': + case 'simpleExprLiteral': + case 'compOp': + case 'simpleExprList': + case 'simpleStatement': + case 'subquery': + case 'exprList': + case 'expr': + case 'tableReferenceList': + case 'tableReference': + case 'tableRef': + case 'tableAlias': + case 'tableFactor': + case 'singleTable': + case 'udfExprList': + case 'udfExpr': + case 'withClause': + case 'whereClause': + case 'commonTableExpression': + case 'derivedTable': + case 'columnRefOrLiteral': + case 'orderClause': + case 'groupByClause': + case 'lockingClauseList': + case 'lockingClause': + case 'havingClause': + case 'direction': + case 'orderExpression': + $child_expressions = array(); + foreach ( $ast->children as $child ) { + $child_expressions[] = $this->translate_query( $child ); + } + return new WP_SQLite_Expression( $child_expressions ); + + case 'textStringLiteral': + return new WP_SQLite_Expression( + array( + $ast->has_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT ) ? + WP_SQLite_Token_Factory::double_quoted_value( $ast->get_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT )->text ) : false, + $ast->has_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT ) ? + WP_SQLite_Token_Factory::raw( $ast->get_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT )->text ) : false, + ) + ); + + case 'functionCall': + return $this->translate_function_call( $ast ); + + case 'runtimeFunctionCall': + return $this->translate_runtime_function_call( $ast ); + + default: + return null; + // var_dump(count($ast->children)); + // foreach($ast->children as $child) { + // var_dump(get_class($child)); + // echo $child->getText(); + // echo "\n\n"; + // } + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( + $rule_name + ), + ) + ); + } + } + + private function translate_runtime_function_call( $ast ): WP_SQLite_Expression { + $name_token = $ast->children[0]; + + switch ( strtoupper( $name_token->text ) ) { + case 'ADDDATE': + case 'DATE_ADD': + $args = $ast->get_children( 'expr' ); + $interval = $ast->get_child( 'interval' ); + $timespan = $interval->get_child( 'intervalTimeStamp' )->get_token()->text; + return WP_SQLite_Token_Factory::create_function( + 'DATETIME', + array( + $this->translate_query( $args[0] ), + new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::value( '+' ), + WP_SQLite_Token_Factory::raw( '||' ), + $this->translate_query( $args[1] ), + WP_SQLite_Token_Factory::raw( '||' ), + WP_SQLite_Token_Factory::value( $timespan ), + ) + ), + ) + ); + + case 'DATE_SUB': + // return new WP_SQLite_Expression([ + // SQLiteTokenFactory::raw("DATETIME("), + // $args[0], + // SQLiteTokenFactory::raw(", '-'"), + // $args[1], + // SQLiteTokenFactory::raw(" days')") + // ]); + + case 'VALUES': + $column = $ast->get_child()->get_descendant( 'pureIdentifier' ); + if ( ! $column ) { + throw new Exception( 'VALUES() calls without explicit column names are unsupported' ); + } + + $colname = $column->get_token()->extract_value(); + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( 'excluded.' ), + WP_SQLite_Token_Factory::identifier( $colname ), + ) + ); + default: + throw new Exception( 'Unsupported function: ' . $name_token->text ); + } + } + + private function translate_function_call( $function_call_tree ): WP_SQLite_Expression { + $name = $function_call_tree->get_child( 'pureIdentifier' )->get_token()->text; + $args = array(); + foreach ( $function_call_tree->get_child( 'udfExprList' )->get_children() as $node ) { + $args[] = $this->translate_query( $node ); + } + switch ( strtoupper( $name ) ) { + case 'ABS': + case 'ACOS': + case 'ASIN': + case 'ATAN': + case 'ATAN2': + case 'COS': + case 'DEGREES': + case 'TRIM': + case 'EXP': + case 'MAX': + case 'MIN': + case 'FLOOR': + case 'RADIANS': + case 'ROUND': + case 'SIN': + case 'SQRT': + case 'TAN': + case 'TRUNCATE': + case 'RANDOM': + case 'PI': + case 'LTRIM': + case 'RTRIM': + return WP_SQLite_Token_Factory::create_function( $name, $args ); + + case 'CEIL': + case 'CEILING': + return WP_SQLite_Token_Factory::create_function( 'CEIL', $args ); + + case 'COT': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( '1 / ' ), + WP_SQLite_Token_Factory::create_function( 'TAN', $args ), + ) + ); + + case 'LN': + case 'LOG': + case 'LOG2': + return WP_SQLite_Token_Factory::create_function( 'LOG', $args ); + + case 'LOG10': + return WP_SQLite_Token_Factory::create_function( 'LOG10', $args ); + + // case 'MOD': + // return $this->transformBinaryOperation([ + // 'operator' => '%', + // 'left' => $args[0], + // 'right' => $args[1] + // ]); + + case 'POW': + case 'POWER': + return WP_SQLite_Token_Factory::create_function( 'POW', $args ); + + // String functions + case 'ASCII': + return WP_SQLite_Token_Factory::create_function( 'UNICODE', $args ); + case 'CHAR_LENGTH': + case 'LENGTH': + return WP_SQLite_Token_Factory::create_function( 'LENGTH', $args ); + case 'CONCAT': + $concated = array( WP_SQLite_Token_Factory::raw( '(' ) ); + foreach ( $args as $k => $arg ) { + $concated[] = $arg; + if ( $k < count( $args ) - 1 ) { + $concated[] = WP_SQLite_Token_Factory::raw( '||' ); + } + } + $concated[] = WP_SQLite_Token_Factory::raw( ')' ); + return new WP_SQLite_Expression( $concated ); + // case 'CONCAT_WS': + // return new WP_SQLite_Expression([ + // SQLiteTokenFactory::raw("REPLACE("), + // implode(" || ", array_slice($args, 1)), + // SQLiteTokenFactory::raw(", '', "), + // $args[0], + // SQLiteTokenFactory::raw(")") + // ]); + case 'INSTR': + return WP_SQLite_Token_Factory::create_function( 'INSTR', $args ); + case 'LCASE': + case 'LOWER': + return WP_SQLite_Token_Factory::create_function( 'LOWER', $args ); + case 'LEFT': + return WP_SQLite_Token_Factory::create_function( + 'SUBSTR', + array( + $args[0], + '1', + $args[1], + ) + ); + case 'LOCATE': + return WP_SQLite_Token_Factory::create_function( + 'INSTR', + array( + $args[1], + $args[0], + ) + ); + case 'REPEAT': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( "REPLACE(CHAR(32), ' ', " ), + $args[0], + WP_SQLite_Token_Factory::raw( ')' ), + ) + ); + + case 'REPLACE': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( 'REPLACE(' ), + implode( ', ', $args ), + WP_SQLite_Token_Factory::raw( ')' ), + ) + ); + case 'RIGHT': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( 'SUBSTR(' ), + $args[0], + WP_SQLite_Token_Factory::raw( ', -(' ), + $args[1], + WP_SQLite_Token_Factory::raw( '))' ), + ) + ); + case 'SPACE': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( "REPLACE(CHAR(32), ' ', '')" ), + ) + ); + case 'SUBSTRING': + case 'SUBSTR': + return WP_SQLite_Token_Factory::create_function( 'SUBSTR', $args ); + case 'UCASE': + case 'UPPER': + return WP_SQLite_Token_Factory::create_function( 'UPPER', $args ); + + case 'DATE_FORMAT': + $mysql_date_format_to_sqlite_strftime = array( + '%a' => '%D', + '%b' => '%M', + '%c' => '%n', + '%D' => '%jS', + '%d' => '%d', + '%e' => '%j', + '%H' => '%H', + '%h' => '%h', + '%I' => '%h', + '%i' => '%M', + '%j' => '%z', + '%k' => '%G', + '%l' => '%g', + '%M' => '%F', + '%m' => '%m', + '%p' => '%A', + '%r' => '%h:%i:%s %A', + '%S' => '%s', + '%s' => '%s', + '%T' => '%H:%i:%s', + '%U' => '%W', + '%u' => '%W', + '%V' => '%W', + '%v' => '%W', + '%W' => '%l', + '%w' => '%w', + '%X' => '%Y', + '%x' => '%o', + '%Y' => '%Y', + '%y' => '%y', + ); + // @TODO: Implement as user defined function to avoid + // rewriting something that may be an expression as a string + $format = $args[1]->elements[0]->value; + $new_format = strtr( $format, $mysql_date_format_to_sqlite_strftime ); + + return WP_SQLite_Token_Factory::create_function( + 'STRFTIME', + array( + new WP_SQLite_Expression( array( WP_SQLite_Token_Factory::raw( $new_format ) ) ), + new WP_SQLite_Expression( array( $args[0] ) ), + ) + ); + case 'DATEDIFF': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::create_function( 'JULIANDAY', array( $args[0] ) ), + WP_SQLite_Token_Factory::raw( ' - ' ), + WP_SQLite_Token_Factory::create_function( 'JULIANDAY', array( $args[1] ) ), + ) + ); + case 'DAYNAME': + return WP_SQLite_Token_Factory::create_function( + 'STRFTIME', + array_merge( array( '%w' ), $args ) + ); + case 'DAY': + case 'DAYOFMONTH': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%d' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), + ) + ); + case 'DAYOFWEEK': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%w' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") + 1 AS INTEGER'" ), + ) + ); + case 'DAYOFYEAR': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%j' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), + ) + ); + case 'HOUR': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%H' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), + ) + ); + case 'MINUTE': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%M' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), + ) + ); + case 'MONTH': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%m' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), + ) + ); + case 'MONTHNAME': + return WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%m' ), $args ) ); + case 'NOW': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( 'CURRENT_TIMESTAMP()' ), + ) + ); + case 'SECOND': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%S' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), + ) + ); + case 'TIMESTAMP': + return new WP_SQLite_Expression( + array_merge( + array( WP_SQLite_Token_Factory::raw( 'DATETIME(' ) ), + $args, + array( WP_SQLite_Token_Factory::raw( ')' ) ) + ) + ); + case 'YEAR': + return new WP_SQLite_Expression( + array( + WP_SQLite_Token_Factory::raw( "CAST('" ), + WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%Y' ), $args ) ), + WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), + ) + ); + case 'FOUND_ROWS': + $this->has_found_rows_call = true; + return new WP_SQLite_Expression( + array( + // Post-processed in handleSqlCalcFoundRows() + WP_SQLite_Token_Factory::raw( 'FOUND_ROWS' ), + ) + ); + default: + throw new Exception( 'Unsupported function: ' . $name ); + } + } +} diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index cd7e36fb..c6210784 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -5,662 +5,778 @@ use Exception; use PDO; +use PDOException; +use PDOStatement; +use SQLite3; use WP_MySQL_Lexer; use WP_MySQL_Parser; -use WP_MySQL_Token; use WP_Parser_Grammar; -use WP_Parser_Node; - -$grammar = new WP_Parser_Grammar( require __DIR__ . '/../../wp-includes/mysql/mysql-grammar.php' ); +use WP_SQLite_PDO_User_Defined_Functions; class WP_SQLite_Driver { + const GRAMMAR_PATH = __DIR__ . '/../../wp-includes/mysql/mysql-grammar.php'; + + const SQLITE_BUSY = 5; + const SQLITE_LOCKED = 6; + + const DATA_TYPES_CACHE_TABLE = '_mysql_data_types_cache'; + + const CREATE_DATA_TYPES_CACHE_TABLE = 'CREATE TABLE IF NOT EXISTS _mysql_data_types_cache ( + `table` TEXT NOT NULL, + `column_or_index` TEXT NOT NULL, + `mysql_type` TEXT NOT NULL, + PRIMARY KEY(`table`, `column_or_index`) + );'; + /** * @var WP_Parser_Grammar */ - private $grammar; + private static $grammar; /** - * @var PDO + * Class variable to reference to the PDO instance. + * + * @access private + * + * @var PDO object */ private $pdo; - private $results; + /** + * The database version. + * + * This is used here to avoid PHP warnings in the health screen. + * + * @var string + */ + public $client_info = ''; - private $has_sql_calc_found_rows = false; - private $has_found_rows_call = false; - private $last_calc_rows_result = null; + /** + * Last executed MySQL query. + * + * @var string + */ + public $mysql_query; - public function __construct( PDO $pdo ) { - global $grammar; - $this->pdo = $pdo; - $this->grammar = $grammar; + /** + * A list of executed SQLite queries. + * + * @var array + */ + public $executed_sqlite_queries = array(); - $pdo->setAttribute( PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION ); - $pdo->setAttribute( PDO::ATTR_STRINGIFY_FETCHES, true ); - $pdo->setAttribute( PDO::ATTR_TIMEOUT, 5 ); - } + /** + * The affected table name. + * + * @var array + */ + private $table_name = array(); - public function query( $query ) { - $this->has_sql_calc_found_rows = false; - $this->has_found_rows_call = false; - $this->last_calc_rows_result = null; + /** + * The type of the executed query (SELECT, INSERT, etc). + * + * @var array + */ + private $query_type = array(); - $lexer = new WP_MySQL_Lexer( $query ); - $tokens = $lexer->remaining_tokens(); + /** + * The columns to insert. + * + * @var array + */ + private $insert_columns = array(); - $parser = new WP_MySQL_Parser( $this->grammar, $tokens ); - $ast = $parser->parse(); - $expr = $this->translate_query( $ast ); - //$expr = $this->rewrite_sql_calc_found_rows( $expr ); + /** + * Class variable to store the result of the query. + * + * @access private + * + * @var array reference to the PHP object + */ + private $results = null; - if ( null === $expr ) { - return false; + /** + * Class variable to check if there is an error. + * + * @var boolean + */ + public $is_error = false; + + /** + * Class variable to store the file name and function to cause error. + * + * @access private + * + * @var array + */ + private $errors; + + /** + * Class variable to store the error messages. + * + * @access private + * + * @var array + */ + private $error_messages = array(); + + /** + * Class variable to store the affected row id. + * + * @var int integer + * @access private + */ + private $last_insert_id; + + /** + * Class variable to store the number of rows affected. + * + * @var int integer + */ + private $affected_rows; + + /** + * Variable to emulate MySQL affected row. + * + * @var integer + */ + private $num_rows; + + /** + * Return value from query(). + * + * Each query has its own return value. + * + * @var mixed + */ + private $return_value; + + /** + * Variable to keep track of nested transactions level. + * + * @var int + */ + private $transaction_level = 0; + + /** + * Value returned by the last exec(). + * + * @var mixed + */ + private $last_exec_returned; + + /** + * The PDO fetch mode passed to query(). + * + * @var mixed + */ + private $pdo_fetch_mode; + + /** + * Associative array with list of system (non-WordPress) tables. + * + * @var array [tablename => tablename] + */ + private $sqlite_system_tables = array(); + + /** + * The last error message from SQLite. + * + * @var string + */ + private $last_sqlite_error; + + /** + * Constructor. + * + * Create PDO object, set user defined functions and initialize other settings. + * Don't use parent::__construct() because this class does not only returns + * PDO instance but many others jobs. + * + * @param PDO $pdo The PDO object. + */ + public function __construct( $pdo = null ) { + if ( ! $pdo ) { + if ( ! is_file( FQDB ) ) { + $this->prepare_directory(); + } + + $locked = false; + $status = 0; + $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, $options ); // phpcs:ignore WordPress.DB.RestrictedClasses + } catch ( PDOException $ex ) { + $status = $ex->getCode(); + if ( self::SQLITE_BUSY === $status || self::SQLITE_LOCKED === $status ) { + $locked = true; + } else { + $err_message = $ex->getMessage(); + } + } + } while ( $locked ); + + if ( $status > 0 ) { + $message = sprintf( + '

%s

%s

%s

', + 'Database initialization error!', + "Code: $status", + "Error Message: $err_message" + ); + $this->is_error = true; + $this->error_messages[] = $message; + return; + } } - $sqlite_query = WP_SQLite_Query_Builder::stringify( $expr ); + new WP_SQLite_PDO_User_Defined_Functions( $pdo ); - // Returning the query just for now for testing. In the end, we'll - // run it and return the SQLite interaction result. - //return $sqlite_query; + // MySQL data comes across stringified by default. + $pdo->setAttribute( PDO::ATTR_STRINGIFY_FETCHES, true ); // phpcs:ignore WordPress.DB.RestrictedClasses.mysql__PDO + $pdo->query( self::CREATE_DATA_TYPES_CACHE_TABLE ); - if ( ! $sqlite_query ) { - return false; + /* + * 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; + + // Load MySQL grammar. + if ( null === self::$grammar ) { + self::$grammar = new WP_Parser_Grammar( require self::GRAMMAR_PATH ); } - $is_select = (bool) $ast->get_descendant( 'selectStatement' ); - $statement = $this->pdo->prepare( $sqlite_query ); - $return_value = $statement->execute(); - $this->results = $return_value; - if ( $is_select ) { - $this->results = $statement->fetchAll( PDO::FETCH_OBJ ); + // Fixes a warning in the site-health screen. + $this->client_info = SQLite3::version()['versionString']; + + register_shutdown_function( array( $this, '__destruct' ) ); + + // WordPress happens to use no foreign keys. + $statement = $this->pdo->query( 'PRAGMA foreign_keys' ); + // phpcs:ignore Universal.Operators.StrictComparisons.LooseEqual + if ( $statement->fetchColumn( 0 ) == '0' ) { + $this->pdo->query( 'PRAGMA foreign_keys = ON' ); + } + $this->pdo->query( 'PRAGMA encoding="UTF-8";' ); + + $valid_journal_modes = array( 'DELETE', 'TRUNCATE', 'PERSIST', 'MEMORY', 'WAL', 'OFF' ); + if ( defined( 'SQLITE_JOURNAL_MODE' ) && in_array( SQLITE_JOURNAL_MODE, $valid_journal_modes, true ) ) { + $this->pdo->query( 'PRAGMA journal_mode = ' . SQLITE_JOURNAL_MODE ); } - return $return_value; } - public function get_error_message() { + /** + * Destructor + * + * If SQLITE_MEM_DEBUG constant is defined, append information about + * memory usage into database/mem_debug.txt. + * + * This definition is changed since version 1.7. + */ + public function __destruct() { + if ( defined( 'SQLITE_MEM_DEBUG' ) && SQLITE_MEM_DEBUG ) { + $max = ini_get( 'memory_limit' ); + if ( is_null( $max ) ) { + $message = sprintf( + '[%s] Memory_limit is not set in php.ini file.', + gmdate( 'Y-m-d H:i:s', $_SERVER['REQUEST_TIME'] ) + ); + error_log( $message ); + return; + } + if ( stripos( $max, 'M' ) !== false ) { + $max = (int) $max * MB_IN_BYTES; + } + $peak = memory_get_peak_usage( true ); + $used = round( (int) $peak / (int) $max * 100, 2 ); + if ( $used > 90 ) { + $message = sprintf( + "[%s] Memory peak usage warning: %s %% used. (max: %sM, now: %sM)\n", + gmdate( 'Y-m-d H:i:s', $_SERVER['REQUEST_TIME'] ), + $used, + $max, + $peak + ); + error_log( $message ); + } + } } - public function get_query_results() { - return $this->results; + /** + * Get the PDO object. + * + * @return PDO + */ + public function get_pdo() { + return $this->pdo; + } + + /** + * Method to return inserted row id. + */ + public function get_insert_id() { + return $this->last_insert_id; + } + + /** + * Method to return the number of rows affected. + */ + public function get_affected_rows() { + return $this->affected_rows; } - private function rewrite_sql_calc_found_rows( WP_SQLite_Expression $expr ) { - if ( $this->has_found_rows_call && ! $this->has_sql_calc_found_rows && null === $this->last_calc_rows_result ) { - throw new Exception( 'FOUND_ROWS() called without SQL_CALC_FOUND_ROWS' ); + /** + * Method to execute query(). + * + * Divide the query types into seven different ones. That is to say: + * + * 1. SELECT SQL_CALC_FOUND_ROWS + * 2. INSERT + * 3. CREATE TABLE(INDEX) + * 4. ALTER TABLE + * 5. SHOW VARIABLES + * 6. DROP INDEX + * 7. THE OTHERS + * + * #1 is just a tricky play. See the private function handle_sql_count() in query.class.php. + * From #2 through #5 call different functions respectively. + * #6 call the ALTER TABLE query. + * #7 is a normal process: sequentially call prepare_query() and execute_query(). + * + * #1 process has been changed since version 1.5.1. + * + * @param string $statement Full SQL statement string. + * @param int $mode Not used. + * @param array ...$fetch_mode_args Not used. + * + * @see PDO::query() + * + * @throws Exception If the query could not run. + * @throws PDOException If the translated query could not run. + * + * @return mixed according to the query type + */ + 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 ( + preg_match( '/^\s*START TRANSACTION/i', $statement ) + || preg_match( '/^\s*BEGIN/i', $statement ) + ) { + return $this->begin_transaction(); + } + if ( preg_match( '/^\s*COMMIT/i', $statement ) ) { + return $this->commit(); + } + if ( preg_match( '/^\s*ROLLBACK/i', $statement ) ) { + return $this->rollback(); } - if ( $this->has_sql_calc_found_rows ) { - $expr_to_run = $expr; - if ( $this->has_found_rows_call ) { - $expr_without_found_rows = new WP_SQLite_Expression( array() ); - foreach ( $expr->elements as $k => $element ) { - if ( WP_SQLite_Token::TYPE_IDENTIFIER === $element->type && 'FOUND_ROWS' === $element->value ) { - $expr_without_found_rows->add_token( - WP_SQLite_Token_Factory::value( 0 ) - ); - } else { - $expr_without_found_rows->add_token( $element ); + try { + // Parse the MySQL query. + $lexer = new WP_MySQL_Lexer( $statement ); + $tokens = $lexer->remaining_tokens(); + + $parser = new WP_MySQL_Parser( self::$grammar, $tokens ); + $ast = $parser->parse(); + + if ( null === $ast ) { + throw new Exception( 'Failed to parse the MySQL query.' ); + } + + // Perform all the queries in a nested transaction. + $this->begin_transaction(); + + do { + $error = null; + try { + $this->execute_mysql_query( $ast ); + } catch ( PDOException $error ) { + if ( $error->getCode() !== self::SQLITE_BUSY ) { + throw $error; } } - $expr_to_run = $expr_without_found_rows; + } while ( $error ); + + if ( function_exists( 'do_action' ) ) { + /** + * Notifies that a query has been translated and executed. + * + * @param string $query The executed SQL query. + * @param string $query_type The type of the SQL query (e.g. SELECT, INSERT, UPDATE, DELETE). + * @param string $table_name The name of the table affected by the SQL query. + * @param array $insert_columns The columns affected by the INSERT query (if applicable). + * @param int $last_insert_id The ID of the last inserted row (if applicable). + * @param int $affected_rows The number of affected rows (if applicable). + * + * @since 0.1.0 + */ + do_action( + 'sqlite_translated_query_executed', + $this->mysql_query, + $this->query_type, + $this->table_name, + $this->insert_columns, + $this->last_insert_id, + $this->affected_rows + ); } - // ...remove the LIMIT clause... - $query = 'SELECT COUNT(*) as cnt FROM (' . WP_SQLite_Query_Builder::stringify( $expr_to_run ) . ');'; + // Commit the nested transaction. + $this->commit(); - // ...run $query... - // $result = ... - // $this->last_calc_rows_result = $result['cnt']; + return $this->return_value; + } catch ( Exception $err ) { + // Rollback the nested transaction. + $this->rollback(); + if ( defined( 'PDO_DEBUG' ) && PDO_DEBUG === true ) { + throw $err; + } + return $this->handle_error( $err ); } + } - if ( ! $this->has_found_rows_call ) { - return $expr; - } + /** + * Method to return the queried result data. + * + * @return mixed + */ + public function get_query_results() { + return $this->results; + } - $expr_with_found_rows_result = new WP_SQLite_Expression( array() ); - foreach ( $expr->elements as $k => $element ) { - if ( WP_SQLite_Token::TYPE_IDENTIFIER === $element->type && 'FOUND_ROWS' === $element->value ) { - $expr_with_found_rows_result->add_token( - WP_SQLite_Token_Factory::value( $this->last_calc_rows_result ) - ); - } else { - $expr_with_found_rows_result->add_token( $element ); - } + /** + * Method to return the number of rows from the queried result. + */ + public function get_num_rows() { + return $this->num_rows; + } + + /** + * Method to return the queried results according to the query types. + * + * @return mixed + */ + public function get_return_value() { + return $this->return_value; + } + + /** + * Executes a MySQL query in SQLite. + * + * @param string $query The query. + * + * @throws Exception If the query is not supported. + */ + private function execute_mysql_query( $query ) { + //@TODO: Implement the query translation. + } + + /** + * Executes a query in SQLite. + * + * @param mixed $sql The query to execute. + * @param mixed $params The parameters to bind to the query. + * @throws PDOException If the query could not be executed. + * @return object { + * The result of the query. + * + * @type PDOStatement $stmt The executed statement + * @type * $result The value returned by $stmt. + * } + */ + public function execute_sqlite_query( $sql, $params = array() ) { + $this->executed_sqlite_queries[] = array( + 'sql' => $sql, + 'params' => $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] ); } - return $expr_with_found_rows_result; + $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; } - private function translate_query( $ast ) { - if ( null === $ast ) { - return null; + /** + * Method to return error messages. + * + * @throws Exception If error is found. + * + * @return string + */ + public function get_error_message() { + if ( count( $this->error_messages ) === 0 ) { + $this->is_error = false; + $this->error_messages = array(); + return ''; } - if ( $ast instanceof WP_MySQL_Token ) { - $token = $ast; - switch ( $token->type ) { - case WP_MySQL_Lexer::EOF: - return new WP_SQLite_Expression( array() ); - - case WP_MySQL_Lexer::IDENTIFIER: - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::identifier( - trim( $token->text, '`"' ) - ), - ) - ); + if ( false === $this->is_error ) { + return ''; + } - default: - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( $token->text ), - ) - ); - } + $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; + $output .= '
    ' . PHP_EOL; + foreach ( $this->executed_sqlite_queries as $q ) { + $message = "Executing: {$q['sql']} | " . ( $q['params'] ? 'parameters: ' . implode( ', ', $q['params'] ) : '(no parameters)' ); + + $output .= '
  1. ' . htmlspecialchars( $message ) . '
  2. ' . PHP_EOL; + } + $output .= '
' . PHP_EOL; + $output .= '
' . PHP_EOL; + foreach ( $this->error_messages as $num => $m ) { + $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'], + '' . htmlspecialchars( $this->errors[ $num ]['function'] ) . '', + $m + ) . PHP_EOL; + $output .= '
' . PHP_EOL; } - if ( ! ( $ast instanceof WP_Parser_Node ) ) { - throw new Exception( 'translate_query only accepts WP_MySQL_Token and WP_Parser_Node instances' ); + try { + throw new Exception(); + } catch ( Exception $e ) { + $output .= '

Backtrace:

' . PHP_EOL; + $output .= '
' . $e->getTraceAsString() . '
' . PHP_EOL; } - $rule_name = $ast->rule_name; - - switch ( $rule_name ) { - case 'indexHintList': - // SQLite doesn't support index hints. Let's skip them. - return null; - - case 'querySpecOption': - $token = $ast->get_token(); - switch ( $token->type ) { - case WP_MySQL_Lexer::ALL_SYMBOL: - case WP_MySQL_Lexer::DISTINCT_SYMBOL: - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( $token->text ), - ) - ); - case WP_MySQL_Lexer::SQL_CALC_FOUND_ROWS_SYMBOL: - $this->has_sql_calc_found_rows = true; - // Fall through to default. - default: - // we'll need to run the current SQL query without any - // LIMIT clause, and then substitute the FOUND_ROWS() - // function with a literal number of rows found. - return new WP_SQLite_Expression( array() ); - } - // Otherwise, fall through. - - case 'fromClause': - // Skip `FROM DUAL`. We only care about a singular - // FROM DUAL statement, as FROM mytable, DUAL is a syntax - // error. - if ( - $ast->has_token( WP_MySQL_Lexer::DUAL_SYMBOL ) && - ! $ast->has_child( 'tableReferenceList' ) - ) { - return null; - } - // Otherwise, fall through. - - case 'selectOption': - case 'interval': - case 'intervalTimeStamp': - case 'bitExpr': - case 'boolPri': - case 'lockStrengh': - case 'orderList': - case 'simpleExpr': - case 'columnRef': - case 'exprIs': - case 'exprAnd': - case 'primaryExprCompare': - case 'fieldIdentifier': - case 'dotIdentifier': - case 'identifier': - case 'literal': - case 'joinedTable': - case 'nullLiteral': - case 'boolLiteral': - case 'numLiteral': - case 'textLiteral': - case 'predicate': - case 'predicateExprBetween': - case 'primaryExprPredicate': - case 'pureIdentifier': - case 'unambiguousIdentifier': - case 'qualifiedIdentifier': - case 'query': - case 'queryExpression': - case 'queryExpressionBody': - case 'queryExpressionParens': - case 'queryPrimary': - case 'querySpecification': - case 'queryTerm': - case 'selectAlias': - case 'selectItem': - case 'selectItemList': - case 'selectStatement': - case 'simpleExprColumnRef': - case 'simpleExprFunction': - case 'outerJoinType': - case 'simpleExprSubQuery': - case 'simpleExprLiteral': - case 'compOp': - case 'simpleExprList': - case 'simpleStatement': - case 'subquery': - case 'exprList': - case 'expr': - case 'tableReferenceList': - case 'tableReference': - case 'tableRef': - case 'tableAlias': - case 'tableFactor': - case 'singleTable': - case 'udfExprList': - case 'udfExpr': - case 'withClause': - case 'whereClause': - case 'commonTableExpression': - case 'derivedTable': - case 'columnRefOrLiteral': - case 'orderClause': - case 'groupByClause': - case 'lockingClauseList': - case 'lockingClause': - case 'havingClause': - case 'direction': - case 'orderExpression': - $child_expressions = array(); - foreach ( $ast->children as $child ) { - $child_expressions[] = $this->translate_query( $child ); - } - return new WP_SQLite_Expression( $child_expressions ); - - case 'textStringLiteral': - return new WP_SQLite_Expression( - array( - $ast->has_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT ) ? - WP_SQLite_Token_Factory::double_quoted_value( $ast->get_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT )->text ) : false, - $ast->has_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT ) ? - WP_SQLite_Token_Factory::raw( $ast->get_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT )->text ) : false, - ) - ); + return $output; + } - case 'functionCall': - return $this->translate_function_call( $ast ); - - case 'runtimeFunctionCall': - return $this->translate_runtime_function_call( $ast ); - - default: - return null; - // var_dump(count($ast->children)); - // foreach($ast->children as $child) { - // var_dump(get_class($child)); - // echo $child->getText(); - // echo "\n\n"; - // } - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( - $rule_name - ), - ) - ); + /** + * Begin a new transaction or nested transaction. + * + * @return boolean + */ + public function begin_transaction() { + $success = false; + try { + if ( 0 === $this->transaction_level ) { + $this->execute_sqlite_query( 'BEGIN' ); + } else { + $this->execute_sqlite_query( 'SAVEPOINT LEVEL' . $this->transaction_level ); + } + $success = $this->last_exec_returned; + } finally { + if ( $success ) { + ++$this->transaction_level; + if ( function_exists( 'do_action' ) ) { + /** + * Notifies that a transaction-related query has been translated and executed. + * + * @param string $command The SQL statement (one of "START TRANSACTION", "COMMIT", "ROLLBACK"). + * @param bool $success Whether the SQL statement was successful or not. + * @param int $nesting_level The nesting level of the transaction. + * + * @since 0.1.0 + */ + do_action( 'sqlite_transaction_query_executed', 'START TRANSACTION', (bool) $this->last_exec_returned, $this->transaction_level - 1 ); + } + } } + return $success; } - private function translate_runtime_function_call( $ast ): WP_SQLite_Expression { - $name_token = $ast->children[0]; - - switch ( strtoupper( $name_token->text ) ) { - case 'ADDDATE': - case 'DATE_ADD': - $args = $ast->get_children( 'expr' ); - $interval = $ast->get_child( 'interval' ); - $timespan = $interval->get_child( 'intervalTimeStamp' )->get_token()->text; - return WP_SQLite_Token_Factory::create_function( - 'DATETIME', - array( - $this->translate_query( $args[0] ), - new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::value( '+' ), - WP_SQLite_Token_Factory::raw( '||' ), - $this->translate_query( $args[1] ), - WP_SQLite_Token_Factory::raw( '||' ), - WP_SQLite_Token_Factory::value( $timespan ), - ) - ), - ) - ); + /** + * Commit the current transaction or nested transaction. + * + * @return boolean True on success, false on failure. + */ + public function commit() { + if ( 0 === $this->transaction_level ) { + return false; + } - case 'DATE_SUB': - // return new WP_SQLite_Expression([ - // SQLiteTokenFactory::raw("DATETIME("), - // $args[0], - // SQLiteTokenFactory::raw(", '-'"), - // $args[1], - // SQLiteTokenFactory::raw(" days')") - // ]); - - case 'VALUES': - $column = $ast->get_child()->get_descendant( 'pureIdentifier' ); - if ( ! $column ) { - throw new Exception( 'VALUES() calls without explicit column names are unsupported' ); - } + --$this->transaction_level; + if ( 0 === $this->transaction_level ) { + $this->execute_sqlite_query( 'COMMIT' ); + } else { + $this->execute_sqlite_query( 'RELEASE SAVEPOINT LEVEL' . $this->transaction_level ); + } - $colname = $column->get_token()->extract_value(); - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( 'excluded.' ), - WP_SQLite_Token_Factory::identifier( $colname ), - ) - ); - default: - throw new Exception( 'Unsupported function: ' . $name_token->text ); + if ( function_exists( 'do_action' ) ) { + do_action( 'sqlite_transaction_query_executed', 'COMMIT', (bool) $this->last_exec_returned, $this->transaction_level ); } + return $this->last_exec_returned; } - private function translate_function_call( $function_call_tree ): WP_SQLite_Expression { - $name = $function_call_tree->get_child( 'pureIdentifier' )->get_token()->text; - $args = array(); - foreach ( $function_call_tree->get_child( 'udfExprList' )->get_children() as $node ) { - $args[] = $this->translate_query( $node ); + /** + * Rollback the current transaction or nested transaction. + * + * @return boolean True on success, false on failure. + */ + public function rollback() { + if ( 0 === $this->transaction_level ) { + return false; } - switch ( strtoupper( $name ) ) { - case 'ABS': - case 'ACOS': - case 'ASIN': - case 'ATAN': - case 'ATAN2': - case 'COS': - case 'DEGREES': - case 'TRIM': - case 'EXP': - case 'MAX': - case 'MIN': - case 'FLOOR': - case 'RADIANS': - case 'ROUND': - case 'SIN': - case 'SQRT': - case 'TAN': - case 'TRUNCATE': - case 'RANDOM': - case 'PI': - case 'LTRIM': - case 'RTRIM': - return WP_SQLite_Token_Factory::create_function( $name, $args ); - - case 'CEIL': - case 'CEILING': - return WP_SQLite_Token_Factory::create_function( 'CEIL', $args ); - - case 'COT': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( '1 / ' ), - WP_SQLite_Token_Factory::create_function( 'TAN', $args ), - ) - ); - case 'LN': - case 'LOG': - case 'LOG2': - return WP_SQLite_Token_Factory::create_function( 'LOG', $args ); - - case 'LOG10': - return WP_SQLite_Token_Factory::create_function( 'LOG10', $args ); - - // case 'MOD': - // return $this->transformBinaryOperation([ - // 'operator' => '%', - // 'left' => $args[0], - // 'right' => $args[1] - // ]); - - case 'POW': - case 'POWER': - return WP_SQLite_Token_Factory::create_function( 'POW', $args ); - - // String functions - case 'ASCII': - return WP_SQLite_Token_Factory::create_function( 'UNICODE', $args ); - case 'CHAR_LENGTH': - case 'LENGTH': - return WP_SQLite_Token_Factory::create_function( 'LENGTH', $args ); - case 'CONCAT': - $concated = array( WP_SQLite_Token_Factory::raw( '(' ) ); - foreach ( $args as $k => $arg ) { - $concated[] = $arg; - if ( $k < count( $args ) - 1 ) { - $concated[] = WP_SQLite_Token_Factory::raw( '||' ); - } - } - $concated[] = WP_SQLite_Token_Factory::raw( ')' ); - return new WP_SQLite_Expression( $concated ); - // case 'CONCAT_WS': - // return new WP_SQLite_Expression([ - // SQLiteTokenFactory::raw("REPLACE("), - // implode(" || ", array_slice($args, 1)), - // SQLiteTokenFactory::raw(", '', "), - // $args[0], - // SQLiteTokenFactory::raw(")") - // ]); - case 'INSTR': - return WP_SQLite_Token_Factory::create_function( 'INSTR', $args ); - case 'LCASE': - case 'LOWER': - return WP_SQLite_Token_Factory::create_function( 'LOWER', $args ); - case 'LEFT': - return WP_SQLite_Token_Factory::create_function( - 'SUBSTR', - array( - $args[0], - '1', - $args[1], - ) - ); - case 'LOCATE': - return WP_SQLite_Token_Factory::create_function( - 'INSTR', - array( - $args[1], - $args[0], - ) - ); - case 'REPEAT': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( "REPLACE(CHAR(32), ' ', " ), - $args[0], - WP_SQLite_Token_Factory::raw( ')' ), - ) - ); + --$this->transaction_level; + if ( 0 === $this->transaction_level ) { + $this->execute_sqlite_query( 'ROLLBACK' ); + } else { + $this->execute_sqlite_query( 'ROLLBACK TO SAVEPOINT LEVEL' . $this->transaction_level ); + } + if ( function_exists( 'do_action' ) ) { + do_action( 'sqlite_transaction_query_executed', 'ROLLBACK', (bool) $this->last_exec_returned, $this->transaction_level ); + } + return $this->last_exec_returned; + } - case 'REPLACE': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( 'REPLACE(' ), - implode( ', ', $args ), - WP_SQLite_Token_Factory::raw( ')' ), - ) - ); - case 'RIGHT': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( 'SUBSTR(' ), - $args[0], - WP_SQLite_Token_Factory::raw( ', -(' ), - $args[1], - WP_SQLite_Token_Factory::raw( '))' ), - ) - ); - case 'SPACE': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( "REPLACE(CHAR(32), ' ', '')" ), - ) - ); - case 'SUBSTRING': - case 'SUBSTR': - return WP_SQLite_Token_Factory::create_function( 'SUBSTR', $args ); - case 'UCASE': - case 'UPPER': - return WP_SQLite_Token_Factory::create_function( 'UPPER', $args ); - - case 'DATE_FORMAT': - $mysql_date_format_to_sqlite_strftime = array( - '%a' => '%D', - '%b' => '%M', - '%c' => '%n', - '%D' => '%jS', - '%d' => '%d', - '%e' => '%j', - '%H' => '%H', - '%h' => '%h', - '%I' => '%h', - '%i' => '%M', - '%j' => '%z', - '%k' => '%G', - '%l' => '%g', - '%M' => '%F', - '%m' => '%m', - '%p' => '%A', - '%r' => '%h:%i:%s %A', - '%S' => '%s', - '%s' => '%s', - '%T' => '%H:%i:%s', - '%U' => '%W', - '%u' => '%W', - '%V' => '%W', - '%v' => '%W', - '%W' => '%l', - '%w' => '%w', - '%X' => '%Y', - '%x' => '%o', - '%Y' => '%Y', - '%y' => '%y', - ); - // @TODO: Implement as user defined function to avoid - // rewriting something that may be an expression as a string - $format = $args[1]->elements[0]->value; - $new_format = strtr( $format, $mysql_date_format_to_sqlite_strftime ); - - return WP_SQLite_Token_Factory::create_function( - 'STRFTIME', - array( - new WP_SQLite_Expression( array( WP_SQLite_Token_Factory::raw( $new_format ) ) ), - new WP_SQLite_Expression( array( $args[0] ) ), - ) - ); - case 'DATEDIFF': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::create_function( 'JULIANDAY', array( $args[0] ) ), - WP_SQLite_Token_Factory::raw( ' - ' ), - WP_SQLite_Token_Factory::create_function( 'JULIANDAY', array( $args[1] ) ), - ) - ); - case 'DAYNAME': - return WP_SQLite_Token_Factory::create_function( - 'STRFTIME', - array_merge( array( '%w' ), $args ) - ); - case 'DAY': - case 'DAYOFMONTH': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( "CAST('" ), - WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%d' ), $args ) ), - WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), - ) - ); - case 'DAYOFWEEK': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( "CAST('" ), - WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%w' ), $args ) ), - WP_SQLite_Token_Factory::raw( ") + 1 AS INTEGER'" ), - ) - ); - case 'DAYOFYEAR': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( "CAST('" ), - WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%j' ), $args ) ), - WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), - ) - ); - case 'HOUR': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( "CAST('" ), - WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%H' ), $args ) ), - WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), - ) - ); - case 'MINUTE': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( "CAST('" ), - WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%M' ), $args ) ), - WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), - ) - ); - case 'MONTH': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( "CAST('" ), - WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%m' ), $args ) ), - WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), - ) - ); - case 'MONTHNAME': - return WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%m' ), $args ) ); - case 'NOW': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( 'CURRENT_TIMESTAMP()' ), - ) - ); - case 'SECOND': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( "CAST('" ), - WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%S' ), $args ) ), - WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), - ) - ); - case 'TIMESTAMP': - return new WP_SQLite_Expression( - array_merge( - array( WP_SQLite_Token_Factory::raw( 'DATETIME(' ) ), - $args, - array( WP_SQLite_Token_Factory::raw( ')' ) ) - ) - ); - case 'YEAR': - return new WP_SQLite_Expression( - array( - WP_SQLite_Token_Factory::raw( "CAST('" ), - WP_SQLite_Token_Factory::create_function( 'STRFTIME', array_merge( array( '%Y' ), $args ) ), - WP_SQLite_Token_Factory::raw( ") AS INTEGER'" ), - ) - ); - case 'FOUND_ROWS': - $this->has_found_rows_call = true; - return new WP_SQLite_Expression( - array( - // Post-processed in handleSqlCalcFoundRows() - WP_SQLite_Token_Factory::raw( 'FOUND_ROWS' ), - ) - ); - default: - throw new Exception( 'Unsupported function: ' . $name ); + /** + * This method makes database directory and .htaccess file. + * + * It is executed only once when the installation begins. + */ + private function prepare_directory() { + global $wpdb; + $u = umask( 0000 ); + if ( ! is_dir( FQDBDIR ) ) { + if ( ! @mkdir( FQDBDIR, 0704, true ) ) { + umask( $u ); + wp_die( 'Unable to create the required directory! Please check your server settings.', 'Error!' ); + } + } + if ( ! is_writable( FQDBDIR ) ) { + umask( $u ); + $message = 'Unable to create a file in the directory! Please check your server settings.'; + wp_die( $message, 'Error!' ); + } + if ( ! is_file( FQDBDIR . '.htaccess' ) ) { + $fh = fopen( FQDBDIR . '.htaccess', 'w' ); + if ( ! $fh ) { + umask( $u ); + echo 'Unable to create a file in the directory! Please check your server settings.'; + + return false; + } + fwrite( $fh, 'DENY FROM ALL' ); + fclose( $fh ); + } + if ( ! is_file( FQDBDIR . 'index.php' ) ) { + $fh = fopen( FQDBDIR . 'index.php', 'w' ); + if ( ! $fh ) { + umask( $u ); + echo 'Unable to create a file in the directory! Please check your server settings.'; + + return false; + } + fwrite( $fh, '' ); + fclose( $fh ); } + umask( $u ); + + return true; + } + + /** + * Method to clear previous data. + */ + private function flush() { + $this->mysql_query = ''; + $this->results = null; + $this->last_exec_returned = null; + $this->table_name = null; + $this->last_insert_id = null; + $this->affected_rows = null; + $this->insert_columns = array(); + $this->num_rows = null; + $this->return_value = null; + $this->error_messages = array(); + $this->is_error = false; + $this->executed_sqlite_queries = array(); + } + + /** + * Error handler. + * + * @param Exception $err Exception object. + * + * @return bool Always false. + */ + private function handle_error( Exception $err ) { + $message = $err->getMessage(); + $this->set_error( __LINE__, __FUNCTION__, $message ); + $this->return_value = false; + return false; + } + + /** + * Method to format the error messages and put out to the file. + * + * When $wpdb::suppress_errors is set to true or $wpdb::show_errors is set to false, + * the error messages are ignored. + * + * @param string $line Where the error occurred. + * @param string $function_name Indicate the function name where the error occurred. + * @param string $message The message. + * + * @return boolean|void + */ + private function set_error( $line, $function_name, $message ) { + $this->errors[] = array( + 'line' => $line, + 'function' => $function_name, + ); + $this->error_messages[] = $message; + $this->is_error = true; } } From 62943d6c49956b5dd8c675fced3f80abb827db6e Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Tue, 19 Nov 2024 10:10:20 +0100 Subject: [PATCH 05/36] Add a base generic WP_Parser_Token class, add docs --- tests/bootstrap.php | 5 +- tests/mysql/WP_MySQL_Lexer_Tests.php | 22 +++---- tests/tools/dump-ast.php | 5 +- tests/tools/dump-sqlite-query.php | 1 + tests/tools/run-lexer-benchmark.php | 1 + tests/tools/run-parser-benchmark.php | 5 +- wp-includes/mysql/class-wp-mysql-token.php | 58 +++++++++---------- wp-includes/parser/class-wp-parser-node.php | 8 +-- wp-includes/parser/class-wp-parser-token.php | 36 ++++++++++++ wp-includes/parser/class-wp-parser.php | 6 +- .../class-wp-sqlite-driver-prototype.php | 2 +- 11 files changed, 95 insertions(+), 54 deletions(-) create mode 100644 wp-includes/parser/class-wp-parser-token.php diff --git a/tests/bootstrap.php b/tests/bootstrap.php index b6635052..4ba0fc79 100644 --- a/tests/bootstrap.php +++ b/tests/bootstrap.php @@ -1,11 +1,12 @@ assertTrue( $lexer->next_token() ); - $this->assertSame( WP_MySQL_Lexer::SELECT_SYMBOL, $lexer->get_token()->get_type() ); + $this->assertSame( WP_MySQL_Lexer::SELECT_SYMBOL, $lexer->get_token()->id ); // id $this->assertTrue( $lexer->next_token() ); - $this->assertSame( WP_MySQL_Lexer::IDENTIFIER, $lexer->get_token()->get_type() ); + $this->assertSame( WP_MySQL_Lexer::IDENTIFIER, $lexer->get_token()->id ); // FROM $this->assertTrue( $lexer->next_token() ); - $this->assertSame( WP_MySQL_Lexer::FROM_SYMBOL, $lexer->get_token()->get_type() ); + $this->assertSame( WP_MySQL_Lexer::FROM_SYMBOL, $lexer->get_token()->id ); // users $this->assertTrue( $lexer->next_token() ); - $this->assertSame( WP_MySQL_Lexer::IDENTIFIER, $lexer->get_token()->get_type() ); + $this->assertSame( WP_MySQL_Lexer::IDENTIFIER, $lexer->get_token()->id ); // EOF $this->assertTrue( $lexer->next_token() ); - $this->assertSame( WP_MySQL_Lexer::EOF, $lexer->get_token()->get_type() ); + $this->assertSame( WP_MySQL_Lexer::EOF, $lexer->get_token()->id ); // No more tokens. $this->assertFalse( $lexer->next_token() ); @@ -40,7 +40,7 @@ public function test_tokenize_invalid_input(): void { // SELECT $this->assertTrue( $lexer->next_token() ); - $this->assertSame( WP_MySQL_Lexer::SELECT_SYMBOL, $lexer->get_token()->get_type() ); + $this->assertSame( WP_MySQL_Lexer::SELECT_SYMBOL, $lexer->get_token()->id ); // Invalid input. $this->assertFalse( $lexer->next_token() ); @@ -66,7 +66,7 @@ public function test_identifier_utf8_range(): void { $lexer = new WP_MySQL_Lexer( $value ); $this->assertTrue( $lexer->next_token() ); - $type = $lexer->get_token()->get_type(); + $type = $lexer->get_token()->id; $is_valid = preg_match( '/^[\x{0080}-\x{ffff}]$/u', $value ); if ( $is_valid ) { $this->assertSame( WP_MySQL_Lexer::IDENTIFIER, $type ); @@ -95,7 +95,7 @@ public function test_identifier_utf8_two_byte_sequences(): void { $is_valid = preg_match( '/^[\x{0080}-\x{ffff}]$/u', $value ); if ( $is_valid ) { $this->assertTrue( $result ); - $this->assertSame( WP_MySQL_Lexer::IDENTIFIER, $token->get_type() ); + $this->assertSame( WP_MySQL_Lexer::IDENTIFIER, $token->id ); } else { $this->assertFalse( $result ); $this->assertNull( $token ); @@ -125,7 +125,7 @@ public function test_identifier_utf8_three_byte_sequences(): void { $is_valid = preg_match( '/^[\x{0080}-\x{ffff}]$/u', $value ); if ( $is_valid ) { $this->assertTrue( $result ); - $this->assertSame( WP_MySQL_Lexer::IDENTIFIER, $token->get_type() ); + $this->assertSame( WP_MySQL_Lexer::IDENTIFIER, $token->id ); } else { $this->assertFalse( $result ); $this->assertNull( $token ); @@ -141,7 +141,7 @@ public function test_identifier_utf8_three_byte_sequences(): void { public function test_integer_types( $input, $expected ): void { $lexer = new WP_MySQL_Lexer( $input ); $this->assertTrue( $lexer->next_token() ); - $this->assertSame( $expected, $lexer->get_token()->get_type() ); + $this->assertSame( $expected, $lexer->get_token()->id ); } public function data_integer_types(): array { @@ -185,7 +185,7 @@ public function test_identifier_or_number( $input, $expected ): void { $lexer = new WP_MySQL_Lexer( $input ); $actual = array_map( function ( $token ) { - return $token->get_type(); + return $token->id; }, $lexer->remaining_tokens() ); diff --git a/tests/tools/dump-ast.php b/tests/tools/dump-ast.php index 5fa512d3..0f2b8ee3 100644 --- a/tests/tools/dump-ast.php +++ b/tests/tools/dump-ast.php @@ -12,12 +12,13 @@ function ( $severity, $message, $file, $line ) { } ); -require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-token.php'; -require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-lexer.php'; require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser.php'; require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser-grammar.php'; require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser-node.php'; +require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser-token.php'; +require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-lexer.php'; require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-parser.php'; +require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-token.php'; $grammar_data = include __DIR__ . '/../../wp-includes/mysql/mysql-grammar.php'; $grammar = new WP_Parser_Grammar( $grammar_data ); diff --git a/tests/tools/dump-sqlite-query.php b/tests/tools/dump-sqlite-query.php index 8b2ada80..82dd244b 100644 --- a/tests/tools/dump-sqlite-query.php +++ b/tests/tools/dump-sqlite-query.php @@ -3,6 +3,7 @@ require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser.php'; require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser-grammar.php'; require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser-node.php'; +require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser-token.php'; require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-lexer.php'; require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-token.php'; require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-parser.php'; diff --git a/tests/tools/run-lexer-benchmark.php b/tests/tools/run-lexer-benchmark.php index 5fd0e2cb..a86d0f0f 100644 --- a/tests/tools/run-lexer-benchmark.php +++ b/tests/tools/run-lexer-benchmark.php @@ -12,6 +12,7 @@ function ( $severity, $message, $file, $line ) { } ); +require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser-token.php'; require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-token.php'; require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-lexer.php'; diff --git a/tests/tools/run-parser-benchmark.php b/tests/tools/run-parser-benchmark.php index 6d162335..5d5f5e2e 100644 --- a/tests/tools/run-parser-benchmark.php +++ b/tests/tools/run-parser-benchmark.php @@ -13,11 +13,12 @@ function ( $severity, $message, $file, $line ) { } ); -require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-token.php'; -require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-lexer.php'; require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser-grammar.php'; require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser-node.php'; +require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser-token.php'; require_once __DIR__ . '/../../wp-includes/parser/class-wp-parser.php'; +require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-token.php'; +require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-lexer.php'; require_once __DIR__ . '/../../wp-includes/mysql/class-wp-mysql-parser.php'; function getStats( $total, $failures, $exceptions ) { diff --git a/wp-includes/mysql/class-wp-mysql-token.php b/wp-includes/mysql/class-wp-mysql-token.php index ba112a76..c812288d 100644 --- a/wp-includes/mysql/class-wp-mysql-token.php +++ b/wp-includes/mysql/class-wp-mysql-token.php @@ -1,39 +1,39 @@ type = $type; - $this->text = $text; - } - - public function get_type() { - return $this->type; + public function get_name(): string { + $name = WP_MySQL_Lexer::get_token_name( $this->id ); + if ( null === $name ) { + $name = 'UNKNOWN'; + } + return $name; } - public function get_text() { - return $this->text; - } - - public function get_name() { - return WP_MySQL_Lexer::get_token_name( $this->type ); - } - - public function extract_value() { - return $this->get_text(); - } - - public function __toString() { - return $this->text . '<' . $this->type . ',' . $this->get_name() . '>'; + /** + * Get the token representation as a string. + * + * This method is intended to be used only for testing and debugging purposes, + * when tokens need to be presented in a human-readable form. It should not + * be used in production code, as it's not performance-optimized. + * + * @return string + */ + public function __toString(): string { + return $this->value . '<' . $this->id . ',' . $this->get_name() . '>'; } } diff --git a/wp-includes/parser/class-wp-parser-node.php b/wp-includes/parser/class-wp-parser-node.php index b65ebd67..75fd4861 100644 --- a/wp-includes/parser/class-wp-parser-node.php +++ b/wp-includes/parser/class-wp-parser-node.php @@ -113,9 +113,9 @@ public function has_child( $rule_name ) { public function has_token( $token_id = null ) { foreach ( $this->children as $child ) { - if ( $child instanceof WP_MySQL_Token && ( + if ( $child instanceof WP_Parser_Token && ( null === $token_id || - $child->type === $token_id + $child->id === $token_id ) ) { return true; } @@ -125,9 +125,9 @@ public function has_token( $token_id = null ) { public function get_token( $token_id = null ) { foreach ( $this->children as $child ) { - if ( $child instanceof WP_MySQL_Token && ( + if ( $child instanceof WP_Parser_Token && ( null === $token_id || - $child->type === $token_id + $child->id === $token_id ) ) { return $child; } diff --git a/wp-includes/parser/class-wp-parser-token.php b/wp-includes/parser/class-wp-parser-token.php new file mode 100644 index 00000000..1148995d --- /dev/null +++ b/wp-includes/parser/class-wp-parser-token.php @@ -0,0 +1,36 @@ +id = $id; + $this->value = $value; + } +} diff --git a/wp-includes/parser/class-wp-parser.php b/wp-includes/parser/class-wp-parser.php index 088f3a2c..c7664f5f 100644 --- a/wp-includes/parser/class-wp-parser.php +++ b/wp-includes/parser/class-wp-parser.php @@ -37,7 +37,7 @@ private function parse_recursive( $rule_id ) { return true; } - if ( $this->tokens[ $this->position ]->type === $rule_id ) { + if ( $this->tokens[ $this->position ]->id === $rule_id ) { ++$this->position; return $this->tokens[ $this->position - 1 ]; } @@ -52,7 +52,7 @@ private function parse_recursive( $rule_id ) { // Bale out from processing the current branch if none of its rules can // possibly match the current token. if ( isset( $this->grammar->lookahead_is_match_possible[ $rule_id ] ) ) { - $token_id = $this->tokens[ $this->position ]->type; + $token_id = $this->tokens[ $this->position ]->id; if ( ! isset( $this->grammar->lookahead_is_match_possible[ $rule_id ][ $token_id ] ) && ! isset( $this->grammar->lookahead_is_match_possible[ $rule_id ][ WP_Parser_Grammar::EMPTY_RULE_ID ] ) @@ -101,7 +101,7 @@ private function parse_recursive( $rule_id ) { // See: https://github.com/mysql/mysql-workbench/blob/8.0.38/library/parsers/grammars/MySQLParser.g4#L994 // See: https://github.com/antlr/antlr4/issues/488 $la = $this->tokens[ $this->position ] ?? null; - if ( $la && 'selectStatement' === $rule_name && WP_MySQL_Lexer::INTO_SYMBOL === $la->type ) { + if ( $la && 'selectStatement' === $rule_name && WP_MySQL_Lexer::INTO_SYMBOL === $la->id ) { $branch_matches = false; } diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver-prototype.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver-prototype.php index 98e732a2..9296051e 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver-prototype.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver-prototype.php @@ -141,7 +141,7 @@ private function translate_query( $ast ) { if ( $ast instanceof WP_MySQL_Token ) { $token = $ast; - switch ( $token->type ) { + switch ( $token->id ) { case WP_MySQL_Lexer::EOF: return new WP_SQLite_Expression( array() ); From 3449b0ba6bdaf12d7f76ccf0e9b62ba54413575e Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Tue, 19 Nov 2024 16:00:29 +0100 Subject: [PATCH 06/36] Complete WP_Parser_Node helper methods, add tests --- tests/parser/WP_Parser_Node_Tests.php | 144 +++++++++++++++++ wp-includes/parser/class-wp-parser-node.php | 161 +++++++++++++++----- wp-includes/parser/class-wp-parser.php | 2 +- 3 files changed, 266 insertions(+), 41 deletions(-) create mode 100644 tests/parser/WP_Parser_Node_Tests.php diff --git a/tests/parser/WP_Parser_Node_Tests.php b/tests/parser/WP_Parser_Node_Tests.php new file mode 100644 index 00000000..e500f835 --- /dev/null +++ b/tests/parser/WP_Parser_Node_Tests.php @@ -0,0 +1,144 @@ +assertFalse( $node->has_child() ); + $this->assertFalse( $node->has_child_node() ); + $this->assertFalse( $node->has_child_token() ); + + $this->assertNull( $node->get_child() ); + $this->assertNull( $node->get_child_node() ); + $this->assertNull( $node->get_child_node( 'root' ) ); + $this->assertNull( $node->get_child_token() ); + $this->assertNull( $node->get_child_token( 1 ) ); + + $this->assertNull( $node->get_descendant_node() ); + $this->assertNull( $node->get_descendant_token() ); + + $this->assertEmpty( $node->get_children() ); + $this->assertEmpty( $node->get_child_nodes() ); + $this->assertEmpty( $node->get_child_nodes( 'root' ) ); + $this->assertEmpty( $node->get_child_tokens() ); + $this->assertEmpty( $node->get_child_tokens( 1 ) ); + + $this->assertEmpty( $node->get_descendants() ); + $this->assertEmpty( $node->get_descendant_nodes() ); + $this->assertEmpty( $node->get_descendant_nodes( 'root' ) ); + $this->assertEmpty( $node->get_descendant_tokens() ); + $this->assertEmpty( $node->get_descendant_tokens( 1 ) ); + } + + public function testNodeTree(): void { + // Prepare nodes and tokens. + $root = new WP_Parser_Node( 1, 'root' ); + $n_keyword = new WP_Parser_Node( 2, 'keyword' ); + $n_expr_a = new WP_Parser_Node( 3, 'expr' ); + $n_expr_b = new WP_Parser_Node( 3, 'expr' ); + $n_expr_c = new WP_Parser_Node( 3, 'expr' ); + $t_select = new WP_Parser_Token( 100, 'SELECT' ); + $t_comma = new WP_Parser_Token( 200, ',' ); + $t_plus = new WP_Parser_Token( 300, '+' ); + $t_one = new WP_Parser_Token( 400, '1' ); + $t_two_a = new WP_Parser_Token( 400, '2' ); + $t_two_b = new WP_Parser_Token( 400, '2' ); + $t_eof = new WP_Parser_Token( 500, '' ); + + // Prepare a tree. + // + // A simplified testing tree for an input like "SELECT 1 + 2, 2". + // + // root + // |- keyword + // | |- "SELECT" + // |- expr [a] + // | |- "1" + // | |- "+" + // | |- expr [c] + // | | |- "2" [b] + // |- "," + // |- expr [b] + // | |- "2" [a] + // |- EOF + $root->append_child( $n_keyword ); + $root->append_child( $n_expr_a ); + $root->append_child( $t_comma ); + $root->append_child( $n_expr_b ); + $root->append_child( $t_eof ); + + $n_keyword->append_child( $t_select ); + $n_expr_a->append_child( $t_one ); + $n_expr_a->append_child( $t_plus ); + $n_expr_a->append_child( $n_expr_c ); + $n_expr_b->append_child( $t_two_a ); + $n_expr_c->append_child( $t_two_b ); + + // Test "has" methods. + $this->assertTrue( $root->has_child() ); + $this->assertTrue( $root->has_child_node() ); + $this->assertTrue( $root->has_child_token() ); + + // Test single child methods. + $this->assertSame( $n_keyword, $root->get_child() ); + $this->assertSame( $n_keyword, $root->get_child_node() ); + $this->assertSame( $n_keyword, $root->get_child_node( 'keyword' ) ); + $this->assertSame( $n_expr_a, $root->get_child_node( 'expr' ) ); + $this->assertSame( $t_comma, $root->get_child_token() ); + $this->assertSame( $t_comma, $root->get_child_token( 200 ) ); + $this->assertNull( $root->get_child_token( 100 ) ); + + // Test multiple children methods. + $this->assertSame( array( $n_keyword, $n_expr_a, $t_comma, $n_expr_b, $t_eof ), $root->get_children() ); + $this->assertSame( array( $n_keyword, $n_expr_a, $n_expr_b ), $root->get_child_nodes() ); + $this->assertSame( array( $n_expr_a, $n_expr_b ), $root->get_child_nodes( 'expr' ) ); + $this->assertSame( array(), $root->get_child_nodes( 'root' ) ); + $this->assertSame( array( $t_comma, $t_eof ), $root->get_child_tokens() ); + $this->assertSame( array( $t_comma ), $root->get_child_tokens( 200 ) ); + $this->assertSame( array(), $root->get_child_tokens( 100 ) ); + + // Test single descendant methods. + // @TODO: Consider breadth-first search vs depth-first search. + $this->assertSame( $n_keyword, $root->get_descendant_node() ); + $this->assertSame( $n_expr_a, $root->get_descendant_node( 'expr' ) ); + $this->assertSame( null, $root->get_descendant_node( 'root' ) ); + $this->assertSame( $t_comma, $root->get_descendant_token() ); + $this->assertSame( $t_one, $root->get_descendant_token( 400 ) ); + $this->assertSame( null, $root->get_descendant_token( 123 ) ); + + // Test multiple descendant methods. + // @TODO: Consider breadth-first search vs depth-first search. + $this->assertSame( + array( $n_keyword, $n_expr_a, $t_comma, $n_expr_b, $t_eof, $t_select, $t_one, $t_plus, $n_expr_c, $t_two_a, $t_two_b ), + $root->get_descendants() + ); + $this->assertSame( + array( $n_keyword, $n_expr_a, $n_expr_b, $n_expr_c ), + $root->get_descendant_nodes() + ); + $this->assertSame( + array( $n_expr_a, $n_expr_b, $n_expr_c ), + $root->get_descendant_nodes( 'expr' ) + ); + $this->assertSame( + array(), + $root->get_descendant_nodes( 'root' ) + ); + $this->assertSame( + array( $t_comma, $t_eof, $t_select, $t_one, $t_plus, $t_two_a, $t_two_b ), + $root->get_descendant_tokens() + ); + $this->assertSame( + array( $t_one, $t_two_a, $t_two_b ), + $root->get_descendant_tokens( 400 ) + ); + $this->assertSame( + array(), + $root->get_descendant_tokens( 123 ) + ); + } +} diff --git a/wp-includes/parser/class-wp-parser-node.php b/wp-includes/parser/class-wp-parser-node.php index 75fd4861..89f86666 100644 --- a/wp-includes/parser/class-wp-parser-node.php +++ b/wp-includes/parser/class-wp-parser-node.php @@ -15,7 +15,7 @@ class WP_Parser_Node { */ public $rule_id; public $rule_name; - public $children = array(); + private $children = array(); public function __construct( $rule_id, $rule_name ) { $this->rule_id = $rule_id; @@ -102,83 +102,164 @@ public function merge_fragment( $node ) { $this->children = array_merge( $this->children, $node->children ); } - public function has_child( $rule_name ) { + public function has_child(): bool { + return count( $this->children ) > 0; + } + + public function has_child_node( ?string $rule_name = null ): bool { foreach ( $this->children as $child ) { - if ( ( $child instanceof WP_Parser_Node && $child->rule_name === $rule_name ) ) { + if ( + $child instanceof WP_Parser_Node + && ( null === $rule_name || $child->rule_name === $rule_name ) + ) { return true; } } return false; } - public function has_token( $token_id = null ) { + public function has_child_token( ?int $token_id = null ): bool { foreach ( $this->children as $child ) { - if ( $child instanceof WP_Parser_Token && ( - null === $token_id || - $child->id === $token_id - ) ) { + if ( + $child instanceof WP_Parser_Token + && ( null === $token_id || $child->id === $token_id ) + ) { return true; } } return false; } - public function get_token( $token_id = null ) { + + public function get_child() { + return $this->children[0] ?? null; + } + + public function get_child_node( ?string $rule_name = null ): ?WP_Parser_Node { foreach ( $this->children as $child ) { - if ( $child instanceof WP_Parser_Token && ( - null === $token_id || - $child->id === $token_id - ) ) { + if ( + $child instanceof WP_Parser_Node + && ( null === $rule_name || $child->rule_name === $rule_name ) + ) { return $child; } } return null; } - public function get_child( $rule_name = null ) { + public function get_child_token( ?int $token_id = null ): ?WP_Parser_Token { foreach ( $this->children as $child ) { - if ( $child instanceof WP_Parser_Node && ( - $child->rule_name === $rule_name || - null === $rule_name - ) ) { + if ( + $child instanceof WP_Parser_Token + && ( null === $token_id || $child->id === $token_id ) + ) { return $child; } } + return null; } - public function get_descendant( $rule_name ) { - $parse_trees = array( $this ); - while ( count( $parse_trees ) ) { - $parse_tree = array_pop( $parse_trees ); - if ( $parse_tree->rule_name === $rule_name ) { - return $parse_tree; + public function get_descendant_node( ?string $rule_name = null ): ?WP_Parser_Node { + $nodes = array( $this ); + while ( count( $nodes ) ) { + $node = array_shift( $nodes ); + $child = $node->get_child_node( $rule_name ); + if ( $child ) { + return $child; + } + $children = $node->get_child_nodes(); + if ( count( $children ) > 0 ) { + array_push( $nodes, ...$children ); } - array_push( $parse_trees, ...$parse_tree->get_children() ); } return null; } - public function get_descendants( $rule_name ) { - $parse_trees = array( $this ); + public function get_descendant_token( ?int $token_id = null ): ?WP_Parser_Token { + $nodes = array( $this ); + while ( count( $nodes ) ) { + $node = array_shift( $nodes ); + $child = $node->get_child_token( $token_id ); + if ( $child ) { + return $child; + } + $children = $node->get_child_nodes(); + if ( count( $children ) > 0 ) { + array_push( $nodes, ...$children ); + } + } + return null; + } + + public function get_children(): array { + return $this->children; + } + + public function get_child_nodes( ?string $rule_name = null ): array { + $nodes = array(); + foreach ( $this->children as $child ) { + if ( + $child instanceof WP_Parser_Node + && ( null === $rule_name || $child->rule_name === $rule_name ) + ) { + $nodes[] = $child; + } + } + return $nodes; + } + + public function get_child_tokens( ?int $token_id = null ): array { + $tokens = array(); + foreach ( $this->children as $child ) { + if ( + $child instanceof WP_Parser_Token + && ( null === $token_id || $child->id === $token_id ) + ) { + $tokens[] = $child; + } + } + return $tokens; + } + + public function get_descendants(): array { + $nodes = array( $this ); + $all_descendants = array(); + while ( count( $nodes ) ) { + $node = array_shift( $nodes ); + $all_descendants = array_merge( $all_descendants, $node->get_children() ); + $children = $node->get_child_nodes(); + if ( count( $children ) > 0 ) { + array_push( $nodes, ...$children ); + } + } + return $all_descendants; + } + + public function get_descendant_nodes( ?string $rule_name = null ): array { + $nodes = array( $this ); $all_descendants = array(); - while ( count( $parse_trees ) ) { - $parse_tree = array_pop( $parse_trees ); - $all_descendants = array_merge( $all_descendants, $parse_tree->get_children( $rule_name ) ); - array_push( $parse_trees, ...$parse_tree->get_children() ); + while ( count( $nodes ) ) { + $node = array_shift( $nodes ); + $all_descendants = array_merge( $all_descendants, $node->get_child_nodes( $rule_name ) ); + $children = $node->get_child_nodes(); + if ( count( $children ) > 0 ) { + array_push( $nodes, ...$children ); + } } return $all_descendants; } - public function get_children( $rule_name = null ) { - $matches = array(); - foreach ( $this->children as $child ) { - if ( $child instanceof WP_Parser_Node && ( - null === $rule_name || - $child->rule_name === $rule_name - ) ) { - $matches[] = $child; + public function get_descendant_tokens( ?int $token_id = null ): array { + $nodes = array( $this ); + $all_descendants = array(); + while ( count( $nodes ) ) { + $node = array_shift( $nodes ); + $all_descendants = array_merge( $all_descendants, $node->get_child_tokens( $token_id ) ); + $children = $node->get_child_nodes(); + if ( count( $children ) > 0 ) { + array_push( $nodes, ...$children ); } } - return $matches; + return $all_descendants; } } diff --git a/wp-includes/parser/class-wp-parser.php b/wp-includes/parser/class-wp-parser.php index c7664f5f..f266cc7f 100644 --- a/wp-includes/parser/class-wp-parser.php +++ b/wp-includes/parser/class-wp-parser.php @@ -115,7 +115,7 @@ private function parse_recursive( $rule_id ) { return false; } - if ( 0 === count( $node->children ) ) { + if ( ! $node->has_child() ) { return true; } From 65afd676570a257fad00b641ac8939e4090001a1 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Tue, 19 Nov 2024 16:32:00 +0100 Subject: [PATCH 07/36] Add basic support for SELECT statements, add unit tests --- tests/WP_SQLite_Driver_Translation_Tests.php | 104 +++++++++++++ tests/tools/dump-sqlite-query.php | 13 +- .../sqlite-ast/class-wp-sqlite-driver.php | 138 ++++++++++++++++-- 3 files changed, 243 insertions(+), 12 deletions(-) create mode 100644 tests/WP_SQLite_Driver_Translation_Tests.php diff --git a/tests/WP_SQLite_Driver_Translation_Tests.php b/tests/WP_SQLite_Driver_Translation_Tests.php new file mode 100644 index 00000000..a9de6e0e --- /dev/null +++ b/tests/WP_SQLite_Driver_Translation_Tests.php @@ -0,0 +1,104 @@ +assertQuery( + 'SELECT 1', + 'SELECT 1' + ); + + $this->assertQuery( + 'SELECT * FROM "t"', + 'SELECT * FROM t' + ); + + $this->assertQuery( + 'SELECT "c" FROM "t"', + 'SELECT c FROM t' + ); + + $this->assertQuery( + 'SELECT ALL "c" FROM "t"', + 'SELECT ALL c FROM t' + ); + + $this->assertQuery( + 'SELECT DISTINCT "c" FROM "t"', + 'SELECT DISTINCT c FROM t' + ); + + $this->assertQuery( + 'SELECT "c1" , "c2" FROM "t"', + 'SELECT c1, c2 FROM t' + ); + + $this->assertQuery( + 'SELECT "t"."c" FROM "t"', + 'SELECT t.c FROM t' + ); + + $this->assertQuery( + 'SELECT "c1" FROM "t" WHERE "c2" = \'abc\'', + "SELECT c1 FROM t WHERE c2 = 'abc'" + ); + + $this->assertQuery( + 'SELECT "c" FROM "t" GROUP BY "c"', + 'SELECT c FROM t GROUP BY c' + ); + + $this->assertQuery( + 'SELECT "c" FROM "t" ORDER BY "c" ASC', + 'SELECT c FROM t ORDER BY c ASC' + ); + + $this->assertQuery( + 'SELECT "c" FROM "t" LIMIT 10', + 'SELECT c FROM t LIMIT 10' + ); + + $this->assertQuery( + 'SELECT "c" FROM "t" GROUP BY "c" HAVING COUNT ( "c" ) > 1', + 'SELECT c FROM t GROUP BY c HAVING COUNT(c) > 1' + ); + + $this->assertQuery( + 'SELECT * FROM "t1" LEFT JOIN "t2" ON "t1"."id" = "t2"."t1_id" WHERE "t1"."name" = \'abc\'', + "SELECT * FROM t1 LEFT JOIN t2 ON t1.id = t2.t1_id WHERE t1.name = 'abc'" + ); + } + + private function assertQuery( $expected, string $query ): void { + $driver = new WP_SQLite_Driver( new PDO( 'sqlite::memory:' ) ); + $driver->query( $query ); + + $executed_queries = array_column( $driver->executed_sqlite_queries, 'sql' ); + if ( count( $executed_queries ) > 2 ) { + // Remove BEGIN and COMMIT/ROLLBACK queries. + $executed_queries = array_values( array_slice( $executed_queries, 1, -1, true ) ); + } + + if ( ! is_array( $expected ) ) { + $expected = array( $expected ); + } + $this->assertSame( $expected, $executed_queries ); + } +} diff --git a/tests/tools/dump-sqlite-query.php b/tests/tools/dump-sqlite-query.php index 82dd244b..158d79d8 100644 --- a/tests/tools/dump-sqlite-query.php +++ b/tests/tools/dump-sqlite-query.php @@ -20,4 +20,15 @@ $query = "SELECT * FROM t1 LEFT JOIN t2 ON t1.id = t2.t1_id WHERE t1.name = 'abc'"; -echo $driver->query( $query ); +$driver->query( $query ); + +$executed_queries = $driver->executed_sqlite_queries; +if ( count( $executed_queries ) > 2 ) { + // Remove BEGIN and COMMIT/ROLLBACK queries. + $executed_queries = array_values( array_slice( $executed_queries, 1, -1, true ) ); +} + +foreach ( $executed_queries as $executed_query ) { + printf( "Query: %s\n", $executed_query['sql'] ); + printf( "Params: %s\n", json_encode( $executed_query['params'] ) ); +} diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index c6210784..f24c9920 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -10,7 +10,9 @@ use SQLite3; use WP_MySQL_Lexer; use WP_MySQL_Parser; +use WP_MySQL_Token; use WP_Parser_Grammar; +use WP_Parser_Node; use WP_SQLite_PDO_User_Defined_Functions; class WP_SQLite_Driver { @@ -502,17 +504,6 @@ public function get_return_value() { return $this->return_value; } - /** - * Executes a MySQL query in SQLite. - * - * @param string $query The query. - * - * @throws Exception If the query is not supported. - */ - private function execute_mysql_query( $query ) { - //@TODO: Implement the query translation. - } - /** * Executes a query in SQLite. * @@ -681,6 +672,93 @@ public function rollback() { return $this->last_exec_returned; } + /** + * Executes a MySQL query in SQLite. + * + * @param string $query The query. + * + * @throws Exception If the query is not supported. + */ + private function execute_mysql_query( WP_Parser_Node $ast ) { + if ( 'query' !== $ast->rule_name ) { + throw new Exception( sprintf( 'Expected "query" node, got: "%s"', $ast->rule_name ) ); + } + + $children = $ast->get_child_nodes(); + if ( count( $children ) !== 1 ) { + throw new Exception( sprintf( 'Expected 1 child, got: %d', count( $children ) ) ); + } + + $ast = $children[0]->get_child_node(); + switch ( $ast->rule_name ) { + case 'selectStatement': + $this->query_type = 'SELECT'; + $query = $this->translate( $ast->get_child() ); + $stmt = $this->execute_sqlite_query( $query ); + $this->set_results_from_fetched_data( + $stmt->fetchAll( $this->pdo_fetch_mode ) + ); + break; + default: + throw new Exception( sprintf( 'Unsupported statement type: "%s"', $ast->rule_name ) ); + } + } + + private function translate( $ast ) { + if ( null === $ast ) { + return null; + } + + if ( $ast instanceof WP_MySQL_Token ) { + return $this->translate_token( $ast ); + } + + if ( ! $ast instanceof WP_Parser_Node ) { + throw new Exception( 'translate_query only accepts WP_MySQL_Token and WP_Parser_Node instances' ); + } + + $rule_name = $ast->rule_name; + switch ( $rule_name ) { + case 'qualifiedIdentifier': + case 'dotIdentifier': + return $this->translate_sequence( $ast->get_children(), '' ); + case 'textStringLiteral': + if ( $ast->has_child_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT ) ) { + return WP_SQLite_Token_Factory::double_quoted_value( + $ast->get_child_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT )->value + )->value; + } + if ( $ast->has_child_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT ) ) { + return WP_SQLite_Token_Factory::raw( + $ast->get_child_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT )->value + )->value; + } + // Fall through to the default case. + + default: + return $this->translate_sequence( $ast->get_children() ); + } + } + + private function translate_token( WP_MySQL_Token $token ) { + switch ( $token->id ) { + case WP_MySQL_Lexer::EOF: + return null; + case WP_MySQL_Lexer::IDENTIFIER: + return '"' . trim( $token->value, '`"' ) . '"'; + default: + return $token->value; + } + } + + private function translate_sequence( array $nodes, string $separator = ' ' ): string { + $parts = array(); + foreach ( $nodes as $node ) { + $parts[] = $this->translate( $node ); + } + return implode( $separator, $parts ); + } + /** * This method makes database directory and .htaccess file. * @@ -745,6 +823,44 @@ private function flush() { $this->executed_sqlite_queries = array(); } + /** + * Method to set the results from the fetched data. + * + * @param array $data The data to set. + */ + private function set_results_from_fetched_data( $data ) { + if ( null === $this->results ) { + $this->results = $data; + } + if ( is_array( $this->results ) ) { + $this->num_rows = count( $this->results ); + $this->last_select_found_rows = count( $this->results ); + } + $this->return_value = $this->results; + } + + /** + * Method to set the results from the affected rows. + * + * @param int|null $override Override the affected rows. + */ + private function set_result_from_affected_rows( $override = null ) { + /* + * SELECT CHANGES() is a workaround for the fact that + * $stmt->rowCount() returns "0" (zero) with the + * SQLite driver at all times. + * Source: https://www.php.net/manual/en/pdostatement.rowcount.php + */ + if ( null === $override ) { + $this->affected_rows = (int) $this->execute_sqlite_query( 'select changes()' )->fetch()[0]; + } else { + $this->affected_rows = $override; + } + $this->return_value = $this->affected_rows; + $this->num_rows = $this->affected_rows; + $this->results = $this->affected_rows; + } + /** * Error handler. * From 00ec46d2fb4a8a5fface35e6c34b44a0235fcb77 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Wed, 20 Nov 2024 16:15:49 +0100 Subject: [PATCH 08/36] Add basic support for INSERT, UPDATE, REPLACE, DELETE --- tests/WP_SQLite_Driver_Translation_Tests.php | 93 +++++++++++++++++++ .../sqlite-ast/class-wp-sqlite-driver.php | 17 ++++ 2 files changed, 110 insertions(+) diff --git a/tests/WP_SQLite_Driver_Translation_Tests.php b/tests/WP_SQLite_Driver_Translation_Tests.php index a9de6e0e..0b754242 100644 --- a/tests/WP_SQLite_Driver_Translation_Tests.php +++ b/tests/WP_SQLite_Driver_Translation_Tests.php @@ -86,6 +86,99 @@ public function testSelect(): void { ); } + public function testInsert(): void { + $this->assertQuery( + 'INSERT INTO "t" ( "c" ) VALUES ( 1 )', + 'INSERT INTO t (c) VALUES (1)' + ); + + $this->assertQuery( + 'INSERT INTO "s"."t" ( "c" ) VALUES ( 1 )', + 'INSERT INTO s.t (c) VALUES (1)' + ); + + $this->assertQuery( + 'INSERT INTO "t" ( "c1" , "c2" ) VALUES ( 1 , 2 )', + 'INSERT INTO t (c1, c2) VALUES (1, 2)' + ); + + $this->assertQuery( + 'INSERT INTO "t" ( "c" ) VALUES ( 1 ) , ( 2 )', + 'INSERT INTO t (c) VALUES (1), (2)' + ); + + $this->assertQuery( + 'INSERT INTO "t1" SELECT * FROM "t2"', + 'INSERT INTO t1 SELECT * FROM t2' + ); + } + + public function testReplace(): void { + $this->assertQuery( + 'REPLACE INTO "t" ( "c" ) VALUES ( 1 )', + 'REPLACE INTO t (c) VALUES (1)' + ); + + $this->assertQuery( + 'REPLACE INTO "s"."t" ( "c" ) VALUES ( 1 )', + 'REPLACE INTO s.t (c) VALUES (1)' + ); + + $this->assertQuery( + 'REPLACE INTO "t" ( "c1" , "c2" ) VALUES ( 1 , 2 )', + 'REPLACE INTO t (c1, c2) VALUES (1, 2)' + ); + + $this->assertQuery( + 'REPLACE INTO "t" ( "c" ) VALUES ( 1 ) , ( 2 )', + 'REPLACE INTO t (c) VALUES (1), (2)' + ); + + $this->assertQuery( + 'REPLACE INTO "t1" SELECT * FROM "t2"', + 'REPLACE INTO t1 SELECT * FROM t2' + ); + } + + public function testUpdate(): void { + $this->assertQuery( + 'UPDATE "t" SET "c" = 1', + 'UPDATE t SET c = 1' + ); + + $this->assertQuery( + 'UPDATE "s"."t" SET "c" = 1', + 'UPDATE s.t SET c = 1' + ); + + $this->assertQuery( + 'UPDATE "t" SET "c1" = 1 , "c2" = 2', + 'UPDATE t SET c1 = 1, c2 = 2' + ); + + $this->assertQuery( + 'UPDATE "t" SET "c" = 1 WHERE "c" = 2', + 'UPDATE t SET c = 1 WHERE c = 2' + ); + } + + public function testDelete(): void { + $this->assertQuery( + 'DELETE FROM "t"', + 'DELETE FROM t' + ); + + $this->assertQuery( + 'DELETE FROM "s"."t"', + 'DELETE FROM s.t' + ); + + $this->assertQuery( + 'DELETE FROM "t" WHERE "c" = 1', + 'DELETE FROM t WHERE c = 1' + ); + } + private function assertQuery( $expected, string $query ): void { $driver = new WP_SQLite_Driver( new PDO( 'sqlite::memory:' ) ); $driver->query( $query ); diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index f24c9920..328fc77c 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -699,6 +699,23 @@ private function execute_mysql_query( WP_Parser_Node $ast ) { $stmt->fetchAll( $this->pdo_fetch_mode ) ); break; + case 'insertStatement': + case 'updateStatement': + case 'replaceStatement': + case 'deleteStatement': + if ( 'insertStatement' === $ast->rule_name ) { + $this->query_type = 'INSERT'; + } elseif ( 'updateStatement' === $ast->rule_name ) { + $this->query_type = 'UPDATE'; + } elseif ( 'replaceStatement' === $ast->rule_name ) { + $this->query_type = 'REPLACE'; + } elseif ( 'deleteStatement' === $ast->rule_name ) { + $this->query_type = 'DELETE'; + } + $query = $this->translate( $ast ); + $this->execute_sqlite_query( $query ); + $this->set_result_from_affected_rows(); + break; default: throw new Exception( sprintf( 'Unsupported statement type: "%s"', $ast->rule_name ) ); } From b8b45009f467507f291dc9b98ec705361207355a Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Wed, 20 Nov 2024 17:00:36 +0100 Subject: [PATCH 09/36] Add basic support for CREATE TABLE, implement data types --- tests/WP_SQLite_Driver_Translation_Tests.php | 133 ++++++++++++++++- .../WP_MySQL_Server_Suite_Parser_Tests.php | 1 - wp-includes/mysql/class-wp-mysql-lexer.php | 4 + .../sqlite-ast/class-wp-sqlite-driver.php | 140 ++++++++++++++++-- 4 files changed, 267 insertions(+), 11 deletions(-) diff --git a/tests/WP_SQLite_Driver_Translation_Tests.php b/tests/WP_SQLite_Driver_Translation_Tests.php index 0b754242..075da646 100644 --- a/tests/WP_SQLite_Driver_Translation_Tests.php +++ b/tests/WP_SQLite_Driver_Translation_Tests.php @@ -179,16 +179,147 @@ public function testDelete(): void { ); } + public function testCreateTable(): void { + $this->assertQuery( + 'CREATE TABLE "t" ( "id" INTEGER )', + 'CREATE TABLE t (id INT)' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "id" INTEGER , "name" TEXT , "score" REAL DEFAULT 0.0 )', + 'CREATE TABLE t (id INT, name TEXT, score FLOAT DEFAULT 0.0)' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "id" INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT )', + 'CREATE TABLE t (id INT NOT NULL PRIMARY KEY AUTO_INCREMENT)' + ); + + $this->assertQuery( + 'CREATE TABLE IF NOT EXISTS "t" ( "id" INTEGER )', + 'CREATE TABLE IF NOT EXISTS t (id INT)' + ); + } + + public function testDataTypes(): void { + // Numeric data types. + $this->assertQuery( + 'CREATE TABLE "t" ( "i1" INTEGER , "i2" INTEGER , "i3" INTEGER )', + 'CREATE TABLE t (i1 BIT, i2 BOOL, i3 BOOLEAN)' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "i1" INTEGER , "i2" INTEGER , "i3" INTEGER , "i4" INTEGER , "i5" INTEGER , "i6" INTEGER )', + 'CREATE TABLE t (i1 TINYINT, i2 SMALLINT, i3 MEDIUMINT, i4 INT, i5 INTEGER, i6 BIGINT)' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "f1" REAL , "f2" REAL , "f3" REAL , "f4" REAL )', + 'CREATE TABLE t (f1 FLOAT, f2 DOUBLE, f3 DOUBLE PRECISION, f4 REAL)' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "f1" REAL , "f2" REAL , "f3" REAL , "f4" REAL )', + 'CREATE TABLE t (f1 DECIMAL, f2 DEC, f3 FIXED, f4 NUMERIC)' + ); + + // String data types. + $this->assertQuery( + 'CREATE TABLE "t" ( "c1" TEXT , "c2" TEXT , "c3" TEXT , "c4" TEXT )', + 'CREATE TABLE t (c1 CHAR, c2 VARCHAR(255), c3 CHAR VARYING(255), c4 CHARACTER VARYING(255))' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "c1" TEXT , "c2" TEXT )', + 'CREATE TABLE t (c1 NATIONAL CHAR, c2 NCHAR)' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "c1" TEXT , "c2" TEXT , "c3" TEXT )', + 'CREATE TABLE t (c1 NCHAR VARCHAR(255), c2 NCHAR VARYING(255), c3 NVARCHAR(255))' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "c1" TEXT , "c2" TEXT , "c3" TEXT )', + 'CREATE TABLE t (c1 NATIONAL VARCHAR(255), c2 NATIONAL CHAR VARYING(255), c3 NATIONAL CHARACTER VARYING(255))' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "t1" TEXT , "t2" TEXT , "t3" TEXT , "t4" TEXT )', + 'CREATE TABLE t (t1 TINYTEXT, t2 TEXT, t3 MEDIUMTEXT, t4 LONGTEXT)' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "e" TEXT )', + 'CREATE TABLE t (e ENUM("a", "b", "c"))' + ); + + // Date and time data types. + $this->assertQuery( + 'CREATE TABLE "t" ( "d" TEXT , "t" TEXT , "dt" TEXT , "ts" TEXT , "y" TEXT )', + 'CREATE TABLE t (d DATE, t TIME, dt DATETIME, ts TIMESTAMP, y YEAR)' + ); + + // Binary data types. + $this->assertQuery( + 'CREATE TABLE "t" ( "b" INTEGER , "v" BLOB )', + 'CREATE TABLE t (b BINARY, v VARBINARY(255))' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "b1" BLOB , "b2" BLOB , "b3" BLOB , "b4" BLOB )', + 'CREATE TABLE t (b1 TINYBLOB, b2 BLOB, b3 MEDIUMBLOB, b4 LONGBLOB)' + ); + + // Spatial data types. + $this->assertQuery( + 'CREATE TABLE "t" ( "g1" TEXT , "g2" TEXT , "g3" TEXT , "g4" TEXT )', + 'CREATE TABLE t (g1 GEOMETRY, g2 POINT, g3 LINESTRING, g4 POLYGON)' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "g1" TEXT , "g2" TEXT , "g3" TEXT )', + 'CREATE TABLE t (g1 MULTIPOINT, g2 MULTILINESTRING, g3 MULTIPOLYGON)' + ); + + $this->assertQuery( + 'CREATE TABLE "t" ( "g1" TEXT , "g2" TEXT )', + 'CREATE TABLE t (g1 GEOMCOLLECTION, g2 GEOMETRYCOLLECTION)' + ); + + // SERIAL + $this->assertQuery( + 'CREATE TABLE "t" ( "id" INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT UNIQUE )', + 'CREATE TABLE t (id SERIAL)' + ); + } + private function assertQuery( $expected, string $query ): void { $driver = new WP_SQLite_Driver( new PDO( 'sqlite::memory:' ) ); $driver->query( $query ); + // Check for SQLite syntax errors. + // This ensures that invalid SQLite syntax will always fail, even if it + // was the expected result. It prevents us from using wrong assertions. + $error = $driver->get_error_message(); + if ( $error && preg_match( '/(SQLSTATE\[HY000].+syntax error\.)/i', $error, $matches ) ) { + $this->fail( 'SQLite syntax error: ' . $matches[1] ); + } + $executed_queries = array_column( $driver->executed_sqlite_queries, 'sql' ); + + // Remove BEGIN and COMMIT/ROLLBACK queries. if ( count( $executed_queries ) > 2 ) { - // Remove BEGIN and COMMIT/ROLLBACK queries. $executed_queries = array_values( array_slice( $executed_queries, 1, -1, true ) ); } + // Remove "select changes()" executed after some queries. + if ( + count( $executed_queries ) > 1 + && 'select changes()' === $executed_queries[ count( $executed_queries ) - 1 ] ) { + array_pop( $executed_queries ); + } + if ( ! is_array( $expected ) ) { $expected = array( $expected ); } diff --git a/tests/mysql/WP_MySQL_Server_Suite_Parser_Tests.php b/tests/mysql/WP_MySQL_Server_Suite_Parser_Tests.php index 6a8a96dc..e6bb1284 100644 --- a/tests/mysql/WP_MySQL_Server_Suite_Parser_Tests.php +++ b/tests/mysql/WP_MySQL_Server_Suite_Parser_Tests.php @@ -17,7 +17,6 @@ class WP_MySQL_Server_Suite_Parser_Tests extends TestCase { 'SELECT 1 /*!99999 /* */ */' => true, 'select 1ea10.1a20,1e+ 1e+10 from 1ea10' => true, "聠聡聢聣聤聬聭聮聯聰聲聽隆垄拢陇楼卤潞禄录陆戮 聶職聳聴\n0聲5\n1聲5\n2聲5\n3聲5\n4\n\nSET NAMES gb18030" => true, - 'CREATE TABLE t1 (g GEOMCOLLECTION)' => true, "alter user mysqltest_7@ identified by 'systpass'" => true, "SELECT 'a%' LIKE 'a!%' ESCAPE '!', 'a%' LIKE 'a!' || '%' ESCAPE '!'" => true, "SELECT 'a%' NOT LIKE 'a!%' ESCAPE '!', 'a%' NOT LIKE 'a!' || '%' ESCAPE '!'" => true, diff --git a/wp-includes/mysql/class-wp-mysql-lexer.php b/wp-includes/mysql/class-wp-mysql-lexer.php index bcaca570..f2174eac 100644 --- a/wp-includes/mysql/class-wp-mysql-lexer.php +++ b/wp-includes/mysql/class-wp-mysql-lexer.php @@ -929,6 +929,7 @@ class WP_MySQL_Lexer { const SECONDARY_ENGINE_ATTRIBUTE_SYMBOL = 849; const JSON_VALUE_SYMBOL = 850; const RETURNING_SYMBOL = 851; + const GEOMCOLLECTION_SYMBOL = 852; // Comments const COMMENT = 900; @@ -1155,6 +1156,7 @@ class WP_MySQL_Lexer { 'FUNCTION' => self::FUNCTION_SYMBOL, 'GENERAL' => self::GENERAL_SYMBOL, 'GENERATED' => self::GENERATED_SYMBOL, + 'GEOMCOLLECTION' => self::GEOMCOLLECTION_SYMBOL, 'GEOMETRY' => self::GEOMETRY_SYMBOL, 'GEOMETRYCOLLECTION' => self::GEOMETRYCOLLECTION_SYMBOL, 'GET' => self::GET_SYMBOL, @@ -1810,6 +1812,7 @@ class WP_MySQL_Lexer { self::FIELDS_SYMBOL => self::COLUMNS_SYMBOL, self::FLOAT4_SYMBOL => self::FLOAT_SYMBOL, self::FLOAT8_SYMBOL => self::DOUBLE_SYMBOL, + self::GEOMCOLLECTION_SYMBOL => self::GEOMETRYCOLLECTION_SYMBOL, self::INT1_SYMBOL => self::TINYINT_SYMBOL, self::INT2_SYMBOL => self::SMALLINT_SYMBOL, self::INT3_SYMBOL => self::MEDIUMINT_SYMBOL, @@ -1936,6 +1939,7 @@ class WP_MySQL_Lexer { self::FAILED_LOGIN_ATTEMPTS_SYMBOL => 80019, self::FIRST_VALUE_SYMBOL => 80000, self::FOLLOWING_SYMBOL => 80000, + self::GEOMCOLLECTION_SYMBOL => 80000, self::GET_MASTER_PUBLIC_KEY_SYMBOL => 80000, self::GET_SOURCE_PUBLIC_KEY_SYMBOL => 80000, self::GROUPING_SYMBOL => 80000, diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 328fc77c..d1d4c21d 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -21,6 +21,65 @@ class WP_SQLite_Driver { const SQLITE_BUSY = 5; const SQLITE_LOCKED = 6; + const DATA_TYPE_MAP = array( + // Numeric data types: + WP_MySQL_Lexer::BIT_SYMBOL => 'INTEGER', + WP_MySQL_Lexer::BOOL_SYMBOL => 'INTEGER', + WP_MySQL_Lexer::BOOLEAN_SYMBOL => 'INTEGER', + WP_MySQL_Lexer::TINYINT_SYMBOL => 'INTEGER', + WP_MySQL_Lexer::SMALLINT_SYMBOL => 'INTEGER', + WP_MySQL_Lexer::MEDIUMINT_SYMBOL => 'INTEGER', + WP_MySQL_Lexer::INT_SYMBOL => 'INTEGER', + WP_MySQL_Lexer::INTEGER_SYMBOL => 'INTEGER', + WP_MySQL_Lexer::BIGINT_SYMBOL => 'INTEGER', + WP_MySQL_Lexer::FLOAT_SYMBOL => 'REAL', + WP_MySQL_Lexer::DOUBLE_SYMBOL => 'REAL', + WP_MySQL_Lexer::REAL_SYMBOL => 'REAL', + WP_MySQL_Lexer::DECIMAL_SYMBOL => 'REAL', + WP_MySQL_Lexer::DEC_SYMBOL => 'REAL', + WP_MySQL_Lexer::FIXED_SYMBOL => 'REAL', + WP_MySQL_Lexer::NUMERIC_SYMBOL => 'REAL', + + // String data types: + WP_MySQL_Lexer::CHAR_SYMBOL => 'TEXT', + WP_MySQL_Lexer::VARCHAR_SYMBOL => 'TEXT', + WP_MySQL_Lexer::NCHAR_SYMBOL => 'TEXT', + WP_MySQL_Lexer::NVARCHAR_SYMBOL => 'TEXT', + WP_MySQL_Lexer::TINYTEXT_SYMBOL => 'TEXT', + WP_MySQL_Lexer::TEXT_SYMBOL => 'TEXT', + WP_MySQL_Lexer::MEDIUMTEXT_SYMBOL => 'TEXT', + WP_MySQL_Lexer::LONGTEXT_SYMBOL => 'TEXT', + WP_MySQL_Lexer::ENUM_SYMBOL => 'TEXT', + + // Date and time data types: + WP_MySQL_Lexer::DATE_SYMBOL => 'TEXT', + WP_MySQL_Lexer::TIME_SYMBOL => 'TEXT', + WP_MySQL_Lexer::DATETIME_SYMBOL => 'TEXT', + WP_MySQL_Lexer::TIMESTAMP_SYMBOL => 'TEXT', + WP_MySQL_Lexer::YEAR_SYMBOL => 'TEXT', + + // Binary data types: + WP_MySQL_Lexer::BINARY_SYMBOL => 'INTEGER', + WP_MySQL_Lexer::VARBINARY_SYMBOL => 'BLOB', + WP_MySQL_Lexer::TINYBLOB_SYMBOL => 'BLOB', + WP_MySQL_Lexer::BLOB_SYMBOL => 'BLOB', + WP_MySQL_Lexer::MEDIUMBLOB_SYMBOL => 'BLOB', + WP_MySQL_Lexer::LONGBLOB_SYMBOL => 'BLOB', + + // Spatial data types: + WP_MySQL_Lexer::GEOMETRY_SYMBOL => 'TEXT', + WP_MySQL_Lexer::POINT_SYMBOL => 'TEXT', + WP_MySQL_Lexer::LINESTRING_SYMBOL => 'TEXT', + WP_MySQL_Lexer::POLYGON_SYMBOL => 'TEXT', + WP_MySQL_Lexer::MULTIPOINT_SYMBOL => 'TEXT', + WP_MySQL_Lexer::MULTILINESTRING_SYMBOL => 'TEXT', + WP_MySQL_Lexer::MULTIPOLYGON_SYMBOL => 'TEXT', + WP_MySQL_Lexer::GEOMCOLLECTION_SYMBOL => 'TEXT', + WP_MySQL_Lexer::GEOMETRYCOLLECTION_SYMBOL => 'TEXT', + + // SERIAL, SET, and JSON types are handled in the translation process. + ); + const DATA_TYPES_CACHE_TABLE = '_mysql_data_types_cache'; const CREATE_DATA_TYPES_CACHE_TABLE = 'CREATE TABLE IF NOT EXISTS _mysql_data_types_cache ( @@ -716,6 +775,25 @@ private function execute_mysql_query( WP_Parser_Node $ast ) { $this->execute_sqlite_query( $query ); $this->set_result_from_affected_rows(); break; + case 'createStatement': + $this->query_type = 'CREATE'; + $subtree = $ast->get_child_node(); + switch ( $subtree->rule_name ) { + case 'createTable': + $query = $this->translate( $ast ); + $this->execute_sqlite_query( $query ); + $this->set_result_from_affected_rows(); + break; + default: + throw new Exception( + sprintf( + 'Unsupported statement type: "%s" > "%s"', + $ast->rule_name, + $subtree->rule_name + ) + ); + } + break; default: throw new Exception( sprintf( 'Unsupported statement type: "%s"', $ast->rule_name ) ); } @@ -739,19 +817,51 @@ private function translate( $ast ) { case 'qualifiedIdentifier': case 'dotIdentifier': return $this->translate_sequence( $ast->get_children(), '' ); + case 'identifierKeyword': + return '"' . $this->translate( $ast->get_child() ) . '"'; case 'textStringLiteral': - if ( $ast->has_child_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT ) ) { - return WP_SQLite_Token_Factory::double_quoted_value( - $ast->get_child_token( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT )->value - )->value; + $token = $ast->get_child_token(); + if ( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT === $token->id ) { + return WP_SQLite_Token_Factory::double_quoted_value( $token->value )->value; + } + if ( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT === $token->id ) { + return WP_SQLite_Token_Factory::raw( $token->value )->value; + } + throw $this->invalid_input_exception(); + case 'dataType': + case 'nchar': + $child = $ast->get_child(); + if ( $child instanceof WP_Parser_Node ) { + return $this->translate( $child ); + } + + // Handle optional prefixes (data type is the second token): + // 1. LONG VARCHAR, LONG CHAR(ACTER) VARYING, LONG VARBINARY. + // 2. NATIONAL CHAR, NATIONAL VARCHAR, NATIONAL CHAR(ACTER) VARYING. + if ( WP_MySQL_Lexer::LONG_SYMBOL === $child->id ) { + $child = $ast->get_child_tokens()[1] ?? null; + } elseif ( WP_MySQL_Lexer::NATIONAL_SYMBOL === $child->id ) { + $child = $ast->get_child_tokens()[1] ?? null; + } + + if ( null === $child ) { + throw $this->invalid_input_exception(); } - if ( $ast->has_child_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT ) ) { - return WP_SQLite_Token_Factory::raw( - $ast->get_child_token( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT )->value - )->value; + + $type = self::DATA_TYPE_MAP[ $child->id ] ?? null; + if ( null !== $type ) { + return $type; + } + + // SERIAL is an alias for BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE. + if ( WP_MySQL_Lexer::SERIAL_SYMBOL === $child->id ) { + return 'INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT UNIQUE'; } - // Fall through to the default case. + // @TODO: Handle SET and JSON. + throw $this->not_supported_exception( + sprintf( 'data type: %s', $child->value ) + ); default: return $this->translate_sequence( $ast->get_children() ); } @@ -763,6 +873,8 @@ private function translate_token( WP_MySQL_Token $token ) { return null; case WP_MySQL_Lexer::IDENTIFIER: return '"' . trim( $token->value, '`"' ) . '"'; + case WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL: + return 'AUTOINCREMENT'; default: return $token->value; } @@ -912,4 +1024,14 @@ private function set_error( $line, $function_name, $message ) { $this->error_messages[] = $message; $this->is_error = true; } + + private function invalid_input_exception() { + throw new Exception( 'MySQL query syntax error.' ); + } + + private function not_supported_exception( string $cause ): Exception { + return new Exception( + sprintf( 'MySQL query not supported. Cause: %s', $cause ) + ); + } } From 6be220d13322b100913b8521edc54bd66c74c70c Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 21 Nov 2024 17:57:04 +0100 Subject: [PATCH 10/36] Handle system variables --- tests/WP_SQLite_Driver_Translation_Tests.php | 17 +++++++++++++++++ .../sqlite-ast/class-wp-sqlite-driver.php | 7 +++++++ 2 files changed, 24 insertions(+) diff --git a/tests/WP_SQLite_Driver_Translation_Tests.php b/tests/WP_SQLite_Driver_Translation_Tests.php index 075da646..1a22112f 100644 --- a/tests/WP_SQLite_Driver_Translation_Tests.php +++ b/tests/WP_SQLite_Driver_Translation_Tests.php @@ -294,6 +294,23 @@ public function testDataTypes(): void { ); } + public function testSystemVariables(): void { + $this->assertQuery( + 'SELECT NULL', + 'SELECT @@sql_mode' + ); + + $this->assertQuery( + 'SELECT NULL', + 'SELECT @@SESSION.sql_mode' + ); + + $this->assertQuery( + 'SELECT NULL', + 'SELECT @@GLOBAL.sql_mode' + ); + } + private function assertQuery( $expected, string $query ): void { $driver = new WP_SQLite_Driver( new PDO( 'sqlite::memory:' ) ); $driver->query( $query ); diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index d1d4c21d..349c8c0a 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -862,6 +862,13 @@ private function translate( $ast ) { throw $this->not_supported_exception( sprintf( 'data type: %s', $child->value ) ); + case 'systemVariable': + // @TODO: Emulate some system variables, or use reasonable defaults. + // See: https://dev.mysql.com/doc/refman/8.4/en/server-system-variable-reference.html + // See: https://dev.mysql.com/doc/refman/8.4/en/server-system-variables.html + + // When we have no value, it's reasonable to use NULL. + return 'NULL'; default: return $this->translate_sequence( $ast->get_children() ); } From 70744b7d47b06dd3ee93f00508832c4be3508895 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 22 Nov 2024 11:33:05 +0100 Subject: [PATCH 11/36] Add support for UPDATE with ORDER BY and LIMIT --- tests/WP_SQLite_Driver_Translation_Tests.php | 12 +++++ .../sqlite-ast/class-wp-sqlite-driver.php | 53 ++++++++++++++++++- 2 files changed, 63 insertions(+), 2 deletions(-) diff --git a/tests/WP_SQLite_Driver_Translation_Tests.php b/tests/WP_SQLite_Driver_Translation_Tests.php index 1a22112f..1d7523b9 100644 --- a/tests/WP_SQLite_Driver_Translation_Tests.php +++ b/tests/WP_SQLite_Driver_Translation_Tests.php @@ -160,6 +160,18 @@ public function testUpdate(): void { 'UPDATE "t" SET "c" = 1 WHERE "c" = 2', 'UPDATE t SET c = 1 WHERE c = 2' ); + + // UPDATE with LIMIT. + $this->assertQuery( + 'UPDATE "t" SET "c" = 1 WHERE rowid IN ( SELECT rowid FROM "t" LIMIT 1 )', + 'UPDATE t SET c = 1 LIMIT 1' + ); + + // UPDATE with ORDER BY and LIMIT. + $this->assertQuery( + 'UPDATE "t" SET "c" = 1 WHERE rowid IN ( SELECT rowid FROM "t" ORDER BY "c" ASC LIMIT 1 )', + 'UPDATE t SET c = 1 ORDER BY c ASC LIMIT 1' + ); } public function testDelete(): void { diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 349c8c0a..e6938949 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -760,12 +760,12 @@ private function execute_mysql_query( WP_Parser_Node $ast ) { break; case 'insertStatement': case 'updateStatement': + $this->execute_update_statement( $ast ); + break; case 'replaceStatement': case 'deleteStatement': if ( 'insertStatement' === $ast->rule_name ) { $this->query_type = 'INSERT'; - } elseif ( 'updateStatement' === $ast->rule_name ) { - $this->query_type = 'UPDATE'; } elseif ( 'replaceStatement' === $ast->rule_name ) { $this->query_type = 'REPLACE'; } elseif ( 'deleteStatement' === $ast->rule_name ) { @@ -799,6 +799,52 @@ private function execute_mysql_query( WP_Parser_Node $ast ) { } } + private function execute_update_statement( WP_Parser_Node $node ): void { + // @TODO: Add support for UPDATE with multiple tables and JOINs. + // SQLite supports them in the FROM clause. + + $has_order = $node->has_child_node( 'orderClause' ); + $has_limit = $node->has_child_node( 'simpleLimitClause' ); + + /* + * SQLite doesn't support UPDATE with ORDER BY/LIMIT. + * We need to use a subquery to emulate this behavior. + * + * For instance, the following query: + * UPDATE t SET c = 1 WHERE c = 2 LIMIT 1; + * Will be rewritten to: + * UPDATE t SET c = 1 WHERE rowid IN ( SELECT rowid FROM t WHERE c = 2 LIMIT 1 ); + */ + if ( $has_order || $has_limit ) { + $subquery = 'SELECT rowid FROM ' . $this->translate_sequence( + array( + $node->get_descendant_node( 'tableReference' ), + $node->get_descendant_node( 'whereClause' ), + $node->get_descendant_node( 'orderClause' ), + $node->get_descendant_node( 'simpleLimitClause' ), + ) + ); + + $update_nodes = array(); + foreach ( $node->get_children() as $child ) { + $update_nodes[] = $child; + if ( + $child instanceof WP_Parser_Node + && 'updateList' === $child->rule_name + ) { + // Skip WHERE, ORDER BY, and LIMIT. + break; + } + } + $query = $this->translate_sequence( $update_nodes ) + . ' WHERE rowid IN ( ' . $subquery . ' )'; + } else { + $query = $this->translate( $node ); + } + $this->execute_sqlite_query( $query ); + $this->set_result_from_affected_rows(); + } + private function translate( $ast ) { if ( null === $ast ) { return null; @@ -890,6 +936,9 @@ private function translate_token( WP_MySQL_Token $token ) { private function translate_sequence( array $nodes, string $separator = ' ' ): string { $parts = array(); foreach ( $nodes as $node ) { + if ( null === $node ) { + continue; + } $parts[] = $this->translate( $node ); } return implode( $separator, $parts ); From 797c3b78f4035f9da4262be75f55190e989a92a5 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Tue, 26 Nov 2024 18:24:34 +0100 Subject: [PATCH 12/36] Handle specifics of the CREATE TABLE statement --- tests/WP_SQLite_Driver_Translation_Tests.php | 84 ++++++++- .../sqlite-ast/class-wp-sqlite-driver.php | 165 +++++++++++++++++- 2 files changed, 239 insertions(+), 10 deletions(-) diff --git a/tests/WP_SQLite_Driver_Translation_Tests.php b/tests/WP_SQLite_Driver_Translation_Tests.php index 1d7523b9..ca41765e 100644 --- a/tests/WP_SQLite_Driver_Translation_Tests.php +++ b/tests/WP_SQLite_Driver_Translation_Tests.php @@ -15,10 +15,19 @@ class WP_SQLite_Driver_Translation_Tests extends TestCase { */ private static $grammar; + /** + * @var WP_SQLite_Driver + */ + private $driver; + public static function setUpBeforeClass(): void { self::$grammar = new WP_Parser_Grammar( include self::GRAMMAR_PATH ); } + public function setUp(): void { + $this->driver = new WP_SQLite_Driver( new PDO( 'sqlite::memory:' ) ); + } + public function testSelect(): void { $this->assertQuery( 'SELECT 1', @@ -207,10 +216,74 @@ public function testCreateTable(): void { 'CREATE TABLE t (id INT NOT NULL PRIMARY KEY AUTO_INCREMENT)' ); + // ENGINE is not supported in SQLite. + $this->assertQuery( + 'CREATE TABLE "t" ( "id" INTEGER )', + 'CREATE TABLE t (id INT) ENGINE=InnoDB' + ); + + /* + * PRIMARY KEY without AUTOINCREMENT: + * In this case, integer must be represented as INT, not INTEGER. SQLite + * treats "INTEGER PRIMARY KEY" as an alias for ROWID, causing unintended + * auto-increment-like behavior for a non-autoincrement column. + * + * See: + * https://www.sqlite.org/lang_createtable.html#rowids_and_the_integer_primary_key + */ + $this->assertQuery( + 'CREATE TABLE "t" ( "id" INT PRIMARY KEY )', + 'CREATE TABLE t (id INT PRIMARY KEY)' + ); + + // With AUTOINCREMENT, we expect "INTEGER". + $this->assertQuery( + 'CREATE TABLE "t" ( "id" INTEGER PRIMARY KEY AUTOINCREMENT )', + 'CREATE TABLE t (id INT PRIMARY KEY AUTO_INCREMENT)' + ); + + // In SQLite, PRIMARY KEY must come before AUTOINCREMENT. + $this->assertQuery( + 'CREATE TABLE "t" ( "id" INTEGER PRIMARY KEY AUTOINCREMENT )', + 'CREATE TABLE t (id INT AUTO_INCREMENT PRIMARY KEY)' + ); + + // In SQLite, AUTOINCREMENT cannot be specified separately from PRIMARY KEY. + $this->assertQuery( + 'CREATE TABLE "t" ( "id" INTEGER PRIMARY KEY AUTOINCREMENT )', + 'CREATE TABLE t (id INT AUTO_INCREMENT, PRIMARY KEY(id))' + ); + + // IF NOT EXISTS. $this->assertQuery( 'CREATE TABLE IF NOT EXISTS "t" ( "id" INTEGER )', 'CREATE TABLE IF NOT EXISTS t (id INT)' ); + + // CREATE TABLE AS SELECT ... + $this->assertQuery( + 'CREATE TABLE "t1" AS SELECT * FROM "t2"', + 'CREATE TABLE t1 AS SELECT * FROM t2' + ); + + // CREATE TABLE SELECT ... + // The "AS" keyword is optional in MySQL, but required in SQLite. + $this->assertQuery( + 'CREATE TABLE "t1" AS SELECT * FROM "t2"', + 'CREATE TABLE t1 SELECT * FROM t2' + ); + + // TEMPORARY. + $this->assertQuery( + 'CREATE TEMPORARY TABLE "t" ( "id" INTEGER )', + 'CREATE TEMPORARY TABLE t (id INT)' + ); + + // TEMPORARY & IF NOT EXISTS. + $this->assertQuery( + 'CREATE TEMPORARY TABLE IF NOT EXISTS "t" ( "id" INTEGER )', + 'CREATE TEMPORARY TABLE IF NOT EXISTS t (id INT)' + ); } public function testDataTypes(): void { @@ -324,18 +397,19 @@ public function testSystemVariables(): void { } private function assertQuery( $expected, string $query ): void { - $driver = new WP_SQLite_Driver( new PDO( 'sqlite::memory:' ) ); - $driver->query( $query ); + $this->driver->query( $query ); // Check for SQLite syntax errors. // This ensures that invalid SQLite syntax will always fail, even if it // was the expected result. It prevents us from using wrong assertions. - $error = $driver->get_error_message(); + $error = $this->driver->get_error_message(); if ( $error && preg_match( '/(SQLSTATE\[HY000].+syntax error\.)/i', $error, $matches ) ) { - $this->fail( 'SQLite syntax error: ' . $matches[1] ); + $this->fail( + sprintf( "SQLite syntax error: %s\nMySQL query: %s", $matches[1], $query ) + ); } - $executed_queries = array_column( $driver->executed_sqlite_queries, 'sql' ); + $executed_queries = array_column( $this->driver->executed_sqlite_queries, 'sql' ); // Remove BEGIN and COMMIT/ROLLBACK queries. if ( count( $executed_queries ) > 2 ) { diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index e6938949..3858efa4 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -780,9 +780,7 @@ private function execute_mysql_query( WP_Parser_Node $ast ) { $subtree = $ast->get_child_node(); switch ( $subtree->rule_name ) { case 'createTable': - $query = $this->translate( $ast ); - $this->execute_sqlite_query( $query ); - $this->set_result_from_affected_rows(); + $this->execute_create_table_statement( $ast ); break; default: throw new Exception( @@ -845,6 +843,97 @@ private function execute_update_statement( WP_Parser_Node $node ): void { $this->set_result_from_affected_rows(); } + private function execute_create_table_statement( WP_Parser_Node $node ): void { + $element_list = $node->get_descendant_node( 'tableElementList' ); + if ( null === $element_list ) { + $query = $this->translate( $node ); + $this->execute_sqlite_query( $query ); + $this->set_result_from_affected_rows(); + return; + } + + /* + * We need to handle some differences between MySQL and SQLite: + * + * 1. Inline index definitions: + * + * In MySQL, we can define an index inline with a column definition. + * In SQLite, we need to define indexes separately, using extra queries. + * + * 2. Column and constraint definition order: + * + * In MySQL, column and constraint definitions can be arbitrarily mixed. + * In SQLite, column definitions must come first, followed by constraints. + * + * 2. Auto-increment: + * + * In MySQL, there can at most one AUTO_INCREMENT column, and it must be + * a PRIMARY KEY, or the first column in a multi-column KEY. + * + * In SQLite, there can at most one AUTOINCREMENT column, and it must be + * a PRIMARY KEY, defined inline on a single column. + * + * Therefore, the following valid MySQL construct is not supported: + * CREATE TABLE t ( a INT AUTO_INCREMENT, b INT, PRIMARY KEY (a, b) ); + * @TODO: Support it with a single-column PK and a multi-column UNIQUE KEY. + */ + + // Collect column, index, and constraint nodes. + $columns = array(); + $constraints = array(); + $indexes = array(); + $has_autoincrement = false; + $primary_key_constraint = null; // Does not include inline PK definition. + + foreach ( $element_list->get_descendant_nodes( 'columnDefinition' ) as $child ) { + if ( null !== $child->get_descendant_token( WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL ) ) { + $has_autoincrement = true; + } + // @TODO: Collect inline index definitions. + $columns[] = $child; + } + + foreach ( $element_list->get_descendant_nodes( 'tableConstraintDef' ) as $child ) { + if ( null !== $child->get_descendant_token( WP_MySQL_Lexer::PRIMARY_SYMBOL ) ) { + $primary_key_constraint = $child; + } else { + $constraints[] = $child; + } + } + + /* + * If we have a PRIMARY KEY constraint: + * 1. Without auto-increment, we can put it back to the list of constraints. + * 2. With auto-increment, we need to later move it to the column definition. + */ + if ( null !== $primary_key_constraint ) { + if ( ! $has_autoincrement ) { + $constraints[] = $primary_key_constraint; + } elseif ( count( $primary_key_constraint->get_descendant_nodes( 'keyPart' ) ) > 1 ) { + throw $this->not_supported_exception( + 'Composite primary key with AUTO_INCREMENT' + ); + } + } + + $query_parts = array( 'CREATE' ); + foreach ( $node->get_child_node()->get_children() as $child ) { + if ( $child instanceof WP_Parser_Node && 'tableElementList' === $child->rule_name ) { + $query_parts[] = $this->translate_sequence( array_merge( $columns, $constraints ), ' , ' ); + } else { + $part = $this->translate( $child ); + if ( null !== $part ) { + $query_parts[] = $part; + } + } + } + + // @TODO: Execute queries for inline index definitions. + + $this->execute_sqlite_query( implode( ' ', $query_parts ) ); + $this->set_result_from_affected_rows(); + } + private function translate( $ast ) { if ( null === $ast ) { return null; @@ -915,6 +1004,64 @@ private function translate( $ast ) { // When we have no value, it's reasonable to use NULL. return 'NULL'; + case 'fieldDefinition': + /* + * In SQLite, there is the a quirk for backward compatibility: + * 1. INTEGER PRIMARY KEY creates an alias of ROWID. + * 2. INT PRIMARY KEY will not alias of ROWID. + * + * Therefore, we want to: + * 1. Use INTEGER PRIMARY KEY for when we have AUTOINCREMENT. + * 2. Use INT PRIMARY KEY otherwise. + */ + $has_primary_key = $ast->get_descendant_token( WP_MySQL_Lexer::KEY_SYMBOL ) !== null; + $has_autoincrement = $ast->get_descendant_token( WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL ) !== null; + $children = $ast->get_children(); + $data_type_node = array_shift( $children ); + $data_type = $this->translate( $data_type_node ); + if ( $has_primary_key && 'INTEGER' === $data_type ) { + $data_type = $has_autoincrement ? 'INTEGER' : 'INT'; + } + + $attributes = $this->translate_sequence( $children ); + $definition = $data_type . ( null === $attributes ? '' : " $attributes" ); + + /* + * In SQLite, AUTOINCREMENT must always be preceded by PRIMARY KEY. + * Therefore, we remove both PRIMARY KEY and AUTOINCREMENT from + * column attributes, and append them here in SQLite-friendly way. + */ + if ( $has_autoincrement ) { + return $definition . ' PRIMARY KEY AUTOINCREMENT'; + } elseif ( $has_primary_key ) { + return $definition . ' PRIMARY KEY'; + } + return $definition; + case 'columnAttribute': + case 'gcolAttribute': + /* + * Remove PRIMARY KEY and AUTOINCREMENT from the column attributes. + * They are handled in the "fieldDefinition" node. + */ + if ( $ast->has_child_token( WP_MySQL_Lexer::KEY_SYMBOL ) ) { + return null; + } + if ( $ast->has_child_token( WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL ) ) { + return null; + } + return $this->translate_sequence( $ast->get_children() ); + case 'createTableOptions': + return $this->translate_sequence( $ast->get_children(), ', ' ); + case 'createTableOption': + if ( $ast->get_child_token( WP_MySQL_Lexer::ENGINE_SYMBOL ) ) { + return null; + } + return $this->translate_sequence( $ast->get_children() ); + case 'duplicateAsQueryExpression': + // @TODO: How to handle IGNORE/REPLACE? + + // The "AS" keyword is optional in MySQL, but required in SQLite. + return 'AS ' . $this->translate( $ast->get_child_node() ); default: return $this->translate_sequence( $ast->get_children() ); } @@ -933,13 +1080,21 @@ private function translate_token( WP_MySQL_Token $token ) { } } - private function translate_sequence( array $nodes, string $separator = ' ' ): string { + private function translate_sequence( array $nodes, string $separator = ' ' ): ?string { $parts = array(); foreach ( $nodes as $node ) { if ( null === $node ) { continue; } - $parts[] = $this->translate( $node ); + + $translated = $this->translate( $node ); + if ( null === $translated ) { + continue; + } + $parts[] = $translated; + } + if ( 0 === count( $parts ) ) { + return null; } return implode( $separator, $parts ); } From 647eaae62a9e82f09116c7f132021504b375c5fd Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Mon, 2 Dec 2024 17:04:33 +0100 Subject: [PATCH 13/36] Add basic ALTER TABLE support --- tests/WP_SQLite_Driver_Translation_Tests.php | 49 ++++++++++ .../sqlite-ast/class-wp-sqlite-driver.php | 92 +++++++++++++++++++ 2 files changed, 141 insertions(+) diff --git a/tests/WP_SQLite_Driver_Translation_Tests.php b/tests/WP_SQLite_Driver_Translation_Tests.php index ca41765e..1da6334b 100644 --- a/tests/WP_SQLite_Driver_Translation_Tests.php +++ b/tests/WP_SQLite_Driver_Translation_Tests.php @@ -286,6 +286,55 @@ public function testCreateTable(): void { ); } + public function testAlterTable(): void { + // Prepare a real table, so we can test multi-operation alter statements. + // Otherwise, we'd hit and exception and rollback after the first query. + $this->assertQuery( + 'CREATE TABLE "t" ( "id" INTEGER PRIMARY KEY AUTOINCREMENT )', + 'CREATE TABLE t (id INT PRIMARY KEY AUTO_INCREMENT)' + ); + + // ADD COLUMN. + $this->assertQuery( + 'ALTER TABLE "t" ADD COLUMN "a" INTEGER', + 'ALTER TABLE t ADD a INT' + ); + + // ADD COLUMN with multiple columns. + $this->assertQuery( + array( + 'ALTER TABLE "t" ADD COLUMN "b" INTEGER', + 'ALTER TABLE "t" ADD COLUMN "c" TEXT', + 'ALTER TABLE "t" ADD COLUMN "d" INTEGER', + ), + 'ALTER TABLE t ADD b INT, ADD c TEXT, ADD d BOOL' + ); + + // DROP COLUMN. + $this->assertQuery( + 'ALTER TABLE "t" DROP COLUMN "a"', + 'ALTER TABLE t DROP a' + ); + + // DROP COLUMN with multiple columns. + $this->assertQuery( + array( + 'ALTER TABLE "t" DROP COLUMN "b"', + 'ALTER TABLE "t" DROP COLUMN "c"', + ), + 'ALTER TABLE t DROP b, DROP c' + ); + + // ADD COLUMN and DROP COLUMN combined. + $this->assertQuery( + array( + 'ALTER TABLE "t" ADD COLUMN "a" INTEGER', + 'ALTER TABLE "t" DROP COLUMN "d"', + ), + 'ALTER TABLE t ADD a INT, DROP d' + ); + } + public function testDataTypes(): void { // Numeric data types. $this->assertQuery( diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 3858efa4..0cb250a2 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -792,6 +792,36 @@ private function execute_mysql_query( WP_Parser_Node $ast ) { ); } break; + case 'alterStatement': + $this->query_type = 'ALTER'; + $subtree = $ast->get_child_node(); + switch ( $subtree->rule_name ) { + case 'alterTable': + $this->execute_alter_table_statement( $ast ); + break; + default: + throw new Exception( + sprintf( + 'Unsupported statement type: "%s" > "%s"', + $ast->rule_name, + $subtree->rule_name + ) + ); + } + break; + case 'dropStatement': + $this->query_type = 'DROP'; + $query = $this->translate( $ast ); + $this->execute_sqlite_query( $query ); + $this->set_result_from_affected_rows(); + break; + case 'setStatement': + /* + * It would be lovely to support at least SET autocommit, + * but I don't think that is even possible with SQLite. + */ + $this->results = 0; + break; default: throw new Exception( sprintf( 'Unsupported statement type: "%s"', $ast->rule_name ) ); } @@ -934,6 +964,68 @@ private function execute_create_table_statement( WP_Parser_Node $node ): void { $this->set_result_from_affected_rows(); } + private function execute_alter_table_statement( WP_Parser_Node $node ): void { + $table_name = $this->translate( $node->get_descendant_node( 'tableRef' ) ); + $actions = $node->get_descendant_nodes( 'alterListItem' ); + + /* + * SQLite supports only a small subset of MySQL ALTER TABLE statement. + * We need to handle some differences and emulate some operations: + * + * 1. Multiple operations in a single ALTER TABLE statement. + * + * SQLite doesn't support multiple operations in a single ALTER TABLE + * statement. We need to execute each operation as a separate query. + * + * 2. ADD COLUMN in SQLite doesn't support some valid MySQL constructs: + * + * - Adding a column with PRIMARY KEY or UNIQUE constraint. + * - Adding a column with AUTOINCREMENT. + * - Adding a column with CURRENT_TIME, CURRENT_DATE, CURRENT_TIMESTAMP, + * or an expression in parentheses as a default value. + * - Adding a NOT NULL column without a default value when the table is + * not empty. In MySQL, this depends on the data type and SQL mode. + * + * @TODO: Address these nuances. + */ + foreach ( $actions as $action ) { + $token = $action->get_child_token(); + + // ADD column/constraint. + if ( WP_MySQL_Lexer::ADD_SYMBOL === $token->id ) { + // ADD COLUMN. + $field_definition = $action->get_descendant_node( 'fieldDefinition' ); + if ( null !== $field_definition ) { + $field_name = $this->translate( $action->get_child_node( 'identifier' ) ); + $field = $this->translate( $field_definition ); + $this->execute_sqlite_query( + sprintf( 'ALTER TABLE %s ADD COLUMN %s %s', $table_name, $field_name, $field ) + ); + } + + // ADD CONSTRAINT. + $constraint = $action->get_descendant_node( 'tableConstraintDef' ); + if ( null !== $constraint ) { + $constraint_name = $this->translate( $constraint->get_child_node( 'identifier' ) ); + $constraint = $this->translate( $constraint ); + $this->execute_sqlite_query( + sprintf( 'ALTER TABLE %s ADD CONSTRAINT %s %s', $table_name, $constraint_name, $constraint ) + ); + } + } elseif ( WP_MySQL_Lexer::DROP_SYMBOL === $token->id ) { + // DROP COLUMN. + $field_name = $this->translate( $action->get_child_node( 'columnInternalRef' ) ); + if ( null !== $field_name ) { + $this->execute_sqlite_query( + sprintf( 'ALTER TABLE %s DROP COLUMN %s', $table_name, $field_name ) + ); + } + } + } + + $this->set_result_from_affected_rows(); + } + private function translate( $ast ) { if ( null === $ast ) { return null; From c5156054c23790e50e86574068d4721d52bbc13e Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Mon, 2 Dec 2024 17:18:01 +0100 Subject: [PATCH 14/36] Fix MySQL syntax errors in tests --- tests/WP_SQLite_Driver_Tests.php | 22 +++++++++++----------- 1 file changed, 11 insertions(+), 11 deletions(-) diff --git a/tests/WP_SQLite_Driver_Tests.php b/tests/WP_SQLite_Driver_Tests.php index bee50ae6..65c3611a 100644 --- a/tests/WP_SQLite_Driver_Tests.php +++ b/tests/WP_SQLite_Driver_Tests.php @@ -247,7 +247,7 @@ public function testUpdateWithoutWhereButWithLimit() { public function testCastAsBinary() { $this->assertQuery( // Use a confusing alias to make sure it replaces only the correct token - "SELECT CAST('ABC' AS BINARY) as binary;" + "SELECT CAST('ABC' AS BINARY) as `binary`;" ); $results = $this->engine->get_query_results(); $this->assertCount( 1, $results ); @@ -470,7 +470,7 @@ public function testShowCreateTableWithCorrectDefaultValues() { "CREATE TABLE _tmp__table ( ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, default_empty_string VARCHAR(255) default '', - null_no_default VARCHAR(255), + null_no_default VARCHAR(255) );" ); @@ -596,7 +596,7 @@ public function testShowTableStatusFrom() { ); $this->assertQuery( - "SHOW TABLE STATUS FROM 'mydb';" + 'SHOW TABLE STATUS FROM mydb;' ); $this->assertCount( @@ -619,7 +619,7 @@ public function testShowTableStatusIn() { ); $this->assertQuery( - "SHOW TABLE STATUS IN 'mydb';" + 'SHOW TABLE STATUS IN mydb;' ); $this->assertCount( @@ -649,7 +649,7 @@ public function testShowTableStatusInTwoTables() { );" ); $this->assertQuery( - "SHOW TABLE STATUS IN 'mydb';" + 'SHOW TABLE STATUS IN mydb;' ); $this->assertCount( @@ -807,7 +807,7 @@ public function testCreateTableWithTrailingComma() { $result = $this->assertQuery( 'CREATE TABLE wptests_users ( ID bigint(20) unsigned NOT NULL auto_increment, - PRIMARY KEY (ID), + PRIMARY KEY (ID) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci' ); $this->assertEquals( '', $this->engine->get_error_message() ); @@ -818,7 +818,7 @@ public function testCreateTableSpatialIndex() { $result = $this->assertQuery( 'CREATE TABLE wptests_users ( ID bigint(20) unsigned NOT NULL auto_increment, - UNIQUE KEY (ID), + UNIQUE KEY (ID) )' ); $this->assertEquals( '', $this->engine->get_error_message() ); @@ -832,7 +832,7 @@ public function testCreateTableWithMultiValueColumnTypeModifiers() { decimal_column DECIMAL(10,2) NOT NULL DEFAULT 0, float_column FLOAT(10,2) NOT NULL DEFAULT 0, enum_column ENUM('a', 'b', 'c') NOT NULL DEFAULT 'a', - PRIMARY KEY (ID), + PRIMARY KEY (ID) )" ); $this->assertEquals( '', $this->engine->get_error_message() ); @@ -2716,7 +2716,7 @@ public function testZeroPlusStringToFloatComparison() { public function testCalcFoundRows() { $result = $this->assertQuery( "CREATE TABLE wptests_dummy ( - ID INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, user_login TEXT NOT NULL default '' );" ); @@ -3030,7 +3030,7 @@ public function testTranslateLikeBinaryAndGlob() { // Create a temporary table for testing $this->assertQuery( "CREATE TABLE _tmp_table ( - ID INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, name varchar(20) NOT NULL default '' );" ); @@ -3114,7 +3114,7 @@ public function testTranslateLikeBinaryAndGlob() { public function testOnConflictReplace() { $this->assertQuery( "CREATE TABLE _tmp_table ( - ID INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, name varchar(20) NOT NULL default 'default-value', unique_name varchar(20) NOT NULL default 'unique-default-value', inline_unique_name varchar(20) NOT NULL default 'inline-unique-default-value', From 1e5c3118f93c50e4e83af7aa6b2fb2f864e0e1d6 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 19 Dec 2024 10:11:38 +0100 Subject: [PATCH 15/36] Introduce information schema builder & create information schema tables --- tests/WP_SQLite_Driver_Tests.php | 3 +- .../sqlite-ast/class-wp-sqlite-driver.php | 24 +- ...s-wp-sqlite-information-schema-builder.php | 250 ++++++++++++++++++ 3 files changed, 274 insertions(+), 3 deletions(-) create mode 100644 wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php diff --git a/tests/WP_SQLite_Driver_Tests.php b/tests/WP_SQLite_Driver_Tests.php index 65c3611a..cd3c3ed7 100644 --- a/tests/WP_SQLite_Driver_Tests.php +++ b/tests/WP_SQLite_Driver_Tests.php @@ -2,6 +2,7 @@ require_once __DIR__ . '/WP_SQLite_Translator_Tests.php'; require_once __DIR__ . '/../wp-includes/sqlite-ast/class-wp-sqlite-driver.php'; +require_once __DIR__ . '/../wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php'; require_once __DIR__ . '/../wp-includes/sqlite-ast/class-wp-sqlite-expression.php'; require_once __DIR__ . '/../wp-includes/sqlite-ast/class-wp-sqlite-token-factory.php'; require_once __DIR__ . '/../wp-includes/sqlite-ast/class-wp-sqlite-token.php'; @@ -39,7 +40,7 @@ public static function setUpBeforeClass(): void { public function setUp(): void { $this->sqlite = new PDO( 'sqlite::memory:' ); - $this->engine = new WP_SQLite_Driver( $this->sqlite ); + $this->engine = new WP_SQLite_Driver( 'wp', $this->sqlite ); $this->engine->query( "CREATE TABLE _options ( ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 0cb250a2..7bd37d03 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -94,6 +94,13 @@ class WP_SQLite_Driver { */ private static $grammar; + /** + * The database name. In WordPress, the value of DB_NAME. + * + * @var string + */ + private $db_name; + /** * Class variable to reference to the PDO instance. * @@ -247,6 +254,11 @@ class WP_SQLite_Driver { */ private $last_sqlite_error; + /** + * @var WP_SQLite_Information_Schema_Builder + */ + private $information_schema_builder; + /** * Constructor. * @@ -254,9 +266,11 @@ class WP_SQLite_Driver { * Don't use parent::__construct() because this class does not only returns * PDO instance but many others jobs. * - * @param PDO $pdo The PDO object. + * @param string $db_name The database name. In WordPress, the value of DB_NAME. + * @param PDO|null $pdo The PDO object. */ - public function __construct( $pdo = null ) { + public function __construct( string $db_name, ?PDO $pdo = null ) { + $this->db_name = $db_name; if ( ! $pdo ) { if ( ! is_file( FQDB ) ) { $this->prepare_directory(); @@ -313,6 +327,12 @@ public function __construct( $pdo = null ) { $this->pdo = $pdo; + $this->information_schema_builder = new WP_SQLite_Information_Schema_Builder( + $this->db_name, + array( $this, 'execute_sqlite_query' ) + ); + $this->information_schema_builder->ensure_information_schema_tables(); + // Load MySQL grammar. if ( null === self::$grammar ) { self::$grammar = new WP_Parser_Grammar( require self::GRAMMAR_PATH ); diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php new file mode 100644 index 00000000..981529ab --- /dev/null +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -0,0 +1,250 @@ +db_name = $db_name; + $this->query_callback = $query_callback; + } + + /** + * Ensure that the supported information schema tables exist in the SQLite + * database. Tables that are missing will be created. + */ + public function ensure_information_schema_tables(): void { + foreach ( self::CREATE_INFORMATION_SCHEMA_QUERIES as $query ) { + $this->query( $query ); + } + } + + /** + * @param string $query + * @param array $params + * @return PDOStatement + */ + private function query( string $query, array $params = array() ) { + return ( $this->query_callback )( $query, $params ); + } +} From b617ef9a74381486ab39674214b5c14e282ff0c0 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 19 Dec 2024 10:49:21 +0100 Subject: [PATCH 16/36] Record CREATE TABLE table info in information schema --- ...s-wp-sqlite-information-schema-builder.php | 147 +++++++++++++++--- 1 file changed, 126 insertions(+), 21 deletions(-) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php index 981529ab..f31779d7 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -4,6 +4,8 @@ namespace WIP; use PDOStatement; +use WP_MySQL_Lexer; +use WP_Parser_Node; class WP_SQLite_Information_Schema_Builder { /** @@ -28,28 +30,28 @@ class WP_SQLite_Information_Schema_Builder { const CREATE_INFORMATION_SCHEMA_QUERIES = array( // TABLES "CREATE TABLE IF NOT EXISTS _mysql_information_schema_tables ( - TABLE_CATALOG TEXT NOT NULL DEFAULT 'def', - TABLE_SCHEMA TEXT NOT NULL, - TABLE_NAME TEXT NOT NULL, - TABLE_TYPE TEXT NOT NULL, - ENGINE TEXT NOT NULL, - VERSION INTEGER NOT NULL DEFAULT 10, - ROW_FORMAT TEXT NOT NULL, - TABLE_ROWS INTEGER NOT NULL DEFAULT 0, - AVG_ROW_LENGTH INTEGER NOT NULL DEFAULT 0, - DATA_LENGTH INTEGER NOT NULL DEFAULT 0, - MAX_DATA_LENGTH INTEGER NOT NULL DEFAULT 0, - INDEX_LENGTH INTEGER NOT NULL DEFAULT 0, - DATA_FREE INTEGER NOT NULL DEFAULT 0, - AUTO_INCREMENT INTEGER, - CREATE_TIME TEXT NOT NULL + TABLE_CATALOG TEXT NOT NULL DEFAULT 'def', -- always 'def' + TABLE_SCHEMA TEXT NOT NULL, -- database name + TABLE_NAME TEXT NOT NULL, -- table name + TABLE_TYPE TEXT NOT NULL, -- 'BASE TABLE' or 'VIEW' + ENGINE TEXT NOT NULL, -- storage engine + VERSION INTEGER NOT NULL DEFAULT 10, -- unused, in MySQL 8 hardcoded to 10 + ROW_FORMAT TEXT NOT NULL, -- row storage format @TODO - implement + TABLE_ROWS INTEGER NOT NULL DEFAULT 0, -- not implemented + AVG_ROW_LENGTH INTEGER NOT NULL DEFAULT 0, -- not implemented + DATA_LENGTH INTEGER NOT NULL DEFAULT 0, -- not implemented + MAX_DATA_LENGTH INTEGER NOT NULL DEFAULT 0, -- not implemented + INDEX_LENGTH INTEGER NOT NULL DEFAULT 0, -- not implemented + DATA_FREE INTEGER NOT NULL DEFAULT 0, -- not implemented + AUTO_INCREMENT INTEGER, -- not implemented + CREATE_TIME TEXT NOT NULL -- table creation timestamp DEFAULT CURRENT_TIMESTAMP, - UPDATE_TIME TEXT, - CHECK_TIME TEXT, - TABLE_COLLATION TEXT NOT NULL, - CHECKSUM INTEGER, - CREATE_OPTIONS TEXT, - TABLE_COMMENT TEXT NOT NULL DEFAULT '' + UPDATE_TIME TEXT, -- table update time + CHECK_TIME TEXT, -- not implemented + TABLE_COLLATION TEXT NOT NULL, -- table collation + CHECKSUM INTEGER, -- not implemented + CREATE_OPTIONS TEXT, -- extra CREATE TABLE options + TABLE_COMMENT TEXT NOT NULL DEFAULT '' -- comment ) STRICT", // COLUMNS @@ -239,6 +241,109 @@ public function ensure_information_schema_tables(): void { } } + /** + * Analyze CREATE TABLE statement and record data in the information schema. + * + * @param WP_Parser_Node $node AST node representing a CREATE TABLE statement. + */ + public function record_create_table( WP_Parser_Node $node ): void { + $table_name = $this->get_value( $node->get_descendant_node( 'tableName' ) ); + $table_engine = $this->get_table_engine( $node ); + $table_row_format = 'MyISAM' === $table_engine ? 'FIXED' : 'DYNAMIC'; + $table_collation = $this->get_table_collation( $node ); + + // 1. Table. + $this->insert_values( + '_mysql_information_schema_tables', + array( + 'table_schema' => $this->db_name, + 'table_name' => $table_name, + 'table_type' => 'BASE TABLE', + 'engine' => $table_engine, + 'row_format' => $table_row_format, + 'table_collation' => $table_collation, + ) + ); + } + + private function get_table_engine( WP_Parser_Node $node ): string { + $engine_node = $node->get_descendant_node( 'engineRef' ); + if ( null === $engine_node ) { + return 'InnoDB'; + } + + $engine = strtoupper( $this->get_value( $engine_node ) ); + if ( 'INNODB' === $engine ) { + return 'InnoDB'; + } elseif ( 'MYISAM' === $engine ) { + return 'MyISAM'; + } + return $engine; + } + + private function get_table_collation( WP_Parser_Node $node ): string { + $collate_node = $node->get_descendant_node( 'collationName' ); + if ( null === $collate_node ) { + // @TODO: Use default DB collation or DB_CHARSET & DB_COLLATE. + return 'utf8mb4_general_ci'; + } + return strtolower( $this->get_value( $collate_node ) ); + } + + /** + * This is a helper function to get the full unescaped value of a node. + * + * @TODO: This should be done in a more correct way, for names maybe allowing + * descending only a single-child hierarchy, such as these: + * identifier -> pureIdentifier -> IDENTIFIER + * identifier -> pureIdentifier -> BACKTICK_QUOTED_ID + * identifier -> pureIdentifier -> DOUBLE_QUOTED_TEXT + * etc. + * + * For saving "DEFAULT ..." in column definitions, we actually need to + * serialize the whole node, in the case of expressions. This may mean + * implementing an MySQL AST -> string printer. + * + * @param WP_Parser_Node $node + * @return string + */ + private function get_value( WP_Parser_Node $node ): string { + $full_value = ''; + foreach ( $node->get_children() as $child ) { + if ( $child instanceof WP_Parser_Node ) { + $value = $this->get_value( $child ); + } elseif ( WP_MySQL_Lexer::BACK_TICK_QUOTED_ID === $child->id ) { + $value = substr( $child->value, 1, -1 ); + $value = str_replace( '\`', '`', $value ); + $value = str_replace( '``', '`', $value ); + } elseif ( WP_MySQL_Lexer::SINGLE_QUOTED_TEXT === $child->id ) { + $value = $child->value; + $value = substr( $value, 1, -1 ); + $value = str_replace( '\"', '"', $value ); + $value = str_replace( '""', '"', $value ); + } elseif ( WP_MySQL_Lexer::DOUBLE_QUOTED_TEXT === $child->id ) { + $value = $child->value; + $value = substr( $value, 1, -1 ); + $value = str_replace( '\"', '"', $value ); + $value = str_replace( '""', '"', $value ); + } else { + $value = $child->value; + } + $full_value .= $value; + } + return $full_value; + } + + private function insert_values( string $table_name, array $data ): void { + $this->query( + ' + INSERT INTO ' . $table_name . ' (' . implode( ', ', array_keys( $data ) ) . ') + VALUES (' . implode( ', ', array_fill( 0, count( $data ), '?' ) ) . ') + ', + array_values( $data ) + ); + } + /** * @param string $query * @param array $params From dbd50e60a48eff52ca187259b7a4f3590edafb2c Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 19 Dec 2024 14:17:02 +0100 Subject: [PATCH 17/36] Record CREATE TABLE column info in information schema --- ...s-wp-sqlite-information-schema-builder.php | 650 +++++++++++++++++- 1 file changed, 628 insertions(+), 22 deletions(-) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php index f31779d7..419fa804 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -56,28 +56,28 @@ class WP_SQLite_Information_Schema_Builder { // COLUMNS "CREATE TABLE IF NOT EXISTS _mysql_information_schema_columns ( - TABLE_CATALOG TEXT NOT NULL DEFAULT 'def', - TABLE_SCHEMA TEXT NOT NULL, - TABLE_NAME TEXT NOT NULL, - COLUMN_NAME TEXT NOT NULL, - ORDINAL_POSITION INTEGER NOT NULL, - COLUMN_DEFAULT TEXT, - IS_NULLABLE TEXT NOT NULL, - DATA_TYPE TEXT NOT NULL, - CHARACTER_MAXIMUM_LENGTH INTEGER, - CHARACTER_OCTET_LENGTH INTEGER, - NUMERIC_PRECISION INTEGER, - NUMERIC_SCALE INTEGER, - DATETIME_PRECISION INTEGER, - CHARACTER_SET_NAME TEXT, - COLLATION_NAME TEXT, - COLUMN_TYPE TEXT NOT NULL, - COLUMN_KEY TEXT NOT NULL DEFAULT '', - EXTRA TEXT NOT NULL DEFAULT '', - PRIVILEGES TEXT NOT NULL, - COLUMN_COMMENT TEXT NOT NULL DEFAULT '', - GENERATION_EXPRESSION TEXT NOT NULL DEFAULT '', - SRS_ID INTEGER + TABLE_CATALOG TEXT NOT NULL DEFAULT 'def', -- always 'def' + TABLE_SCHEMA TEXT NOT NULL, -- database name + TABLE_NAME TEXT NOT NULL, -- table name + COLUMN_NAME TEXT NOT NULL, -- column name + ORDINAL_POSITION INTEGER NOT NULL, -- column position + COLUMN_DEFAULT TEXT, -- default value, NULL for both NULL and none + IS_NULLABLE TEXT NOT NULL, -- 'YES' or 'NO' + DATA_TYPE TEXT NOT NULL, -- data type (without length, precision, etc.) + CHARACTER_MAXIMUM_LENGTH INTEGER, -- max length for string columns in characters + CHARACTER_OCTET_LENGTH INTEGER, -- max length for string columns in bytes + NUMERIC_PRECISION INTEGER, -- number precision for numeric columns + NUMERIC_SCALE INTEGER, -- number scale for numeric columns + DATETIME_PRECISION INTEGER, -- fractional seconds precision for temporal columns + CHARACTER_SET_NAME TEXT, -- charset for string columns + COLLATION_NAME TEXT, -- collation for string columns + COLUMN_TYPE TEXT NOT NULL, -- full data type (with length, precision, etc.) + COLUMN_KEY TEXT NOT NULL DEFAULT '', -- if column is indexed ('', 'PRI', 'UNI', 'MUL') + EXTRA TEXT NOT NULL DEFAULT '', -- AUTO_INCREMENT, VIRTUAL, STORED, etc. + PRIVILEGES TEXT NOT NULL, -- not implemented + COLUMN_COMMENT TEXT NOT NULL DEFAULT '', -- comment + GENERATION_EXPRESSION TEXT NOT NULL DEFAULT '', -- expression for generated columns + SRS_ID INTEGER -- not implemented ) STRICT", // VIEWS @@ -199,6 +199,125 @@ class WP_SQLite_Information_Schema_Builder { ) STRICT', ); + /** + * A mapping of MySQL tokens to normalized MySQL data types. + * This is used to store column data types in the information schema. + */ + const TOKEN_TO_TYPE_MAP = array( + WP_MySQL_Lexer::INT_SYMBOL => 'int', + WP_MySQL_Lexer::TINYINT_SYMBOL => 'tinyint', + WP_MySQL_Lexer::SMALLINT_SYMBOL => 'smallint', + WP_MySQL_Lexer::MEDIUMINT_SYMBOL => 'mediumint', + WP_MySQL_Lexer::BIGINT_SYMBOL => 'bigint', + WP_MySQL_Lexer::REAL_SYMBOL => 'double', + WP_MySQL_Lexer::DOUBLE_SYMBOL => 'double', + WP_MySQL_Lexer::FLOAT_SYMBOL => 'float', + WP_MySQL_Lexer::DECIMAL_SYMBOL => 'decimal', + WP_MySQL_Lexer::NUMERIC_SYMBOL => 'decimal', + WP_MySQL_Lexer::FIXED_SYMBOL => 'decimal', + WP_MySQL_Lexer::BIT_SYMBOL => 'bit', + WP_MySQL_Lexer::BOOL_SYMBOL => 'tinyint', + WP_MySQL_Lexer::BOOLEAN_SYMBOL => 'tinyint', + WP_MySQL_Lexer::BINARY_SYMBOL => 'binary', + WP_MySQL_Lexer::VARBINARY_SYMBOL => 'varbinary', + WP_MySQL_Lexer::YEAR_SYMBOL => 'year', + WP_MySQL_Lexer::DATE_SYMBOL => 'date', + WP_MySQL_Lexer::TIME_SYMBOL => 'time', + WP_MySQL_Lexer::TIMESTAMP_SYMBOL => 'timestamp', + WP_MySQL_Lexer::DATETIME_SYMBOL => 'datetime', + WP_MySQL_Lexer::TINYBLOB_SYMBOL => 'tinyblob', + WP_MySQL_Lexer::BLOB_SYMBOL => 'blob', + WP_MySQL_Lexer::MEDIUMBLOB_SYMBOL => 'mediumblob', + WP_MySQL_Lexer::LONGBLOB_SYMBOL => 'longblob', + WP_MySQL_Lexer::TINYTEXT_SYMBOL => 'tinytext', + WP_MySQL_Lexer::TEXT_SYMBOL => 'text', + WP_MySQL_Lexer::MEDIUMTEXT_SYMBOL => 'mediumtext', + WP_MySQL_Lexer::LONGTEXT_SYMBOL => 'longtext', + WP_MySQL_Lexer::ENUM_SYMBOL => 'enum', + WP_MySQL_Lexer::SET_SYMBOL => 'set', + WP_MySQL_Lexer::SERIAL_SYMBOL => 'bigint', + WP_MySQL_Lexer::GEOMETRY_SYMBOL => 'geometry', + WP_MySQL_Lexer::GEOMETRYCOLLECTION_SYMBOL => 'geomcollection', + WP_MySQL_Lexer::POINT_SYMBOL => 'point', + WP_MySQL_Lexer::MULTIPOINT_SYMBOL => 'multipoint', + WP_MySQL_Lexer::LINESTRING_SYMBOL => 'linestring', + WP_MySQL_Lexer::MULTILINESTRING_SYMBOL => 'multilinestring', + WP_MySQL_Lexer::POLYGON_SYMBOL => 'polygon', + WP_MySQL_Lexer::MULTIPOLYGON_SYMBOL => 'multipolygon', + WP_MySQL_Lexer::JSON_SYMBOL => 'json', + ); + + /** + * The default collation for each MySQL charset. + * This is needed as collation is not always specified in a query. + */ + const CHARSET_DEFAULT_COLLATION_MAP = array( + 'armscii8' => 'armscii8_general_ci', + 'ascii' => 'ascii_general_ci', + 'big5' => 'big5_chinese_ci', + 'binary' => 'binary', + 'cp1250' => 'cp1250_general_ci', + 'cp1251' => 'cp1251_general_ci', + 'cp1256' => 'cp1256_general_ci', + 'cp1257' => 'cp1257_general_ci', + 'cp850' => 'cp850_general_ci', + 'cp852' => 'cp852_general_ci', + 'cp866' => 'cp866_general_ci', + 'cp932' => 'cp932_japanese_ci', + 'dec8' => 'dec8_swedish_ci', + 'eucjpms' => 'eucjpms_japanese_ci', + 'euckr' => 'euckr_korean_ci', + 'gb18030' => 'gb18030_chinese_ci', + 'gb2312' => 'gb2312_chinese_ci', + 'gbk' => 'gbk_chinese_ci', + 'geostd8' => 'geostd8_general_ci', + 'greek' => 'greek_general_ci', + 'hebrew' => 'hebrew_general_ci', + 'hp8' => 'hp8_english_ci', + 'keybcs2' => 'keybcs2_general_ci', + 'koi8r' => 'koi8r_general_ci', + 'koi8u' => 'koi8u_general_ci', + 'latin1' => 'latin1_swedish_ci', + 'latin2' => 'latin2_general_ci', + 'latin5' => 'latin5_turkish_ci', + 'latin7' => 'latin7_general_ci', + 'macce' => 'macce_general_ci', + 'macroman' => 'macroman_general_ci', + 'sjis' => 'sjis_japanese_ci', + 'swe7' => 'swe7_swedish_ci', + 'tis620' => 'tis620_thai_ci', + 'ucs2' => 'ucs2_general_ci', + 'ujis' => 'ujis_japanese_ci', + 'utf16' => 'utf16_general_ci', + 'utf16le' => 'utf16le_general_ci', + 'utf32' => 'utf32_general_ci', + 'utf8' => 'utf8_general_ci', + 'utf8mb4' => 'utf8mb4_general_ci', // @TODO: From MySQL 8.0.1, this is utf8mb4_0900_ai_ci. + ); + + /** + * Maximum number of bytes per character for each charset. + * The map contains only multi-byte charsets. + * Charsets that are not included are single-byte. + */ + const CHARSET_MAX_BYTES_MAP = array( + 'big5' => 2, + 'cp932' => 2, + 'eucjpms' => 3, + 'euckr' => 2, + 'gb18030' => 4, + 'gb2312' => 2, + 'gbk' => 2, + 'sjis' => 2, + 'ucs2' => 2, + 'ujis' => 3, + 'utf16' => 4, + 'utf16le' => 4, + 'utf32' => 4, + 'utf8' => 3, + 'utf8mb4' => 4, + ); + /** * Database name. * @@ -264,6 +383,61 @@ public function record_create_table( WP_Parser_Node $node ): void { 'table_collation' => $table_collation, ) ); + + // 2. Columns. + $column_position = 1; + foreach ( $node->get_descendant_nodes( 'columnDefinition' ) as $column_node ) { + $column_name = $this->get_value( $column_node->get_child_node( 'columnName' ) ); + + // Column definition. + $column_data = $this->extract_column_data( + $table_name, + $column_name, + $column_node, + $column_position + ); + $this->insert_values( '_mysql_information_schema_columns', $column_data ); + $column_position += 1; + } + } + + private function extract_column_data( string $table_name, string $column_name, WP_Parser_Node $node, int $position ): array { + $default = $this->get_column_default( $node ); + $nullable = $this->get_column_nullable( $node ); + $key = $this->get_column_key( $node ); + $extra = $this->get_column_extra( $node ); + $comment = $this->get_column_comment( $node ); + + list ( $data_type, $column_type ) = $this->get_column_data_types( $node ); + list ( $charset, $collation ) = $this->get_column_charset_and_collation( $node, $data_type ); + list ( $char_length, $octet_length ) = $this->get_column_lengths( $node, $data_type, $charset ); + list ( $precision, $scale ) = $this->get_column_numeric_attributes( $node, $data_type ); + $datetime_precision = $this->get_column_datetime_precision( $node, $data_type ); + $generation_expression = $this->get_column_generation_expression( $node ); + + return array( + 'table_schema' => $this->db_name, + 'table_name' => $table_name, + 'column_name' => $column_name, + 'ordinal_position' => $position, + 'column_default' => $default, + 'is_nullable' => $nullable, + 'data_type' => $data_type, + 'character_maximum_length' => $char_length, + 'character_octet_length' => $octet_length, + 'numeric_precision' => $precision, + 'numeric_scale' => $scale, + 'datetime_precision' => $datetime_precision, + 'character_set_name' => $charset, + 'collation_name' => $collation, + 'column_type' => $column_type, + 'column_key' => $key, + 'extra' => $extra, + 'privileges' => 'select,insert,update,references', + 'column_comment' => $comment, + 'generation_expression' => $generation_expression, + 'srs_id' => null, // not implemented + ); } private function get_table_engine( WP_Parser_Node $node ): string { @@ -290,6 +464,438 @@ private function get_table_collation( WP_Parser_Node $node ): string { return strtolower( $this->get_value( $collate_node ) ); } + private function get_column_default( WP_Parser_Node $node ): ?string { + foreach ( $node->get_descendant_nodes( 'columnAttribute' ) as $attr ) { + if ( $attr->has_child_token( WP_MySQL_Lexer::DEFAULT_SYMBOL ) ) { + // @TODO: MySQL seems to normalize default values for numeric + // columns, such as 1.0 to 1, 1e3 to 1000, etc. + return substr( $this->get_value( $attr ), strlen( 'DEFAULT' ) ); + } + } + return null; + } + + private function get_column_nullable( WP_Parser_Node $node ): string { + // SERIAL is an alias for BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE. + $data_type = $node->get_descendant_node( 'dataType' ); + if ( null !== $data_type->get_descendant_token( WP_MySQL_Lexer::SERIAL_SYMBOL ) ) { + return 'NO'; + } + + foreach ( $node->get_descendant_nodes( 'columnAttribute' ) as $attr ) { + // PRIMARY KEY columns are always NOT NULL. + if ( $attr->has_child_token( WP_MySQL_Lexer::KEY_SYMBOL ) ) { + return 'NO'; + } + + // Check for NOT NULL attribute. + if ( + $attr->has_child_token( WP_MySQL_Lexer::NOT_SYMBOL ) + && $attr->has_child_node( 'nullLiteral' ) + ) { + return 'NO'; + } + } + return 'YES'; + } + + private function get_column_key( WP_Parser_Node $column_node ): string { + // 1. PRI: Column is a primary key or its any component. + if ( + null !== $column_node->get_descendant_token( WP_MySQL_Lexer::KEY_SYMBOL ) + ) { + return 'PRI'; + } + + // SERIAL is an alias for BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE. + $data_type = $column_node->get_descendant_node( 'dataType' ); + if ( null !== $data_type->get_descendant_token( WP_MySQL_Lexer::SERIAL_SYMBOL ) ) { + return 'PRI'; + } + + // 2. UNI: Column has UNIQUE constraint. + if ( null !== $column_node->get_descendant_token( WP_MySQL_Lexer::UNIQUE_SYMBOL ) ) { + return 'UNI'; + } + + // 3. MUL: Column has INDEX. + if ( null !== $column_node->get_descendant_token( WP_MySQL_Lexer::INDEX_SYMBOL ) ) { + return 'MUL'; + } + + return ''; + } + + private function get_column_extra( WP_Parser_Node $node ): string { + $extra = ''; + + // SERIAL + $data_type = $node->get_descendant_node( 'dataType' ); + if ( null !== $data_type->get_descendant_token( WP_MySQL_Lexer::SERIAL_SYMBOL ) ) { + return 'auto_increment'; + } + + foreach ( $node->get_descendant_nodes( 'columnAttribute' ) as $attr ) { + if ( $attr->has_child_token( WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL ) ) { + return 'auto_increment'; + } + if ( + $attr->has_child_token( WP_MySQL_Lexer::ON_SYMBOL ) + && $attr->has_child_token( WP_MySQL_Lexer::UPDATE_SYMBOL ) + ) { + return 'on update CURRENT_TIMESTAMP'; + } + } + + if ( $node->get_descendant_token( WP_MySQL_Lexer::VIRTUAL_SYMBOL ) ) { + $extra = 'VIRTUAL GENERATED'; + } elseif ( $node->get_descendant_token( WP_MySQL_Lexer::STORED_SYMBOL ) ) { + $extra = 'STORED GENERATED'; + } + return $extra; + } + + private function get_column_comment( WP_Parser_Node $node ): string { + foreach ( $node->get_descendant_nodes( 'columnAttribute' ) as $attr ) { + if ( $attr->has_child_token( WP_MySQL_Lexer::COMMENT_SYMBOL ) ) { + return $this->get_value( $attr->get_child_node( 'textLiteral' ) ); + } + } + return ''; + } + + private function get_column_data_types( WP_Parser_Node $node ): array { + $type_node = $node->get_descendant_node( 'dataType' ); + $type = $type_node->get_descendant_tokens(); + $token = $type[0]; + + // Normalize types. + if ( isset( self::TOKEN_TO_TYPE_MAP[ $token->id ] ) ) { + $type = self::TOKEN_TO_TYPE_MAP[ $token->id ]; + } elseif ( + // VARCHAR/NVARCHAR + // NCHAR/NATIONAL VARCHAR + // CHAR/CHARACTER/NCHAR VARYING + // NATIONAL CHAR/CHARACTER VARYING + WP_MySQL_Lexer::VARCHAR_SYMBOL === $token->id + || WP_MySQL_Lexer::NVARCHAR_SYMBOL === $token->id + || ( isset( $type[1] ) && WP_MySQL_Lexer::VARCHAR_SYMBOL === $type[1]->id ) + || ( isset( $type[1] ) && WP_MySQL_Lexer::VARYING_SYMBOL === $type[1]->id ) + || ( isset( $type[2] ) && WP_MySQL_Lexer::VARYING_SYMBOL === $type[2]->id ) + ) { + $type = 'varchar'; + } elseif ( + // CHAR, NCHAR, NATIONAL CHAR + WP_MySQL_Lexer::CHAR_SYMBOL === $token->id + || WP_MySQL_Lexer::NCHAR_SYMBOL === $token->id + || isset( $type[1] ) && WP_MySQL_Lexer::CHAR_SYMBOL === $type[1]->id + ) { + $type = 'char'; + } elseif ( + // LONG VARBINARY + WP_MySQL_Lexer::LONG_SYMBOL === $token->id + && isset( $type[1] ) && WP_MySQL_Lexer::VARBINARY_SYMBOL === $type[1]->id + ) { + $type = 'mediumblob'; + } elseif ( + // LONG CHAR/CHARACTER, LONG CHAR/CHARACTER VARYING + WP_MySQL_Lexer::LONG_SYMBOL === $token->id + && isset( $type[1] ) && WP_MySQL_Lexer::CHAR_SYMBOL === $type[1]->id + ) { + $type = 'mediumtext'; + } elseif ( + // LONG VARCHAR + WP_MySQL_Lexer::LONG_SYMBOL === $token->id + && isset( $type[1] ) && WP_MySQL_Lexer::VARCHAR_SYMBOL === $type[1]->id + ) { + $type = 'mediumtext'; + } else { + throw new \RuntimeException( 'Unknown data type: ' . $token->value ); + } + + // Get full type. + $full_type = $type; + if ( 'enum' === $type || 'set' === $type ) { + $string_list = $type_node->get_descendant_node( 'stringList' ); + $values = $string_list->get_child_nodes( 'textString' ); + foreach ( $values as $i => $value ) { + $values[ $i ] = "'" . str_replace( "'", "''", $this->get_value( $value ) ) . "'"; + } + $full_type .= '(' . implode( ',', $values ) . ')'; + } + + $field_length = $type_node->get_descendant_node( 'fieldLength' ); + if ( null !== $field_length ) { + if ( 'decimal' === $type || 'float' === $type || 'double' === $type ) { + $full_type .= rtrim( $this->get_value( $field_length ), ')' ) . ',0)'; + } else { + $full_type .= $this->get_value( $field_length ); + } + /* + * As of MySQL 8.0.17, the display width attribute is deprecated for + * integer types (tinyint, smallint, mediumint, int/integer, bigint) + * and is not stored anymore. However, it may be important for older + * versions and WP's dbDelta, so it is safer to keep it at the moment. + * @TODO: Investigate if it is important to keep this. + */ + } + + $precision = $type_node->get_descendant_node( 'precision' ); + if ( null !== $precision ) { + $full_type .= $this->get_value( $precision ); + } + + $datetime_precision = $type_node->get_descendant_node( 'typeDatetimePrecision' ); + if ( null !== $datetime_precision ) { + $full_type .= $this->get_value( $datetime_precision ); + } + + if ( + WP_MySQL_Lexer::BOOL_SYMBOL === $token->id + || WP_MySQL_Lexer::BOOLEAN_SYMBOL === $token->id + ) { + $full_type .= '(1)'; // Add length for booleans. + } + + if ( null === $field_length && null === $precision ) { + if ( 'decimal' === $type ) { + $full_type .= '(10,0)'; // Add default precision for decimals. + } elseif ( 'char' === $type || 'bit' === $type || 'binary' === $type ) { + $full_type .= '(1)'; // Add default length for char, bit, binary. + } + } + + // UNSIGNED. + // SERIAL is an alias for BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE. + if ( + $type_node->get_descendant_token( WP_MySQL_Lexer::UNSIGNED_SYMBOL ) + || $type_node->get_descendant_token( WP_MySQL_Lexer::SERIAL_SYMBOL ) + ) { + $full_type .= ' unsigned'; + } + + // ZEROFILL. + if ( $type_node->get_descendant_token( WP_MySQL_Lexer::ZEROFILL_SYMBOL ) ) { + $full_type .= ' zerofill'; + } + + return array( $type, $full_type ); + } + + private function get_column_charset_and_collation( WP_Parser_Node $node, string $data_type ): array { + if ( ! ( + 'char' === $data_type + || 'varchar' === $data_type + || 'tinytext' === $data_type + || 'text' === $data_type + || 'mediumtext' === $data_type + || 'longtext' === $data_type + || 'enum' === $data_type + || 'set' === $data_type + ) ) { + return array( null, null ); + } + + $charset = null; + $collation = null; + $is_binary = false; + + // Charset. + $charset_node = $node->get_descendant_node( 'charsetWithOptBinary' ); + if ( null !== $charset_node ) { + $charset_name_node = $charset_node->get_child_node( 'charsetName' ); + if ( null !== $charset_name_node ) { + $charset = strtolower( $this->get_value( $charset_name_node ) ); + } elseif ( $charset_node->has_child_token( WP_MySQL_Lexer::ASCII_SYMBOL ) ) { + $charset = 'latin1'; + } elseif ( $charset_node->has_child_token( WP_MySQL_Lexer::UNICODE_SYMBOL ) ) { + $charset = 'ucs2'; + } elseif ( $charset_node->has_child_token( WP_MySQL_Lexer::BYTE_SYMBOL ) ) { + // @TODO: This changes varchar to varbinary. + } + + // @TODO: "DEFAULT" + + if ( $charset_node->has_child_token( WP_MySQL_Lexer::BINARY_SYMBOL ) ) { + $is_binary = true; + } + } else { + // National charsets (in MySQL, it's "utf8"). + $data_type_node = $node->get_descendant_node( 'dataType' ); + if ( + $data_type_node->has_child_node( 'nchar' ) + || $data_type_node->has_child_token( WP_MySQL_Lexer::NCHAR_SYMBOL ) + || $data_type_node->has_child_token( WP_MySQL_Lexer::NATIONAL_SYMBOL ) + || $data_type_node->has_child_token( WP_MySQL_Lexer::NVARCHAR_SYMBOL ) + ) { + $charset = 'utf8'; + } + } + + // Normalize charset. + if ( 'utf8mb3' === $charset ) { + $charset = 'utf8'; + } + + // Collation. + $collation_node = $node->get_descendant_node( 'collationName' ); + if ( null !== $collation_node ) { + $collation = strtolower( $this->get_value( $collation_node ) ); + } + + // Defaults. + // @TODO: These are hardcoded now. We should get them from table/DB. + if ( null === $charset && null === $collation ) { + $charset = 'utf8mb4'; + // @TODO: "BINARY" (seems to change varchar to varbinary). + // @TODO: "DEFAULT" + } + + // If only one of charset/collation is set, the other one is derived. + if ( null === $collation ) { + if ( $is_binary ) { + $collation = $charset . '_bin'; + } elseif ( isset( self::CHARSET_DEFAULT_COLLATION_MAP[ $charset ] ) ) { + $collation = self::CHARSET_DEFAULT_COLLATION_MAP[ $charset ]; + } else { + $collation = $charset . '_general_ci'; + } + } elseif ( null === $charset ) { + $charset = substr( $collation, 0, strpos( $collation, '_' ) ); + } + + return array( $charset, $collation ); + } + + private function get_column_lengths( WP_Parser_Node $node, string $data_type, ?string $charset ): array { + // Text and blob types. + if ( 'tinytext' === $data_type || 'tinyblob' === $data_type ) { + return array( 255, 255 ); + } elseif ( 'text' === $data_type || 'blob' === $data_type ) { + return array( 65535, 65535 ); + } elseif ( 'mediumtext' === $data_type || 'mediumblob' === $data_type ) { + return array( 16777215, 16777215 ); + } elseif ( 'longtext' === $data_type || 'longblob' === $data_type ) { + return array( 4294967295, 4294967295 ); + } + + // For CHAR, VARCHAR, BINARY, VARBINARY, we need to check the field length. + if ( + 'char' === $data_type + || 'binary' === $data_type + || 'varchar' === $data_type + || 'varbinary' === $data_type + ) { + $field_length = $node->get_descendant_node( 'fieldLength' ); + if ( null === $field_length ) { + $length = 1; + } else { + $length = (int) trim( $this->get_value( $field_length ), '()' ); + } + + if ( 'char' === $data_type || 'varchar' === $data_type ) { + $max_bytes_per_char = self::CHARSET_MAX_BYTES_MAP[ $charset ] ?? 1; + return array( $length, $max_bytes_per_char * $length ); + } else { + return array( $length, $length ); + } + } + + // For ENUM and SET, we need to check the longest value. + if ( 'enum' === $data_type || 'set' === $data_type ) { + $string_list = $node->get_descendant_node( 'stringList' ); + $values = $string_list->get_child_nodes( 'textString' ); + $length = 0; + foreach ( $values as $value ) { + $length = max( $length, strlen( $this->get_value( $value ) ) ); + } + $max_bytes_per_char = self::CHARSET_MAX_BYTES_MAP[ $charset ] ?? 1; + return array( $length, $max_bytes_per_char * $length ); + } + + return array( null, null ); + } + + private function get_column_numeric_attributes( WP_Parser_Node $node, string $data_type ): array { + if ( 'tinyint' === $data_type ) { + return array( 3, 0 ); + } elseif ( 'smallint' === $data_type ) { + return array( 5, 0 ); + } elseif ( 'mediumint' === $data_type ) { + return array( 7, 0 ); + } elseif ( 'int' === $data_type ) { + return array( 10, 0 ); + } elseif ( 'bigint' === $data_type ) { + if ( null !== $node->get_descendant_token( WP_MySQL_Lexer::UNSIGNED_SYMBOL ) ) { + return array( 20, 0 ); + } + + // SERIAL is an alias for BIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE. + $data_type = $node->get_descendant_node( 'dataType' ); + if ( null !== $data_type->get_descendant_token( WP_MySQL_Lexer::SERIAL_SYMBOL ) ) { + return array( 20, 0 ); + } + + return array( 19, 0 ); + } + + // For bit columns, we need to check the precision. + if ( 'bit' === $data_type ) { + $field_length = $node->get_descendant_node( 'fieldLength' ); + if ( null === $field_length ) { + return array( 1, null ); + } + return array( (int) trim( $this->get_value( $field_length ), '()' ), null ); + } + + // For floating point numbers, we need to check the precision and scale. + $precision = null; + $scale = null; + $precision_node = $node->get_descendant_node( 'precision' ); + if ( null !== $precision_node ) { + $values = $precision_node->get_descendant_tokens( WP_MySQL_Lexer::INT_NUMBER ); + $precision = (int) $values[0]->value; + $scale = (int) $values[1]->value; + } + + if ( 'float' === $data_type ) { + return array( $precision ?? 12, $scale ); + } elseif ( 'double' === $data_type ) { + return array( $precision ?? 22, $scale ); + } elseif ( 'decimal' === $data_type ) { + if ( null === $precision ) { + // Only precision can be specified ("fieldLength" in the grammar). + $field_length = $node->get_descendant_node( 'fieldLength' ); + if ( null !== $field_length ) { + $precision = (int) trim( $this->get_value( $field_length ), '()' ); + } + } + return array( $precision ?? 10, $scale ?? 0 ); + } + + return array( null, null ); + } + + private function get_column_datetime_precision( WP_Parser_Node $node, string $data_type ): ?int { + if ( 'time' === $data_type || 'datetime' === $data_type || 'timestamp' === $data_type ) { + $precision = $node->get_descendant_node( 'typeDatetimePrecision' ); + if ( null === $precision ) { + return 0; + } else { + return (int) $this->get_value( $precision ); + } + } + return null; + } + + private function get_column_generation_expression( WP_Parser_Node $node ): string { + if ( null !== $node->get_descendant_token( WP_MySQL_Lexer::GENERATED_SYMBOL ) ) { + $expr = $node->get_descendant_node( 'exprWithParentheses' ); + return $this->get_value( $expr ); + } + return ''; + } + /** * This is a helper function to get the full unescaped value of a node. * From 6bdb7aae56a097276a48ef17b197bc7d7b71aeb2 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 19 Dec 2024 15:22:19 +0100 Subject: [PATCH 18/36] Record CREATE TABLE constraint info in information schema --- ...s-wp-sqlite-information-schema-builder.php | 259 ++++++++++++++++-- 1 file changed, 241 insertions(+), 18 deletions(-) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php index 419fa804..037b4c23 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -3,8 +3,10 @@ // @TODO: Remove the namespace and use statements when replacing the old driver. namespace WIP; +use PDO; use PDOStatement; use WP_MySQL_Lexer; +use WP_MySQL_Token; use WP_Parser_Node; class WP_SQLite_Information_Schema_Builder { @@ -98,24 +100,24 @@ class WP_SQLite_Information_Schema_Builder { // STATISTICS (indexes) "CREATE TABLE IF NOT EXISTS _mysql_information_schema_statistics ( - TABLE_CATALOG TEXT NOT NULL DEFAULT 'def', - TABLE_SCHEMA TEXT NOT NULL, - TABLE_NAME TEXT NOT NULL, - NON_UNIQUE INTEGER NOT NULL, - INDEX_SCHEMA TEXT NOT NULL, - INDEX_NAME TEXT NOT NULL, - SEQ_IN_INDEX INTEGER NOT NULL, - COLUMN_NAME TEXT, - COLLATION TEXT, - CARDINALITY INTEGER, - SUB_PART INTEGER, - PACKED TEXT, - NULLABLE TEXT NOT NULL, - INDEX_TYPE TEXT NOT NULL, - COMMENT TEXT NOT NULL DEFAULT '', - INDEX_COMMENT TEXT NOT NULL DEFAULT '', - IS_VISIBLE TEXT NOT NULL DEFAULT 'YES', - EXPRESSION TEXT + TABLE_CATALOG TEXT NOT NULL DEFAULT 'def', -- always 'def' + TABLE_SCHEMA TEXT NOT NULL, -- database name + TABLE_NAME TEXT NOT NULL, -- table name + NON_UNIQUE INTEGER NOT NULL, -- 0 for unique indexes, 1 otherwise + INDEX_SCHEMA TEXT NOT NULL, -- index database name + INDEX_NAME TEXT NOT NULL, -- index name, for PKs always 'PRIMARY' + SEQ_IN_INDEX INTEGER NOT NULL, -- column position in index (from 1) + COLUMN_NAME TEXT, -- column name (NULL for functional indexes) + COLLATION TEXT, -- column sort in the index ('A', 'D', or NULL) + CARDINALITY INTEGER, -- not implemented + SUB_PART INTEGER, -- number of indexed chars, NULL for full column + PACKED TEXT, -- not implemented + NULLABLE TEXT NOT NULL, -- 'YES' if column can contain NULL, '' otherwise + INDEX_TYPE TEXT NOT NULL, -- 'BTREE', 'FULLTEXT', 'SPATIAL' + COMMENT TEXT NOT NULL DEFAULT '', -- not implemented + INDEX_COMMENT TEXT NOT NULL DEFAULT '', -- index comment + IS_VISIBLE TEXT NOT NULL DEFAULT 'YES', -- 'NO' if column is hidden, 'YES' otherwise + EXPRESSION TEXT -- expression for functional indexes ) STRICT", // TABLE_CONSTRAINTS @@ -399,6 +401,106 @@ public function record_create_table( WP_Parser_Node $node ): void { $this->insert_values( '_mysql_information_schema_columns', $column_data ); $column_position += 1; } + + // 3. Constraints. + foreach ( $node->get_descendant_nodes( 'tableConstraintDef' ) as $constraint_node ) { + $this->record_add_constraint( $table_name, $constraint_node ); + } + } + + private function record_add_constraint( string $table_name, WP_Parser_Node $node ): void { + // Get first constraint keyword. + $children = $node->get_children(); + $keyword = $children[0] instanceof WP_MySQL_Token ? $children[0] : $children[1]; + if ( ! $keyword instanceof WP_MySQL_Token ) { + $keyword = $keyword->get_child_token(); + } + + if ( + WP_MySQL_Lexer::FOREIGN_SYMBOL === $keyword->id + || WP_MySQL_Lexer::CHECK_SYMBOL === $keyword->id + ) { + throw new \Exception( 'FOREIGN KEY and CHECK constraints are not supported yet.' ); + } + + // Fetch column info. + $column_info = $this->query( + ' + SELECT column_name, data_type, is_nullable, character_maximum_length + FROM _mysql_information_schema_columns + WHERE table_name = ? + ', + array( $table_name ) + )->fetchAll( PDO::FETCH_ASSOC ); + + $column_info_map = array_combine( + array_column( $column_info, 'COLUMN_NAME' ), + $column_info + ); + + // Get first index column data type (needed for index type). + $first_column_name = $column_info[0]['COLUMN_NAME']; + $first_column_type = $column_info_map[ $first_column_name ]['DATA_TYPE'] ?? null; + $has_spatial_column = null !== $first_column_type && $this->is_spatial_data_type( $first_column_type ); + + $non_unique = $this->get_index_non_unique( $keyword ); + $index_name = $this->get_index_name( $node ); + $index_type = $this->get_index_type( $node, $keyword, $has_spatial_column ); + + $key_list = $node->get_child_node( 'keyListVariants' )->get_child(); + if ( 'keyListWithExpression' === $key_list->rule_name ) { + $key_parts = array(); + foreach ( $key_list->get_descendant_nodes( 'keyPartOrExpression' ) as $key_part ) { + $key_parts[] = $key_part->get_child(); + } + } else { + $key_parts = $key_list->get_descendant_nodes( 'keyPart' ); + } + + $seq_in_index = 1; + foreach ( $key_parts as $key_part ) { + $column_name = $this->get_index_column_name( $key_part ); + $collation = $this->get_index_column_collation( $key_part, $index_type ); + if ( + 'PRIMARY' === $index_name + || 'NO' === $column_info_map[ $column_name ]['IS_NULLABLE'] + ) { + $nullable = ''; + } else { + $nullable = 'YES'; + } + + $sub_part = $this->get_index_column_sub_part( + $key_part, + $column_info_map[ $column_name ]['CHARACTER_MAXIMUM_LENGTH'], + $has_spatial_column + ); + + $this->insert_values( + '_mysql_information_schema_statistics', + array( + 'table_schema' => $this->db_name, + 'table_name' => $table_name, + 'non_unique' => $non_unique, + 'index_schema' => $this->db_name, + 'index_name' => $index_name, + 'seq_in_index' => $seq_in_index, + 'column_name' => $column_name, + 'collation' => $collation, + 'cardinality' => 0, // not implemented + 'sub_part' => $sub_part, + 'packed' => null, // not implemented + 'nullable' => $nullable, + 'index_type' => $index_type, + 'comment' => '', // not implemented + 'index_comment' => '', // @TODO + 'is_visible' => 'YES', // @TODO: Save actual visibility value. + 'expression' => null, // @TODO + ) + ); + + $seq_in_index += 1; + } } private function extract_column_data( string $table_name, string $column_name, WP_Parser_Node $node, int $position ): array { @@ -896,6 +998,127 @@ private function get_column_generation_expression( WP_Parser_Node $node ): strin return ''; } + private function get_index_name( WP_Parser_Node $node ): string { + if ( $node->get_descendant_token( WP_MySQL_Lexer::PRIMARY_SYMBOL ) ) { + return 'PRIMARY'; + } + + $name_node = $node->get_descendant_node( 'indexName' ); + if ( null === $name_node ) { + /* + * In MySQL, the default index name equals the first column name. + * For functional indexes, the string "functional_index" is used. + * If the name is already used, we need to append a number. + */ + $subnode = $node->get_child_node( 'keyListVariants' )->get_child_node(); + if ( 'exprWithParentheses' === $subnode->rule_name ) { + $name = 'functional_index'; + } else { + $name = $this->get_value( $subnode->get_descendant_node( 'identifier' ) ); + } + + // @TODO: Check if the name is already used. + return $name; + } + return $this->get_value( $name_node ); + } + + private function get_index_non_unique( WP_MySQL_Token $token ): int { + if ( + WP_MySQL_Lexer::PRIMARY_SYMBOL === $token->id + || WP_MySQL_Lexer::UNIQUE_SYMBOL === $token->id + ) { + return 0; + } + return 1; + } + + private function get_index_type( + WP_Parser_Node $node, + WP_MySQL_Token $token, + bool $has_spatial_column + ): string { + // Handle "USING ..." clause. + $index_type = $node->get_descendant_node( 'indexTypeClause' ); + if ( null !== $index_type ) { + $index_type = strtoupper( + $this->get_value( $index_type->get_child_node( 'indexType' ) ) + ); + if ( 'RTREE' === $index_type ) { + return 'SPATIAL'; + } elseif ( 'HASH' === $index_type ) { + // InnoDB uses BTREE even when HASH is specified. + return 'BTREE'; + } + return $index_type; + } + + // Derive index type from its definition. + if ( WP_MySQL_Lexer::FULLTEXT_SYMBOL === $token->id ) { + return 'FULLTEXT'; + } elseif ( WP_MySQL_Lexer::SPATIAL_SYMBOL === $token->id ) { + return 'SPATIAL'; + } + + // Spatial indexes are also derived from column data type. + if ( $has_spatial_column ) { + return 'SPATIAL'; + } + + return 'BTREE'; + } + + private function get_index_column_name( WP_Parser_Node $node ): ?string { + if ( 'keyPart' !== $node->rule_name ) { + return null; + } + return $this->get_value( $node->get_descendant_node( 'identifier' ) ); + } + + private function get_index_column_collation( WP_Parser_Node $node, string $index_type ): ?string { + if ( 'FULLTEXT' === $index_type ) { + return null; + } + + $collate_node = $node->get_descendant_node( 'collationName' ); + if ( null === $collate_node ) { + return 'A'; + } + $collate = strtoupper( $this->get_value( $collate_node ) ); + return 'DESC' === $collate ? 'D' : 'A'; + } + + private function get_index_column_sub_part( + WP_Parser_Node $node, + ?int $max_length, + bool $is_spatial + ): ?int { + $field_length = $node->get_descendant_node( 'fieldLength' ); + if ( null === $field_length ) { + if ( $is_spatial ) { + return 32; + } + return null; + } + + $value = (int) trim( $this->get_value( $field_length ), '()' ); + if ( null !== $max_length && $value >= $max_length ) { + return $max_length; + } + return $value; + } + + private function is_spatial_data_type( string $data_type ): bool { + return 'geometry' === $data_type + || 'geomcollection' === $data_type + || 'point' === $data_type + || 'multipoint' === $data_type + || 'linestring' === $data_type + || 'multilinestring' === $data_type + || 'polygon' === $data_type + || 'multipolygon' === $data_type; + } + /** * This is a helper function to get the full unescaped value of a node. * From afeeb18787edc820d101842627c8cbb0f9ecb82e Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 19 Dec 2024 15:23:32 +0100 Subject: [PATCH 19/36] Record CREATE TABLE inline constraint info in information schema --- ...s-wp-sqlite-information-schema-builder.php | 44 +++++++++++++++++++ 1 file changed, 44 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php index 037b4c23..e685eb39 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -399,6 +399,21 @@ public function record_create_table( WP_Parser_Node $node ): void { $column_position ); $this->insert_values( '_mysql_information_schema_columns', $column_data ); + + // Inline column constraint. + $column_constraint_data = $this->extract_column_constraint_data( + $table_name, + $column_name, + $column_node, + 'YES' === $column_data['is_nullable'] + ); + if ( null !== $column_constraint_data ) { + $this->insert_values( + '_mysql_information_schema_statistics', + $column_constraint_data + ); + } + $column_position += 1; } @@ -542,6 +557,35 @@ private function extract_column_data( string $table_name, string $column_name, W ); } + private function extract_column_constraint_data( string $table_name, string $column_name, WP_Parser_Node $node, bool $nullable ): ?array { + // Handle inline PRIMARY KEY and UNIQUE constraints. + $has_inline_primary_key = null !== $node->get_descendant_token( WP_MySQL_Lexer::KEY_SYMBOL ); + $has_inline_unique_key = null !== $node->get_descendant_token( WP_MySQL_Lexer::UNIQUE_SYMBOL ); + if ( $has_inline_primary_key || $has_inline_unique_key ) { + $index_name = $has_inline_primary_key ? 'PRIMARY' : $column_name; + return array( + 'table_schema' => $this->db_name, + 'table_name' => $table_name, + 'non_unique' => 0, + 'index_schema' => $this->db_name, + 'index_name' => $index_name, + 'seq_in_index' => 1, + 'column_name' => $column_name, + 'collation' => 'A', + 'cardinality' => 0, // not implemented + 'sub_part' => null, + 'packed' => null, // not implemented + 'nullable' => true === $nullable ? 'YES' : '', + 'index_type' => 'BTREE', + 'comment' => '', // not implemented + 'index_comment' => '', // @TODO + 'is_visible' => 'YES', // @TODO: Save actual visibility value. + 'expression' => null, // @TODO + ); + } + return null; + } + private function get_table_engine( WP_Parser_Node $node ): string { $engine_node = $node->get_descendant_node( 'engineRef' ); if ( null === $engine_node ) { From 2eaf0774fea1fc8cc44b8a8ca4ff409a437e6164 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 19 Dec 2024 15:28:36 +0100 Subject: [PATCH 20/36] Sync constraint info to columns table when constraints are modified --- ...s-wp-sqlite-information-schema-builder.php | 47 +++++++++++++++++++ 1 file changed, 47 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php index e685eb39..1561801a 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -516,6 +516,8 @@ private function record_add_constraint( string $table_name, WP_Parser_Node $node $seq_in_index += 1; } + + $this->sync_column_key_info( $table_name ); } private function extract_column_data( string $table_name, string $column_name, WP_Parser_Node $node, int $position ): array { @@ -586,6 +588,51 @@ private function extract_column_constraint_data( string $table_name, string $col return null; } + /** + * Update column info from constraint data in the statistics table. + * + * When constraints are added or removed, we need to reflect the changes + * in the "COLUMN_KEY" and "IS_NULLABLE" columns of the "COLUMNS" table. + * + * A) COLUMN_KEY (priority from 1 to 4): + * 1. "PRI": Column is any component of a PRIMARY KEY. + * 2. "UNI": Column is the first column of a UNIQUE KEY. + * 3. "MUL": Column is the first column of a non-unique index. + * 4. "": Column is not indexed. + * + * B) IS_NULLABLE: In COLUMNS, "YES"/"NO". In STATISTICS, "YES"/"". + */ + private function sync_column_key_info( string $table_name ): void { + // @TODO: Consider listing only affected columns. + $this->query( + " + WITH s AS ( + SELECT + column_name, + CASE + WHEN MAX(index_name = 'PRIMARY') THEN 'PRI' + WHEN MAX(non_unique = 0 AND seq_in_index = 1) THEN 'UNI' + WHEN MAX(seq_in_index = 1) THEN 'MUL' + ELSE '' + END AS column_key + FROM _mysql_information_schema_statistics + WHERE table_schema = ? + AND table_name = ? + GROUP BY column_name + ) + UPDATE _mysql_information_schema_columns AS c + SET + column_key = s.column_key, + is_nullable = IIF(s.column_key = 'PRI', 'NO', c.is_nullable) + FROM s + WHERE c.table_schema = ? + AND c.table_name = ? + AND s.column_name = c.column_name + ", + array( $this->db_name, $table_name, $this->db_name, $table_name ) + ); + } + private function get_table_engine( WP_Parser_Node $node ): string { $engine_node = $node->get_descendant_node( 'engineRef' ); if ( null === $engine_node ) { From d03892d77731fd003a4e94d093dfdd8603adda5b Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 19 Dec 2024 21:02:38 +0100 Subject: [PATCH 21/36] Record ALTER TABLE ADD COLUMN(s) in information schema --- ...s-wp-sqlite-information-schema-builder.php | 69 +++++++++++++++++++ 1 file changed, 69 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php index 1561801a..4d5ab5a3 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -423,6 +423,54 @@ public function record_create_table( WP_Parser_Node $node ): void { } } + public function record_alter_table( WP_Parser_Node $node ): void { + $table_name = $this->get_value( $node->get_descendant_node( 'tableRef' ) ); + $actions = $node->get_descendant_nodes( 'alterListItem' ); + + foreach ( $actions as $action ) { + $first_token = $action->get_child_token(); + + // ADD + if ( WP_MySQL_Lexer::ADD_SYMBOL === $first_token->id ) { + // ADD [COLUMN] (...[, ...]) + $column_definitions = $action->get_descendant_nodes( 'columnDefinition' ); + if ( count( $column_definitions ) > 0 ) { + foreach ( $column_definitions as $column_definition ) { + $name = $this->get_value( $column_definition->get_child_node( 'identifier' ) ); + $this->record_add_column( $table_name, $name, $column_definition ); + } + continue; + } + + // ADD [COLUMN] ... + $field_definition = $action->get_descendant_node( 'fieldDefinition' ); + if ( null !== $field_definition ) { + $name = $this->get_value( $action->get_child_node( 'identifier' ) ); + $this->record_add_column( $table_name, $name, $field_definition ); + // @TODO: Handle FIRST/AFTER. + continue; + } + + throw new \Exception( sprintf( 'Unsupported ALTER TABLE ADD action: %s', $first_token->value ) ); + } + } + } + + private function record_add_column( string $table_name, string $column_name, WP_Parser_Node $node ): void { + $position = $this->query( + 'SELECT MAX(ordinal_position) FROM _mysql_information_schema_columns WHERE table_name = ?', + array( $table_name ) + )->fetchColumn(); + + $column_data = $this->extract_column_data( $table_name, $column_name, $node, (int) $position + 1 ); + $this->insert_values( '_mysql_information_schema_columns', $column_data ); + + $column_constraint_data = $this->extract_column_constraint_data( $table_name, $column_name, $node, true ); + if ( null !== $column_constraint_data ) { + $this->insert_values( '_mysql_information_schema_statistics', $column_constraint_data ); + } + } + private function record_add_constraint( string $table_name, WP_Parser_Node $node ): void { // Get first constraint keyword. $children = $node->get_children(); @@ -1264,6 +1312,27 @@ private function insert_values( string $table_name, array $data ): void { ); } + private function update_values( string $table_name, array $data, array $where ): void { + $set = array(); + foreach ( $data as $column => $value ) { + $set[] = $column . ' = ?'; + } + + $where_clause = array(); + foreach ( $where as $column => $value ) { + $where_clause[] = $column . ' = ?'; + } + + $this->query( + ' + UPDATE ' . $table_name . ' + SET ' . implode( ', ', $set ) . ' + WHERE ' . implode( ' AND ', $where_clause ) . ' + ', + array_merge( array_values( $data ), array_values( $where ) ) + ); + } + /** * @param string $query * @param array $params From 93f536e023e35a38e800d5238417f5eda8375f01 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 19 Dec 2024 21:04:12 +0100 Subject: [PATCH 22/36] Record ALTER TABLE ADD CONSTRAINT in information schema --- .../class-wp-sqlite-information-schema-builder.php | 7 +++++++ 1 file changed, 7 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php index 4d5ab5a3..d6702d02 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -451,6 +451,13 @@ public function record_alter_table( WP_Parser_Node $node ): void { continue; } + // ADD CONSTRAINT. + $constraint = $action->get_descendant_node( 'tableConstraintDef' ); + if ( null !== $constraint ) { + $this->record_add_constraint( $table_name, $constraint ); + continue; + } + throw new \Exception( sprintf( 'Unsupported ALTER TABLE ADD action: %s', $first_token->value ) ); } } From 6940a5b5c946249ba244dc29d6ef5ae7dca462ff Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 19 Dec 2024 21:04:53 +0100 Subject: [PATCH 23/36] Record ALTER TABLE CHANGE/MODIFY COLUMN in information schema --- ...s-wp-sqlite-information-schema-builder.php | 76 +++++++++++++++++++ 1 file changed, 76 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php index d6702d02..3baf5b05 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -460,6 +460,30 @@ public function record_alter_table( WP_Parser_Node $node ): void { throw new \Exception( sprintf( 'Unsupported ALTER TABLE ADD action: %s', $first_token->value ) ); } + + // CHANGE [COLUMN] + if ( WP_MySQL_Lexer::CHANGE_SYMBOL === $first_token->id ) { + $old_name = $this->get_value( $action->get_child_node( 'columnInternalRef' ) ); + $new_name = $this->get_value( $action->get_child_node( 'identifier' ) ); + $this->record_change_column( + $table_name, + $old_name, + $new_name, + $action->get_descendant_node( 'fieldDefinition' ) + ); + continue; + } + + // MODIFY [COLUMN] + if ( WP_MySQL_Lexer::MODIFY_SYMBOL === $first_token->id ) { + $name = $this->get_value( $action->get_child_node( 'columnInternalRef' ) ); + $this->record_modify_column( + $table_name, + $name, + $action->get_descendant_node( 'fieldDefinition' ) + ); + continue; + } } } @@ -478,6 +502,58 @@ private function record_add_column( string $table_name, string $column_name, WP_ } } + private function record_change_column( + string $table_name, + string $column_name, + string $new_column_name, + WP_Parser_Node $node + ): void { + $column_data = $this->extract_column_data( $table_name, $new_column_name, $node, 0 ); + $this->update_values( + '_mysql_information_schema_columns', + $column_data, + array( + 'table_name' => $table_name, + 'column_name' => $column_name, + ) + ); + + // Update column name in statistics, if it has changed. + if ( $new_column_name !== $column_name ) { + $this->update_values( + '_mysql_information_schema_statistics', + array( + 'column_name' => $new_column_name, + ), + array( + 'table_name' => $table_name, + 'column_name' => $column_name, + ) + ); + } + + // Handle inline constraints. When inline constraint is defined, MySQL + // always adds a new constraint rather than replacing an existing one. + $column_constraint_data = $this->extract_column_constraint_data( + $table_name, + $new_column_name, + $node, + 'YES' === $column_data['is_nullable'] + ); + if ( null !== $column_constraint_data ) { + $this->insert_values( '_mysql_information_schema_statistics', $column_constraint_data ); + $this->sync_column_key_info( $table_name ); + } + } + + private function record_modify_column( + string $table_name, + string $column_name, + WP_Parser_Node $node + ): void { + $this->record_change_column( $table_name, $column_name, $column_name, $node ); + } + private function record_add_constraint( string $table_name, WP_Parser_Node $node ): void { // Get first constraint keyword. $children = $node->get_children(); From 127efc25b27decef936cb9b523409f60d44e4d64 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Thu, 19 Dec 2024 21:05:04 +0100 Subject: [PATCH 24/36] Record ALTER TABLE DROP COLUMN in information schema --- ...s-wp-sqlite-information-schema-builder.php | 60 +++++++++++++++++++ 1 file changed, 60 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php index 3baf5b05..f5ce252d 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -484,6 +484,16 @@ public function record_alter_table( WP_Parser_Node $node ): void { ); continue; } + + // DROP + if ( WP_MySQL_Lexer::DROP_SYMBOL === $first_token->id ) { + // DROP [COLUMN] + $column_ref = $action->get_child_node( 'columnInternalRef' ); + if ( null !== $column_ref ) { + $name = $this->get_value( $column_ref ); + $this->record_drop_column( $table_name, $name ); + } + } } } @@ -554,6 +564,41 @@ private function record_modify_column( $this->record_change_column( $table_name, $column_name, $column_name, $node ); } + private function record_drop_column( $table_name, $column_name ): void { + $this->delete_values( + '_mysql_information_schema_columns', + array( + 'table_name' => $table_name, + 'column_name' => $column_name, + ) + ); + + /** + * From MySQL documentation: + * + * If columns are dropped from a table, the columns are also removed + * from any index of which they are a part. If all columns that make up + * an index are dropped, the index is dropped as well. + * + * This means we need to remove the records from the STATISTICS table, + * renumber the SEQ_IN_INDEX values, and resync the column key info. + * + * See: + * - https://dev.mysql.com/doc/refman/8.4/en/alter-table.html + */ + $this->delete_values( + '_mysql_information_schema_statistics', + array( + 'table_name' => $table_name, + 'column_name' => $column_name, + ) + ); + + // @TODO: Renumber SEQ_IN_INDEX values. + + $this->sync_column_key_info( $table_name ); + } + private function record_add_constraint( string $table_name, WP_Parser_Node $node ): void { // Get first constraint keyword. $children = $node->get_children(); @@ -1416,6 +1461,21 @@ private function update_values( string $table_name, array $data, array $where ): ); } + private function delete_values( string $table_name, array $where ): void { + $where_clause = array(); + foreach ( $where as $column => $value ) { + $where_clause[] = $column . ' = ?'; + } + + $this->query( + ' + DELETE FROM ' . $table_name . ' + WHERE ' . implode( ' AND ', $where_clause ) . ' + ', + array_values( $where ) + ); + } + /** * @param string $query * @param array $params From 71265edbd8ea24a575d0149f10578de1124602f2 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 20 Dec 2024 11:03:23 +0100 Subject: [PATCH 25/36] Record ALTER TABLE DROP INDEX in information schema --- ...s-wp-sqlite-information-schema-builder.php | 19 +++++++++++++++++++ 1 file changed, 19 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php index f5ce252d..ca0302a0 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-information-schema-builder.php @@ -492,6 +492,14 @@ public function record_alter_table( WP_Parser_Node $node ): void { if ( null !== $column_ref ) { $name = $this->get_value( $column_ref ); $this->record_drop_column( $table_name, $name ); + continue; + } + + // DROP INDEX + if ( $action->has_child_node( 'keyOrIndex' ) ) { + $name = $this->get_value( $action->get_child_node( 'indexRef' ) ); + $this->record_drop_index( $table_name, $name ); + continue; } } } @@ -599,6 +607,17 @@ private function record_drop_column( $table_name, $column_name ): void { $this->sync_column_key_info( $table_name ); } + private function record_drop_index( string $table_name, string $index_name ): void { + $this->delete_values( + '_mysql_information_schema_statistics', + array( + 'table_name' => $table_name, + 'index_name' => $index_name, + ) + ); + $this->sync_column_key_info( $table_name ); + } + private function record_add_constraint( string $table_name, WP_Parser_Node $node ): void { // Get first constraint keyword. $children = $node->get_children(); From 71e8d08c5d7f4476b65c9891af52e3ad53048b66 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 20 Dec 2024 12:18:38 +0100 Subject: [PATCH 26/36] Execute CREATE TABLE using information schema --- .../sqlite-ast/class-wp-sqlite-driver.php | 362 +++++++++++------- 1 file changed, 234 insertions(+), 128 deletions(-) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 7bd37d03..f1a63eef 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -21,6 +21,11 @@ class WP_SQLite_Driver { const SQLITE_BUSY = 5; const SQLITE_LOCKED = 6; + /** + * A map of MySQL tokens to SQLite data types. + * + * This is used to translate a MySQL data type to an SQLite data type. + */ const DATA_TYPE_MAP = array( // Numeric data types: WP_MySQL_Lexer::BIT_SYMBOL => 'INTEGER', @@ -80,6 +85,72 @@ class WP_SQLite_Driver { // SERIAL, SET, and JSON types are handled in the translation process. ); + /** + * A map of normalized MySQL data types to SQLite data types. + * + * This is used to generate SQLite CREATE TABLE statements from the MySQL + * INFORMATION_SCHEMA tables. They keys are MySQL data types normalized + * as they appear in the INFORMATION_SCHEMA. Values are SQLite data types. + */ + const DATA_TYPE_STRING_MAP = array( + // Numeric data types: + 'bit' => 'INTEGER', + 'bool' => 'INTEGER', + 'boolean' => 'INTEGER', + 'tinyint' => 'INTEGER', + 'smallint' => 'INTEGER', + 'mediumint' => 'INTEGER', + 'int' => 'INTEGER', + 'integer' => 'INTEGER', + 'bigint' => 'INTEGER', + 'float' => 'REAL', + 'double' => 'REAL', + 'real' => 'REAL', + 'decimal' => 'REAL', + 'dec' => 'REAL', + 'fixed' => 'REAL', + 'numeric' => 'REAL', + + // String data types: + 'char' => 'TEXT', + 'varchar' => 'TEXT', + 'nchar' => 'TEXT', + 'nvarchar' => 'TEXT', + 'tinytext' => 'TEXT', + 'text' => 'TEXT', + 'mediumtext' => 'TEXT', + 'longtext' => 'TEXT', + 'enum' => 'TEXT', + 'set' => 'TEXT', + 'json' => 'TEXT', + + // Date and time data types: + 'date' => 'TEXT', + 'time' => 'TEXT', + 'datetime' => 'TEXT', + 'timestamp' => 'TEXT', + 'year' => 'TEXT', + + // Binary data types: + 'binary' => 'INTEGER', + 'varbinary' => 'BLOB', + 'tinyblob' => 'BLOB', + 'blob' => 'BLOB', + 'mediumblob' => 'BLOB', + 'longblob' => 'BLOB', + + // Spatial data types: + 'geometry' => 'TEXT', + 'point' => 'TEXT', + 'linestring' => 'TEXT', + 'polygon' => 'TEXT', + 'multipoint' => 'TEXT', + 'multilinestring' => 'TEXT', + 'multipolygon' => 'TEXT', + 'geomcollection' => 'TEXT', + 'geometrycollection' => 'TEXT', + ); + const DATA_TYPES_CACHE_TABLE = '_mysql_data_types_cache'; const CREATE_DATA_TYPES_CACHE_TABLE = 'CREATE TABLE IF NOT EXISTS _mysql_data_types_cache ( @@ -902,86 +973,25 @@ private function execute_create_table_statement( WP_Parser_Node $node ): void { return; } - /* - * We need to handle some differences between MySQL and SQLite: - * - * 1. Inline index definitions: - * - * In MySQL, we can define an index inline with a column definition. - * In SQLite, we need to define indexes separately, using extra queries. - * - * 2. Column and constraint definition order: - * - * In MySQL, column and constraint definitions can be arbitrarily mixed. - * In SQLite, column definitions must come first, followed by constraints. - * - * 2. Auto-increment: - * - * In MySQL, there can at most one AUTO_INCREMENT column, and it must be - * a PRIMARY KEY, or the first column in a multi-column KEY. - * - * In SQLite, there can at most one AUTOINCREMENT column, and it must be - * a PRIMARY KEY, defined inline on a single column. - * - * Therefore, the following valid MySQL construct is not supported: - * CREATE TABLE t ( a INT AUTO_INCREMENT, b INT, PRIMARY KEY (a, b) ); - * @TODO: Support it with a single-column PK and a multi-column UNIQUE KEY. - */ - - // Collect column, index, and constraint nodes. - $columns = array(); - $constraints = array(); - $indexes = array(); - $has_autoincrement = false; - $primary_key_constraint = null; // Does not include inline PK definition. + $table_name = $this->unquote_sqlite_identifier( + $this->translate( $node->get_descendant_node( 'tableName' ) ) + ); - foreach ( $element_list->get_descendant_nodes( 'columnDefinition' ) as $child ) { - if ( null !== $child->get_descendant_token( WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL ) ) { - $has_autoincrement = true; - } - // @TODO: Collect inline index definitions. - $columns[] = $child; - } + // Save information to information schema tables. + $this->information_schema_builder->record_create_table( $node ); - foreach ( $element_list->get_descendant_nodes( 'tableConstraintDef' ) as $child ) { - if ( null !== $child->get_descendant_token( WP_MySQL_Lexer::PRIMARY_SYMBOL ) ) { - $primary_key_constraint = $child; - } else { - $constraints[] = $child; - } - } + // Generate CREATE TABLE statement from the information schema tables. + $queries = $this->get_sqlite_create_table_statement( $table_name ); + $create_table_query = $queries[0]; + $constraint_queries = array_slice( $queries, 1 ); - /* - * If we have a PRIMARY KEY constraint: - * 1. Without auto-increment, we can put it back to the list of constraints. - * 2. With auto-increment, we need to later move it to the column definition. - */ - if ( null !== $primary_key_constraint ) { - if ( ! $has_autoincrement ) { - $constraints[] = $primary_key_constraint; - } elseif ( count( $primary_key_constraint->get_descendant_nodes( 'keyPart' ) ) > 1 ) { - throw $this->not_supported_exception( - 'Composite primary key with AUTO_INCREMENT' - ); - } - } + $this->execute_sqlite_query( $create_table_query ); + $this->results = $this->last_exec_returned; + $this->return_value = $this->results; - $query_parts = array( 'CREATE' ); - foreach ( $node->get_child_node()->get_children() as $child ) { - if ( $child instanceof WP_Parser_Node && 'tableElementList' === $child->rule_name ) { - $query_parts[] = $this->translate_sequence( array_merge( $columns, $constraints ), ' , ' ); - } else { - $part = $this->translate( $child ); - if ( null !== $part ) { - $query_parts[] = $part; - } - } + foreach ( $constraint_queries as $query ) { + $this->execute_sqlite_query( $query ); } - - // @TODO: Execute queries for inline index definitions. - - $this->execute_sqlite_query( implode( ' ', $query_parts ) ); - $this->set_result_from_affected_rows(); } private function execute_alter_table_statement( WP_Parser_Node $node ): void { @@ -1116,59 +1126,9 @@ private function translate( $ast ) { // When we have no value, it's reasonable to use NULL. return 'NULL'; - case 'fieldDefinition': - /* - * In SQLite, there is the a quirk for backward compatibility: - * 1. INTEGER PRIMARY KEY creates an alias of ROWID. - * 2. INT PRIMARY KEY will not alias of ROWID. - * - * Therefore, we want to: - * 1. Use INTEGER PRIMARY KEY for when we have AUTOINCREMENT. - * 2. Use INT PRIMARY KEY otherwise. - */ - $has_primary_key = $ast->get_descendant_token( WP_MySQL_Lexer::KEY_SYMBOL ) !== null; - $has_autoincrement = $ast->get_descendant_token( WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL ) !== null; - $children = $ast->get_children(); - $data_type_node = array_shift( $children ); - $data_type = $this->translate( $data_type_node ); - if ( $has_primary_key && 'INTEGER' === $data_type ) { - $data_type = $has_autoincrement ? 'INTEGER' : 'INT'; - } - - $attributes = $this->translate_sequence( $children ); - $definition = $data_type . ( null === $attributes ? '' : " $attributes" ); - - /* - * In SQLite, AUTOINCREMENT must always be preceded by PRIMARY KEY. - * Therefore, we remove both PRIMARY KEY and AUTOINCREMENT from - * column attributes, and append them here in SQLite-friendly way. - */ - if ( $has_autoincrement ) { - return $definition . ' PRIMARY KEY AUTOINCREMENT'; - } elseif ( $has_primary_key ) { - return $definition . ' PRIMARY KEY'; - } - return $definition; - case 'columnAttribute': - case 'gcolAttribute': - /* - * Remove PRIMARY KEY and AUTOINCREMENT from the column attributes. - * They are handled in the "fieldDefinition" node. - */ - if ( $ast->has_child_token( WP_MySQL_Lexer::KEY_SYMBOL ) ) { - return null; - } - if ( $ast->has_child_token( WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL ) ) { - return null; - } - return $this->translate_sequence( $ast->get_children() ); - case 'createTableOptions': - return $this->translate_sequence( $ast->get_children(), ', ' ); - case 'createTableOption': - if ( $ast->get_child_token( WP_MySQL_Lexer::ENGINE_SYMBOL ) ) { - return null; - } - return $this->translate_sequence( $ast->get_children() ); + case 'defaultCollation': + // @TODO: Check and save in information schema. + return null; case 'duplicateAsQueryExpression': // @TODO: How to handle IGNORE/REPLACE? @@ -1184,6 +1144,8 @@ private function translate_token( WP_MySQL_Token $token ) { case WP_MySQL_Lexer::EOF: return null; case WP_MySQL_Lexer::IDENTIFIER: + case WP_MySQL_Lexer::BACK_TICK_QUOTED_ID: + // @TODO: Properly unquote (MySQL) and escape (SQLite). return '"' . trim( $token->value, '`"' ) . '"'; case WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL: return 'AUTOINCREMENT'; @@ -1211,6 +1173,150 @@ private function translate_sequence( array $nodes, string $separator = ' ' ): ?s return implode( $separator, $parts ); } + private function get_sqlite_create_table_statement( string $table_name, ?string $new_table_name = null ): array { + // 1. Get table info. + $table_info = $this->execute_sqlite_query( + ' + SELECT * + FROM _mysql_information_schema_tables + WHERE table_type = "BASE TABLE" + AND table_schema = ? + AND table_name = ? + ', + array( $this->db_name, $table_name ) + )->fetch( PDO::FETCH_ASSOC ); + + if ( false === $table_info ) { + throw new Exception( 'Table not found in information_schema' ); + } + + // 2. Get column info. + $column_info = $this->execute_sqlite_query( + 'SELECT * FROM _mysql_information_schema_columns WHERE table_schema = ? AND table_name = ?', + array( $this->db_name, $table_name ) + )->fetchAll( PDO::FETCH_ASSOC ); + + // 3. Get index info, grouped by index name. + $constraint_info = $this->execute_sqlite_query( + 'SELECT * FROM _mysql_information_schema_statistics WHERE table_schema = ? AND table_name = ?', + array( $this->db_name, $table_name ) + )->fetchAll( PDO::FETCH_ASSOC ); + + $grouped_constraints = array(); + foreach ( $constraint_info as $constraint ) { + $name = $constraint['INDEX_NAME']; + $seq = $constraint['SEQ_IN_INDEX']; + $grouped_constraints[ $name ][ $seq ] = $constraint; + } + + // 4. Generate CREATE TABLE statement columns. + $rows = array(); + $has_autoincrement = false; + foreach ( $column_info as $column ) { + $sql = ' '; + $sql .= sprintf( '"%s"', str_replace( '"', '""', $column['COLUMN_NAME'] ) ); + + $type = self::DATA_TYPE_STRING_MAP[ $column['DATA_TYPE'] ]; + + /* + * In SQLite, there is a PRIMARY KEY quirk for backward compatibility. + * This applies to ROWID tables and single-column primary keys only: + * 1. "INTEGER PRIMARY KEY" creates an alias of ROWID. + * 2. "INT PRIMARY KEY" will not alias of ROWID. + * + * Therefore, we want to: + * 1. Use "INT PRIMARY KEY" when we have a single-column integer + * PRIMARY KEY without AUTOINCREMENT (to avoid the ROWID alias). + * 2. Use "INTEGER PRIMARY KEY" otherwise. + * + * See: + * - https://www.sqlite.org/autoinc.html + * - https://www.sqlite.org/lang_createtable.html + */ + if ( + 'INTEGER' === $type + && 'PRI' === $column['COLUMN_KEY'] + && 'auto_increment' !== $column['EXTRA'] + && count( $grouped_constraints['PRIMARY'] ) === 1 + ) { + $type = 'INT'; + } + + $sql .= ' ' . $type; + if ( 'NO' === $column['IS_NULLABLE'] ) { + $sql .= ' NOT NULL'; + } + if ( 'auto_increment' === $column['EXTRA'] ) { + $has_autoincrement = true; + $sql .= ' PRIMARY KEY AUTOINCREMENT'; + } + if ( null !== $column['COLUMN_DEFAULT'] ) { + // @TODO: Correctly quote based on the data type. + $sql .= ' DEFAULT ' . $this->pdo->quote( $column['COLUMN_DEFAULT'] ); + } + $rows[] = $sql; + } + + // 4. Generate CREATE TABLE statement constraints, collect indexes. + $create_index_sqls = array(); + foreach ( $grouped_constraints as $constraint ) { + ksort( $constraint ); + $info = $constraint[1]; + + if ( 'PRIMARY' === $info['INDEX_NAME'] ) { + if ( $has_autoincrement ) { + continue; + } + $sql = ' PRIMARY KEY ('; + $sql .= implode( + ', ', + array_map( + function ( $column ) { + return sprintf( '"%s"', str_replace( '"', '""', $column['COLUMN_NAME'] ) ); + }, + $constraint + ) + ); + $sql .= ')'; + $rows[] = $sql; + } else { + $is_unique = '0' === $info['NON_UNIQUE']; + + $sql = sprintf( 'CREATE %sINDEX', $is_unique ? 'UNIQUE ' : '' ); + $sql .= sprintf( ' "%s"', $info['INDEX_NAME'] ); + $sql .= sprintf( ' ON "%s" (', $table_name ); + $sql .= implode( + ', ', + array_map( + function ( $column ) { + return sprintf( '"%s"', str_replace( '"', '""', $column['COLUMN_NAME'] ) ); + }, + $constraint + ) + ); + $sql .= ')'; + + $create_index_sqls[] = $sql; + } + } + + // 5. Compose the CREATE TABLE statement. + $sql = sprintf( 'CREATE TABLE "%s" (%s', str_replace( '"', '""', $new_table_name ?? $table_name ), "\n" ); + $sql .= implode( ",\n", $rows ); + $sql .= "\n)"; + return array_merge( array( $sql ), $create_index_sqls ); + } + + private function unquote_sqlite_identifier( string $quoted_identifier ): string { + $first_byte = $quoted_identifier[0] ?? null; + if ( '"' === $first_byte ) { + $unquoted = substr( $quoted_identifier, 1, -1 ); + } else { + $unquoted = $quoted_identifier; + } + return str_replace( '""', '"', $unquoted ); + } + /** * This method makes database directory and .htaccess file. * From 4b4fb8fa29b28f96b2555688f1dd48be1d439b19 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 20 Dec 2024 12:24:15 +0100 Subject: [PATCH 27/36] Execute ALTER TABLE using information schema --- .../sqlite-ast/class-wp-sqlite-driver.php | 147 +++++++++++++----- 1 file changed, 109 insertions(+), 38 deletions(-) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index f1a63eef..684e95c2 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -995,8 +995,115 @@ private function execute_create_table_statement( WP_Parser_Node $node ): void { } private function execute_alter_table_statement( WP_Parser_Node $node ): void { - $table_name = $this->translate( $node->get_descendant_node( 'tableRef' ) ); - $actions = $node->get_descendant_nodes( 'alterListItem' ); + $table_name = $this->unquote_sqlite_identifier( + $this->translate( $node->get_descendant_node( 'tableRef' ) ) + ); + + // Save all column names from the original table. + $column_names = $this->execute_sqlite_query( + 'SELECT COLUMN_NAME FROM _mysql_information_schema_columns WHERE table_schema = ? AND table_name = ?', + array( $this->db_name, $table_name ) + )->fetchAll( PDO::FETCH_COLUMN ); + + // Track column renames and removals. + $column_map = array_combine( $column_names, $column_names ); + foreach ( $node->get_descendant_nodes( 'alterListItem' ) as $action ) { + $first_token = $action->get_child_token(); + + if ( WP_MySQL_Lexer::DROP_SYMBOL === $first_token->id ) { + $name = $this->translate( $action->get_child_node( 'columnInternalRef' ) ); + if ( null !== $name ) { + $name = $this->unquote_sqlite_identifier( $name ); + unset( $column_map[ $name ] ); + } + } + + if ( WP_MySQL_Lexer::CHANGE_SYMBOL === $first_token->id ) { + $old_name = $this->unquote_sqlite_identifier( + $this->translate( $action->get_child_node( 'columnInternalRef' ) ) + ); + $new_name = $this->unquote_sqlite_identifier( + $this->translate( $action->get_child_node( 'identifier' ) ) + ); + + $column_map[ $old_name ] = $new_name; + } + + if ( WP_MySQL_Lexer::RENAME_SYMBOL === $first_token->id ) { + $column_ref = $action->get_child_node( 'columnInternalRef' ); + if ( null !== $column_ref ) { + $old_name = $this->unquote_sqlite_identifier( + $this->translate( $column_ref ) + ); + $new_name = $this->unquote_sqlite_identifier( + $this->translate( $action->get_child_node( 'identifier' ) ) + ); + + $column_map[ $old_name ] = $new_name; + } + } + } + + $this->information_schema_builder->record_alter_table( $node ); + + /* + * See: + * https://www.sqlite.org/lang_altertable.html#making_other_kinds_of_table_schema_changes + */ + + // 1. If foreign key constraints are enabled, disable them. + // @TODO + + // 2. Create a new table with the new schema. + $tmp_table_name = "_tmp__{$table_name}_" . uniqid(); + $queries = $this->get_sqlite_create_table_statement( $table_name, $tmp_table_name ); + $create_table_query = $queries[0]; + $constraint_queries = array_slice( $queries, 1 ); + $this->execute_sqlite_query( $create_table_query ); + + // 3. Copy data from the original table to the new table. + $this->execute_sqlite_query( + sprintf( + 'INSERT INTO "%s" (%s) SELECT %s FROM "%s"', + $tmp_table_name, + implode( + ', ', + array_map( + function ( $column ) { + return '"' . $column . '"'; + }, + $column_map + ) + ), + implode( + ', ', + array_map( + function ( $column ) { + return '"' . $column . '"'; + }, + array_keys( $column_map ) + ) + ), + $table_name + ) + ); + + // 4. Drop the original table. + $this->execute_sqlite_query( sprintf( 'DROP TABLE "%s"', $table_name ) ); + + // 5. Rename the new table to the original table name. + $this->execute_sqlite_query( sprintf( 'ALTER TABLE "%s" RENAME TO "%s"', $tmp_table_name, $table_name ) ); + + // 6. Reconstruct indexes, triggers, and views. + foreach ( $constraint_queries as $query ) { + $this->execute_sqlite_query( $query ); + } + + // @TODO: Triggers and views. + + $this->results = 1; + $this->return_value = $this->results; + return; /* * SQLite supports only a small subset of MySQL ALTER TABLE statement. @@ -1018,42 +1125,6 @@ private function execute_alter_table_statement( WP_Parser_Node $node ): void { * * @TODO: Address these nuances. */ - foreach ( $actions as $action ) { - $token = $action->get_child_token(); - - // ADD column/constraint. - if ( WP_MySQL_Lexer::ADD_SYMBOL === $token->id ) { - // ADD COLUMN. - $field_definition = $action->get_descendant_node( 'fieldDefinition' ); - if ( null !== $field_definition ) { - $field_name = $this->translate( $action->get_child_node( 'identifier' ) ); - $field = $this->translate( $field_definition ); - $this->execute_sqlite_query( - sprintf( 'ALTER TABLE %s ADD COLUMN %s %s', $table_name, $field_name, $field ) - ); - } - - // ADD CONSTRAINT. - $constraint = $action->get_descendant_node( 'tableConstraintDef' ); - if ( null !== $constraint ) { - $constraint_name = $this->translate( $constraint->get_child_node( 'identifier' ) ); - $constraint = $this->translate( $constraint ); - $this->execute_sqlite_query( - sprintf( 'ALTER TABLE %s ADD CONSTRAINT %s %s', $table_name, $constraint_name, $constraint ) - ); - } - } elseif ( WP_MySQL_Lexer::DROP_SYMBOL === $token->id ) { - // DROP COLUMN. - $field_name = $this->translate( $action->get_child_node( 'columnInternalRef' ) ); - if ( null !== $field_name ) { - $this->execute_sqlite_query( - sprintf( 'ALTER TABLE %s DROP COLUMN %s', $table_name, $field_name ) - ); - } - } - } - - $this->set_result_from_affected_rows(); } private function translate( $ast ) { From a0a67c05538f946633331c2fd378c765c333a371 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 20 Dec 2024 12:28:55 +0100 Subject: [PATCH 28/36] Implement SHOW CREATE TABLE using information schema --- tests/WP_SQLite_Driver_Tests.php | 78 ++++----- .../sqlite-ast/class-wp-sqlite-driver.php | 150 ++++++++++++++++++ 2 files changed, 189 insertions(+), 39 deletions(-) diff --git a/tests/WP_SQLite_Driver_Tests.php b/tests/WP_SQLite_Driver_Tests.php index cd3c3ed7..471782c0 100644 --- a/tests/WP_SQLite_Driver_Tests.php +++ b/tests/WP_SQLite_Driver_Tests.php @@ -288,13 +288,13 @@ public function testShowCreateTable1() { # TODO: Should we fix mismatch with original `option_value` text NOT NULL,` without default? $this->assertEquals( "CREATE TABLE `_tmp_table` ( - `ID` bigint NOT NULL AUTO_INCREMENT, - `option_name` varchar(255) DEFAULT '', - `option_value` text NOT NULL DEFAULT '', - PRIMARY KEY (`ID`), - KEY `composite` (`option_name`, `option_value`), - UNIQUE KEY `option_name` (`option_name`) -);", + `ID` bigint NOT NULL AUTO_INCREMENT, + `option_name` varchar(255) DEFAULT '', + `option_value` text NOT NULL, + PRIMARY KEY (`ID`), + UNIQUE KEY `option_name` (`option_name`), + KEY `composite` (`option_name`, `option_value`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci", $results[0]->{'Create Table'} ); } @@ -317,13 +317,13 @@ public function testShowCreateTableQuoted() { # TODO: Should we fix mismatch with original `option_value` text NOT NULL,` without default? $this->assertEquals( "CREATE TABLE `_tmp_table` ( - `ID` bigint NOT NULL AUTO_INCREMENT, - `option_name` varchar(255) DEFAULT '', - `option_value` text NOT NULL DEFAULT '', - PRIMARY KEY (`ID`), - KEY `composite` (`option_name`, `option_value`), - UNIQUE KEY `option_name` (`option_name`) -);", + `ID` bigint NOT NULL AUTO_INCREMENT, + `option_name` varchar(255) DEFAULT '', + `option_value` text NOT NULL, + PRIMARY KEY (`ID`), + UNIQUE KEY `option_name` (`option_name`), + KEY `composite` (`option_name`, `option_value`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci", $results[0]->{'Create Table'} ); } @@ -341,8 +341,8 @@ public function testShowCreateTableSimpleTable() { $results = $this->engine->get_query_results(); $this->assertEquals( 'CREATE TABLE `_tmp_table` ( - `ID` bigint NOT NULL DEFAULT 0 -);', + `ID` bigint NOT NULL +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci', $results[0]->{'Create Table'} ); } @@ -370,12 +370,12 @@ public function testShowCreateTableWithAlterAndCreateIndex() { $results = $this->engine->get_query_results(); $this->assertEquals( 'CREATE TABLE `_tmp_table` ( - `ID` bigint NOT NULL AUTO_INCREMENT, - `option_name` smallint NOT NULL DEFAULT 14, - `option_value` text NOT NULL DEFAULT \'\', - PRIMARY KEY (`ID`), - KEY `option_name` (`option_name`) -);', + `ID` bigint NOT NULL AUTO_INCREMENT, + `option_name` smallint NOT NULL DEFAULT \'14\', + `option_value` text NOT NULL, + PRIMARY KEY (`ID`), + KEY `option_name` (`option_name`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci', $results[0]->{'Create Table'} ); } @@ -419,13 +419,13 @@ public function testShowCreateTablePreservesDoubleUnderscoreKeyNames() { $results = $this->engine->get_query_results(); $this->assertEquals( 'CREATE TABLE `_tmp__table` ( - `ID` bigint NOT NULL AUTO_INCREMENT, - `option_name` varchar(255) DEFAULT \'\', - `option_value` text NOT NULL DEFAULT \'\', - PRIMARY KEY (`ID`), - KEY `double__underscores` (`option_name`, `ID`), - KEY `option_name` (`option_name`) -);', + `ID` bigint NOT NULL AUTO_INCREMENT, + `option_name` varchar(255) DEFAULT \'\', + `option_value` text NOT NULL, + PRIMARY KEY (`ID`), + KEY `option_name` (`option_name`), + KEY `double__underscores` (`option_name`, `ID`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci', $results[0]->{'Create Table'} ); } @@ -446,11 +446,11 @@ public function testShowCreateTableWithPrimaryKeyColumnsReverseOrdered() { $results = $this->engine->get_query_results(); $this->assertEquals( 'CREATE TABLE `_tmp_table` ( - `ID_A` bigint NOT NULL DEFAULT 0, - `ID_B` bigint NOT NULL DEFAULT 0, - `ID_C` bigint NOT NULL DEFAULT 0, - PRIMARY KEY (`ID_B`, `ID_A`, `ID_C`) -);', + `ID_A` bigint NOT NULL, + `ID_B` bigint NOT NULL, + `ID_C` bigint NOT NULL, + PRIMARY KEY (`ID_B`, `ID_A`, `ID_C`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci', $results[0]->{'Create Table'} ); } @@ -481,11 +481,11 @@ public function testShowCreateTableWithCorrectDefaultValues() { $results = $this->engine->get_query_results(); $this->assertEquals( 'CREATE TABLE `_tmp__table` ( - `ID` bigint NOT NULL AUTO_INCREMENT, - `default_empty_string` varchar(255) DEFAULT \'\', - `null_no_default` varchar(255), - PRIMARY KEY (`ID`) -);', + `ID` bigint NOT NULL AUTO_INCREMENT, + `default_empty_string` varchar(255) DEFAULT \'\', + `null_no_default` varchar(255), + PRIMARY KEY (`ID`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci', $results[0]->{'Create Table'} ); } diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 684e95c2..a4c98a17 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -913,6 +913,10 @@ private function execute_mysql_query( WP_Parser_Node $ast ) { */ $this->results = 0; break; + case 'showStatement': + $this->query_type = 'SHOW'; + $this->execute_show_statement( $ast ); + break; default: throw new Exception( sprintf( 'Unsupported statement type: "%s"', $ast->rule_name ) ); } @@ -1127,6 +1131,38 @@ function ( $column ) { */ } + private function execute_show_statement( WP_Parser_Node $node ): void { + $tokens = $node->get_child_tokens(); + $keyword1 = $tokens[1]; + $keyword2 = $tokens[2] ?? null; + + switch ( $keyword1->id ) { + case WP_MySQL_Lexer::CREATE_SYMBOL: + if ( WP_MySQL_Lexer::TABLE_SYMBOL === $keyword2->id ) { + $table_name = $this->unquote_sqlite_identifier( + $this->translate( $node->get_child_node( 'tableRef' ) ) + ); + + $sql = $this->get_mysql_create_table_statement( $table_name ); + if ( null === $sql ) { + $this->set_results_from_fetched_data( array() ); + } else { + $this->set_results_from_fetched_data( + array( + (object) array( + 'Create Table' => $sql, + ), + ) + ); + } + return; + } + // Fall through to default. + default: + // @TODO + } + } + private function translate( $ast ) { if ( null === $ast ) { return null; @@ -1378,6 +1414,120 @@ function ( $column ) { return array_merge( array( $sql ), $create_index_sqls ); } + private function get_mysql_create_table_statement( string $table_name ): ?string { + // 1. Get table info. + $table_info = $this->execute_sqlite_query( + ' + SELECT * + FROM _mysql_information_schema_tables + WHERE table_type = "BASE TABLE" + AND table_schema = ? + AND table_name = ? + ', + array( $this->db_name, $table_name ) + )->fetch( PDO::FETCH_ASSOC ); + + if ( false === $table_info ) { + return null; + } + + // 2. Get column info. + $column_info = $this->execute_sqlite_query( + 'SELECT * FROM _mysql_information_schema_columns WHERE table_schema = ? AND table_name = ?', + array( $this->db_name, $table_name ) + )->fetchAll( PDO::FETCH_ASSOC ); + + // 3. Get index info, grouped by index name. + $constraint_info = $this->execute_sqlite_query( + 'SELECT * FROM _mysql_information_schema_statistics WHERE table_schema = ? AND table_name = ?', + array( $this->db_name, $table_name ) + )->fetchAll( PDO::FETCH_ASSOC ); + + $grouped_constraints = array(); + foreach ( $constraint_info as $constraint ) { + $name = $constraint['INDEX_NAME']; + $seq = $constraint['SEQ_IN_INDEX']; + $grouped_constraints[ $name ][ $seq ] = $constraint; + } + + // 4. Generate CREATE TABLE statement columns. + $rows = array(); + foreach ( $column_info as $column ) { + $sql = ' '; + // @TODO: Proper identifier escaping. + $sql .= sprintf( '`%s`', str_replace( '`', '``', $column['COLUMN_NAME'] ) ); + + $sql .= ' ' . $column['COLUMN_TYPE']; + if ( 'NO' === $column['IS_NULLABLE'] ) { + $sql .= ' NOT NULL'; + } + if ( 'auto_increment' === $column['EXTRA'] ) { + $sql .= ' AUTO_INCREMENT'; + } + if ( null !== $column['COLUMN_DEFAULT'] ) { + // @TODO: Correctly quote based on the data type. + $sql .= ' DEFAULT ' . $this->pdo->quote( $column['COLUMN_DEFAULT'] ); + } + $rows[] = $sql; + } + + // 4. Generate CREATE TABLE statement constraints, collect indexes. + foreach ( $grouped_constraints as $constraint ) { + ksort( $constraint ); + $info = $constraint[1]; + + if ( 'PRIMARY' === $info['INDEX_NAME'] ) { + $sql = ' PRIMARY KEY ('; + $sql .= implode( + ', ', + array_map( + function ( $column ) { + // @TODO: Proper identifier escaping. + return sprintf( '`%s`', str_replace( '`', '``', $column['COLUMN_NAME'] ) ); + }, + $constraint + ) + ); + $sql .= ')'; + $rows[] = $sql; + } else { + $is_unique = '0' === $info['NON_UNIQUE']; + + $sql = sprintf( ' %sKEY', $is_unique ? 'UNIQUE ' : '' ); + // @TODO: Proper identifier escaping. + $sql .= sprintf( ' `%s`', str_replace( '`', '``', $info['INDEX_NAME'] ) ); + $sql .= ' ('; + $sql .= implode( + ', ', + array_map( + function ( $column ) { + // @TODO: Proper identifier escaping. + return sprintf( '`%s`', str_replace( '`', '``', $column['COLUMN_NAME'] ) ); + }, + $constraint + ) + ); + $sql .= ')'; + + $rows[] = $sql; + } + } + + // 5. Compose the CREATE TABLE statement. + // @TODO: Proper identifier escaping. + $sql = sprintf( 'CREATE TABLE `%s` (%s', str_replace( '`', '``', $table_name ), "\n" ); + $sql .= implode( ",\n", $rows ); + $sql .= "\n)"; + + $sql .= sprintf( ' ENGINE=%s', $table_info['ENGINE'] ); + + $collation = $table_info['TABLE_COLLATION']; + $charset = substr( $collation, 0, strpos( $collation, '_' ) ); + $sql .= sprintf( ' DEFAULT CHARSET=%s', $charset ); + $sql .= sprintf( ' COLLATE=%s', $collation ); + return $sql; + } + private function unquote_sqlite_identifier( string $quoted_identifier ): string { $first_byte = $quoted_identifier[0] ?? null; if ( '"' === $first_byte ) { From 837655c177d9ea26ddee1f7485595931f2c0c18d Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 20 Dec 2024 12:31:21 +0100 Subject: [PATCH 29/36] Implement SHOW INDEX using information schema --- .../sqlite-ast/class-wp-sqlite-driver.php | 37 +++++++++++++++++++ 1 file changed, 37 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index a4c98a17..a3a96c21 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -1158,11 +1158,48 @@ private function execute_show_statement( WP_Parser_Node $node ): void { return; } // Fall through to default. + case WP_MySQL_Lexer::INDEX_SYMBOL: + case WP_MySQL_Lexer::INDEXES_SYMBOL: + case WP_MySQL_Lexer::KEYS_SYMBOL: + $table_name = $this->unquote_sqlite_identifier( + $this->translate( $node->get_child_node( 'tableRef' ) ) + ); + $this->execute_show_index_statement( $table_name ); + break; default: // @TODO } } + private function execute_show_index_statement( string $table_name ): void { + $index_info = $this->execute_sqlite_query( + ' + SELECT + TABLE_NAME AS `Table`, + NON_UNIQUE AS `Non_unique`, + INDEX_NAME AS `Key_name`, + SEQ_IN_INDEX AS `Seq_in_index`, + COLUMN_NAME AS `Column_name`, + COLLATION AS `Collation`, + CARDINALITY AS `Cardinality`, + SUB_PART AS `Sub_part`, + PACKED AS `Packed`, + NULLABLE AS `Null`, + INDEX_TYPE AS `Index_type`, + COMMENT AS `Comment`, + INDEX_COMMENT AS `Index_comment`, + IS_VISIBLE AS `Visible`, + EXPRESSION AS `Expression` + FROM _mysql_information_schema_statistics + WHERE table_schema = ? + AND table_name = ? + ', + array( $this->db_name, $table_name ) + )->fetchAll( PDO::FETCH_OBJ ); + + $this->set_results_from_fetched_data( $index_info ); + } + private function translate( $ast ) { if ( null === $ast ) { return null; From f11fb09b413cb4171d5a1a5ebe00fd48c9e66b7b Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 20 Dec 2024 12:32:09 +0100 Subject: [PATCH 30/36] Implement SHOW GRANTS --- wp-includes/sqlite-ast/class-wp-sqlite-driver.php | 9 +++++++++ 1 file changed, 9 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index a3a96c21..0d2d73d3 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -1166,6 +1166,15 @@ private function execute_show_statement( WP_Parser_Node $node ): void { ); $this->execute_show_index_statement( $table_name ); break; + case WP_MySQL_Lexer::GRANTS_SYMBOL: + $this->set_results_from_fetched_data( + array( + (object) array( + 'Grants for root@localhost' => 'GRANT SELECT, INSERT, UPDATE, DELETE, CREATE, DROP, RELOAD, SHUTDOWN, PROCESS, FILE, REFERENCES, INDEX, ALTER, SHOW DATABASES, SUPER, CREATE TEMPORARY TABLES, LOCK TABLES, EXECUTE, REPLICATION SLAVE, REPLICATION CLIENT, CREATE VIEW, SHOW VIEW, CREATE ROUTINE, ALTER ROUTINE, CREATE USER, EVENT, TRIGGER, CREATE TABLESPACE, CREATE ROLE, DROP ROLE ON *.* TO `root`@`localhost` WITH GRANT OPTION', + ), + ) + ); + return; default: // @TODO } From cf6008d50fbe26262cc68d588bffaf687973fd9f Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 20 Dec 2024 12:32:33 +0100 Subject: [PATCH 31/36] Implement DESCRIBE using information schema --- tests/WP_SQLite_Driver_Tests.php | 72 ++++++++++--------- .../sqlite-ast/class-wp-sqlite-driver.php | 41 +++++++++++ 2 files changed, 80 insertions(+), 33 deletions(-) diff --git a/tests/WP_SQLite_Driver_Tests.php b/tests/WP_SQLite_Driver_Tests.php index 471782c0..2e658cb5 100644 --- a/tests/WP_SQLite_Driver_Tests.php +++ b/tests/WP_SQLite_Driver_Tests.php @@ -724,14 +724,14 @@ public function testCreateTable() { 'Type' => 'bigint(20) unsigned', 'Null' => 'NO', 'Key' => 'PRI', - 'Default' => '0', - 'Extra' => '', + 'Default' => null, + 'Extra' => 'auto_increment', ), (object) array( 'Field' => 'user_login', 'Type' => 'varchar(60)', 'Null' => 'NO', - 'Key' => '', + 'Key' => 'MUL', 'Default' => '', 'Extra' => '', ), @@ -747,7 +747,7 @@ public function testCreateTable() { 'Field' => 'user_nicename', 'Type' => 'varchar(50)', 'Null' => 'NO', - 'Key' => '', + 'Key' => 'MUL', 'Default' => '', 'Extra' => '', ), @@ -755,7 +755,7 @@ public function testCreateTable() { 'Field' => 'user_email', 'Type' => 'varchar(100)', 'Null' => 'NO', - 'Key' => '', + 'Key' => 'MUL', 'Default' => '', 'Extra' => '', ), @@ -848,8 +848,8 @@ enum_column ENUM('a', 'b', 'c') NOT NULL DEFAULT 'a', 'Type' => 'bigint(20) unsigned', 'Null' => 'NO', 'Key' => 'PRI', - 'Default' => '0', - 'Extra' => '', + 'Default' => null, + 'Extra' => 'auto_increment', ), (object) array( 'Field' => 'decimal_column', @@ -1052,7 +1052,7 @@ public function testColumnWithOnUpdate() { 'Type' => 'int(11)', 'Null' => 'NO', 'Key' => '', - 'Default' => '0', + 'Default' => null, 'Extra' => '', ), (object) array( @@ -1061,7 +1061,7 @@ public function testColumnWithOnUpdate() { 'Null' => 'YES', 'Key' => '', 'Default' => null, - 'Extra' => '', + 'Extra' => 'on update CURRENT_TIMESTAMP', ), ), $results @@ -1079,7 +1079,7 @@ public function testColumnWithOnUpdate() { 'Type' => 'int(11)', 'Null' => 'NO', 'Key' => '', - 'Default' => '0', + 'Default' => null, 'Extra' => '', ), (object) array( @@ -1088,7 +1088,7 @@ public function testColumnWithOnUpdate() { 'Null' => 'YES', 'Key' => '', 'Default' => null, - 'Extra' => '', + 'Extra' => 'on update CURRENT_TIMESTAMP', ), (object) array( 'Field' => 'updated_at', @@ -1096,7 +1096,7 @@ public function testColumnWithOnUpdate() { 'Null' => 'YES', 'Key' => '', 'Default' => null, - 'Extra' => '', + 'Extra' => 'on update CURRENT_TIMESTAMP', ), ), $results @@ -1221,7 +1221,7 @@ public function testChangeColumnWithOnUpdate() { 'Type' => 'int(11)', 'Null' => 'NO', 'Key' => '', - 'Default' => '0', + 'Default' => null, 'Extra' => '', ), (object) array( @@ -1254,7 +1254,7 @@ public function testChangeColumnWithOnUpdate() { 'Type' => 'int(11)', 'Null' => 'NO', 'Key' => '', - 'Default' => '0', + 'Default' => null, 'Extra' => '', ), (object) array( @@ -1263,7 +1263,7 @@ public function testChangeColumnWithOnUpdate() { 'Null' => 'YES', 'Key' => '', 'Default' => null, - 'Extra' => '', + 'Extra' => 'on update CURRENT_TIMESTAMP', ), ), $results @@ -1286,7 +1286,7 @@ public function testChangeColumnWithOnUpdate() { 'Type' => 'int(11)', 'Null' => 'NO', 'Key' => '', - 'Default' => '0', + 'Default' => null, 'Extra' => '', ), (object) array( @@ -1328,7 +1328,7 @@ public function testAlterTableWithColumnFirstAndAfter() { 'Type' => 'int(11)', 'Null' => 'NO', 'Key' => '', - 'Default' => '0', + 'Default' => null, 'Extra' => '', ), (object) array( @@ -1336,7 +1336,7 @@ public function testAlterTableWithColumnFirstAndAfter() { 'Type' => 'varchar(20)', 'Null' => 'NO', 'Key' => '', - 'Default' => null, + 'Default' => '', 'Extra' => '', ), (object) array( @@ -1363,7 +1363,7 @@ public function testAlterTableWithColumnFirstAndAfter() { 'Type' => 'int(11)', 'Null' => 'NO', 'Key' => '', - 'Default' => '0', + 'Default' => null, 'Extra' => '', ), (object) array( @@ -1457,7 +1457,7 @@ public function testAlterTableWithColumnFirstAndAfter() { 'Type' => 'varchar(20)', 'Null' => 'NO', 'Key' => '', - 'Default' => null, + 'Default' => '', 'Extra' => '', ), (object) array( @@ -1503,7 +1503,7 @@ public function testAlterTableWithMultiColumnFirstAndAfter() { 'Type' => 'int(11)', 'Null' => 'NO', 'Key' => '', - 'Default' => '0', + 'Default' => null, 'Extra' => '', ), (object) array( @@ -1549,7 +1549,7 @@ public function testAlterTableWithMultiColumnFirstAndAfter() { 'Type' => 'int(11)', 'Null' => 'NO', 'Key' => '', - 'Default' => '0', + 'Default' => null, 'Extra' => '', ), (object) array( @@ -1600,7 +1600,7 @@ public function testAlterTableAddIndex() { 'Table' => '_tmp_table', 'Non_unique' => '1', 'Key_name' => 'name', - 'Seq_in_index' => '0', + 'Seq_in_index' => '1', 'Column_name' => 'name', 'Collation' => 'A', 'Cardinality' => '0', @@ -1610,6 +1610,8 @@ public function testAlterTableAddIndex() { 'Index_type' => 'BTREE', 'Comment' => '', 'Index_comment' => '', + 'Visible' => 'YES', + 'Expression' => null, ), ), $results @@ -1635,16 +1637,18 @@ public function testAlterTableAddUniqueIndex() { 'Table' => '_tmp_table', 'Non_unique' => '0', 'Key_name' => 'name', - 'Seq_in_index' => '0', + 'Seq_in_index' => '1', 'Column_name' => 'name', 'Collation' => 'A', 'Cardinality' => '0', - 'Sub_part' => null, + 'Sub_part' => '20', 'Packed' => null, 'Null' => '', 'Index_type' => 'BTREE', 'Comment' => '', 'Index_comment' => '', + 'Visible' => 'YES', + 'Expression' => null, ), ), $results @@ -1670,9 +1674,9 @@ public function testAlterTableAddFulltextIndex() { 'Table' => '_tmp_table', 'Non_unique' => '1', 'Key_name' => 'name', - 'Seq_in_index' => '0', + 'Seq_in_index' => '1', 'Column_name' => 'name', - 'Collation' => 'A', + 'Collation' => null, 'Cardinality' => '0', 'Sub_part' => null, 'Packed' => null, @@ -1680,6 +1684,8 @@ public function testAlterTableAddFulltextIndex() { 'Index_type' => 'FULLTEXT', 'Comment' => '', 'Index_comment' => '', + 'Visible' => 'YES', + 'Expression' => null, ), ), $results @@ -2167,15 +2173,14 @@ public function testNestedTransactionWorkComplexModify() { $fields = $this->engine->get_query_results(); $this->assertEquals( - $fields, array( (object) array( 'Field' => 'ID', - 'Type' => 'integer', + 'Type' => 'int', 'Null' => 'NO', 'Key' => 'PRI', - 'Default' => '0', - 'Extra' => '', + 'Default' => null, + 'Extra' => 'auto_increment', ), (object) array( 'Field' => 'option_name', @@ -2193,7 +2198,8 @@ public function testNestedTransactionWorkComplexModify() { 'Default' => '', 'Extra' => '', ), - ) + ), + $fields ); } @@ -2426,7 +2432,7 @@ public function testDescribeAccurate() { 'Field' => 'term_name', 'Type' => 'varchar(11)', 'Null' => 'NO', - 'Key' => '', + 'Key' => 'MUL', 'Default' => '0', 'Extra' => '', ), diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 0d2d73d3..58a7bd4d 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -917,6 +917,23 @@ private function execute_mysql_query( WP_Parser_Node $ast ) { $this->query_type = 'SHOW'; $this->execute_show_statement( $ast ); break; + case 'utilityStatement': + $this->query_type = 'DESCRIBE'; + $subtree = $ast->get_child_node(); + switch ( $subtree->rule_name ) { + case 'describeStatement': + $this->execute_describe_statement( $subtree ); + break; + default: + throw new Exception( + sprintf( + 'Unsupported statement type: "%s" > "%s"', + $ast->rule_name, + $subtree->rule_name + ) + ); + } + break; default: throw new Exception( sprintf( 'Unsupported statement type: "%s"', $ast->rule_name ) ); } @@ -1209,6 +1226,30 @@ private function execute_show_index_statement( string $table_name ): void { $this->set_results_from_fetched_data( $index_info ); } + private function execute_describe_statement( WP_Parser_Node $node ): void { + $table_name = $this->unquote_sqlite_identifier( + $this->translate( $node->get_child_node( 'tableRef' ) ) + ); + + $column_info = $this->execute_sqlite_query( + ' + SELECT + column_name AS `Field`, + column_type AS `Type`, + is_nullable AS `Null`, + column_key AS `Key`, + column_default AS `Default`, + extra AS Extra + FROM _mysql_information_schema_columns + WHERE table_schema = ? + AND table_name = ? + ', + array( $this->db_name, $table_name ) + )->fetchAll( PDO::FETCH_OBJ ); + + $this->set_results_from_fetched_data( $column_info ); + } + private function translate( $ast ) { if ( null === $ast ) { return null; From f5a52cadc6249ece1a9a83388abc71b455793bd8 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 20 Dec 2024 12:32:57 +0100 Subject: [PATCH 32/36] Ignore index hints --- wp-includes/sqlite-ast/class-wp-sqlite-driver.php | 3 +++ 1 file changed, 3 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 58a7bd4d..30752a07 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -1328,6 +1328,9 @@ private function translate( $ast ) { // The "AS" keyword is optional in MySQL, but required in SQLite. return 'AS ' . $this->translate( $ast->get_child_node() ); + case 'indexHint': + case 'indexHintList': + return null; default: return $this->translate_sequence( $ast->get_children() ); } From 174916ac7736a7465f10845cd90bebe55e73aa88 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 10 Jan 2025 10:09:42 +0100 Subject: [PATCH 33/36] Add support for LIKE BINARY --- tests/WP_SQLite_Driver_Tests.php | 119 ++++++++----- .../sqlite-ast/class-wp-sqlite-driver.php | 46 +++++ ...s-wp-sqlite-pdo-user-defined-functions.php | 163 +++++++++++++----- 3 files changed, 250 insertions(+), 78 deletions(-) diff --git a/tests/WP_SQLite_Driver_Tests.php b/tests/WP_SQLite_Driver_Tests.php index 2e658cb5..13bbfcf9 100644 --- a/tests/WP_SQLite_Driver_Tests.php +++ b/tests/WP_SQLite_Driver_Tests.php @@ -3033,13 +3033,13 @@ public function testTranslatesUtf8SELECT() { $this->assertQuery( 'DELETE FROM _options' ); } - public function testTranslateLikeBinaryAndGlob() { + public function testTranslateLikeBinary() { // Create a temporary table for testing $this->assertQuery( - "CREATE TABLE _tmp_table ( - ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, - name varchar(20) NOT NULL default '' - );" + 'CREATE TABLE _tmp_table ( + ID INTEGER PRIMARY KEY AUTO_INCREMENT NOT NULL, + name varchar(20) + )' ); // Insert data into the table @@ -3052,70 +3052,111 @@ public function testTranslateLikeBinaryAndGlob() { $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('special%chars');" ); $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('special_chars');" ); $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('special\\chars');" ); + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('aste*risk');" ); + $this->assertQuery( "INSERT INTO _tmp_table (name) VALUES ('question?mark');" ); - // Test case-sensitive LIKE BINARY + // Test exact string $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'first'" ); $this->assertCount( 1, $result ); $this->assertEquals( 'first', $result[0]->name ); - // Test case-sensitive LIKE BINARY with wildcard % + // Test exact string with no matches + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'third'" ); + $this->assertCount( 0, $result ); + + // Test mixed case + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'First'" ); + $this->assertCount( 0, $result ); + + // Test % wildcard $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f%'" ); $this->assertCount( 1, $result ); $this->assertEquals( 'first', $result[0]->name ); - // Test case-sensitive LIKE BINARY with wildcard _ + // Test % wildcard with no matches + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'x%'" ); + $this->assertCount( 0, $result ); + + // Test "%" character (not a wildcard) + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'special\\%chars'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'special%chars', $result[0]->name ); + + // Test _ wildcard $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f_rst'" ); $this->assertCount( 1, $result ); $this->assertEquals( 'first', $result[0]->name ); - // Test case-insensitive LIKE - $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE 'FIRST'" ); - $this->assertCount( 2, $result ); // Should match both 'first' and 'FIRST' - - // Test mixed case with LIKE BINARY - $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'First'" ); - $this->assertCount( 0, $result ); - - // Test no matches with LIKE BINARY - $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'third'" ); + // Test _ wildcard with no matches + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'x_yz'" ); $this->assertCount( 0, $result ); - // Test GLOB equivalent for case-sensitive matching with wildcard - $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'f*'" ); + // Test "_" character (not a wildcard) + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'special\\_chars'" ); $this->assertCount( 1, $result ); - $this->assertEquals( 'first', $result[0]->name ); + $this->assertEquals( 'special_chars', $result[0]->name ); - // Test GLOB with single character wildcard - $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'f?rst'" ); + // Test escaping of "*" + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'aste*risk'" ); $this->assertCount( 1, $result ); - $this->assertEquals( 'first', $result[0]->name ); + $this->assertEquals( 'aste*risk', $result[0]->name ); - // Test GLOB with no matches - $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'S*'" ); + // Test escaping of "*" with no matches + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f*'" ); $this->assertCount( 0, $result ); - // Test GLOB case sensitivity with LIKE and GLOB - $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'first';" ); - $this->assertCount( 1, $result ); // Should only match 'first' + // Test escaping of "?" + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'question?mark'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'question?mark', $result[0]->name ); - $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name GLOB 'FIRST';" ); - $this->assertCount( 1, $result ); // Should only match 'FIRST' + // Test escaping of "?" with no matches + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'f?rst'" ); + $this->assertCount( 0, $result ); - // Test NULL comparison with LIKE BINARY - $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'first';" ); - $this->assertCount( 1, $result ); - $this->assertEquals( 'first', $result[0]->name ); + // Test escaping of character class + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY '[f]irst'" ); + $this->assertCount( 0, $result ); - $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE name LIKE BINARY NULL;' ); - $this->assertCount( 0, $result ); // NULL comparison should return no results + // Test NULL + $result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE name LIKE BINARY NULL' ); + $this->assertCount( 0, $result ); // Test pattern with special characters using LIKE BINARY - $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY '%special%';" ); + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY '%special%'" ); $this->assertCount( 4, $result ); $this->assertEquals( '%special%', $result[0]->name ); $this->assertEquals( 'special%chars', $result[1]->name ); $this->assertEquals( 'special_chars', $result[2]->name ); - $this->assertEquals( 'specialchars', $result[3]->name ); + $this->assertEquals( 'special\chars', $result[3]->name ); + + // Test escaping - "\t" is a tab character + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'firs\\t'" ); + $this->assertCount( 0, $result ); + + // Test escaping - "\\t" is "t" (input resolves to "\t", which LIKE resolves to "t") + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'firs\\\\t'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'first', $result[0]->name ); + + // Test escaping - "\%" is a "%" literal + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'special\\%chars'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'special%chars', $result[0]->name ); + + // Test escaping - "\\%" is also a "%" literal + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'special\\\\%chars'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'special%chars', $result[0]->name ); + + // Test escaping - "\\\%" is "\" and a wildcard + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE BINARY 'special\\\\\\%chars'" ); + $this->assertCount( 1, $result ); + $this->assertEquals( 'special\\chars', $result[0]->name ); + + // Test LIKE without BINARY + $result = $this->assertQuery( "SELECT * FROM _tmp_table WHERE name LIKE 'FIRST'" ); + $this->assertCount( 2, $result ); // Should match both 'first' and 'FIRST' } public function testOnConflictReplace() { diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 30752a07..d18d92a1 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -1313,6 +1313,12 @@ private function translate( $ast ) { throw $this->not_supported_exception( sprintf( 'data type: %s', $child->value ) ); + case 'predicateOperations': + $token = $ast->get_child_token(); + if ( WP_MySQL_Lexer::LIKE_SYMBOL === $token->id ) { + return $this->translate_like( $ast ); + } + return $this->translate_sequence( $ast->get_children() ); case 'systemVariable': // @TODO: Emulate some system variables, or use reasonable defaults. // See: https://dev.mysql.com/doc/refman/8.4/en/server-system-variable-reference.html @@ -1346,6 +1352,13 @@ private function translate_token( WP_MySQL_Token $token ) { return '"' . trim( $token->value, '`"' ) . '"'; case WP_MySQL_Lexer::AUTO_INCREMENT_SYMBOL: return 'AUTOINCREMENT'; + case WP_MySQL_Lexer::BINARY_SYMBOL: + /* + * There is no "BINARY expr" equivalent in SQLite. We can look for + * the BINARY keyword in particular cases (with REGEXP, LIKE, etc.) + * and then remove it from the translated output here. + */ + return null; default: return $token->value; } @@ -1370,6 +1383,39 @@ private function translate_sequence( array $nodes, string $separator = ' ' ): ?s return implode( $separator, $parts ); } + private function translate_like( WP_Parser_Node $node ): string { + $tokens = $node->get_descendant_tokens(); + $is_binary = isset( $tokens[1] ) && WP_MySQL_Lexer::BINARY_SYMBOL === $tokens[1]->id; + + if ( true === $is_binary ) { + $children = $node->get_children(); + return sprintf( + 'GLOB _helper_like_to_glob_pattern(%s)', + $this->translate( $children[1] ) + ); + } + + /* + * @TODO: Implement the ESCAPE '...' clause. + */ + + /* + * @TODO: Implement more correct LIKE behavior. + * + * While SQLite supports the LIKE operator, it seems to differ from the + * MySQL behavior in some ways: + * + * 1. In SQLite, LIKE is case-insensitive only for ASCII characters + * ('a' LIKE 'A' is TRUE but 'æ' LIKE 'Æ' is FALSE) + * 2. In MySQL, LIKE interprets some escape sequences. See the contents + * of the "_helper_like_to_glob_pattern" function. + * + * We'll probably need to overload the like() function: + * https://www.sqlite.org/lang_corefunc.html#like + */ + return $this->translate_sequence( $node->get_children() ); + } + private function get_sqlite_create_table_statement( string $table_name, ?string $new_table_name = null ): array { // 1. Get table info. $table_info = $this->execute_sqlite_query( 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 6f0d83df..010e5a92 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 @@ -46,45 +46,48 @@ public function __construct( $pdo ) { * @var array */ private $functions = array( - 'month' => 'month', - 'monthnum' => 'month', - 'year' => 'year', - 'day' => 'day', - 'hour' => 'hour', - 'minute' => 'minute', - 'second' => 'second', - 'week' => 'week', - 'weekday' => 'weekday', - 'dayofweek' => 'dayofweek', - 'dayofmonth' => 'dayofmonth', - 'unix_timestamp' => 'unix_timestamp', - 'now' => 'now', - 'md5' => 'md5', - 'curdate' => 'curdate', - 'rand' => 'rand', - 'from_unixtime' => 'from_unixtime', - 'localtime' => 'now', - 'localtimestamp' => 'now', - 'isnull' => 'isnull', - 'if' => '_if', - 'regexp' => 'regexp', - 'field' => 'field', - 'log' => 'log', - 'least' => 'least', - 'greatest' => 'greatest', - 'get_lock' => 'get_lock', - 'release_lock' => 'release_lock', - 'ucase' => 'ucase', - 'lcase' => 'lcase', - 'unhex' => 'unhex', - 'inet_ntoa' => 'inet_ntoa', - 'inet_aton' => 'inet_aton', - 'datediff' => 'datediff', - 'locate' => 'locate', - 'utc_date' => 'utc_date', - 'utc_time' => 'utc_time', - 'utc_timestamp' => 'utc_timestamp', - 'version' => 'version', + 'month' => 'month', + 'monthnum' => 'month', + 'year' => 'year', + 'day' => 'day', + 'hour' => 'hour', + 'minute' => 'minute', + 'second' => 'second', + 'week' => 'week', + 'weekday' => 'weekday', + 'dayofweek' => 'dayofweek', + 'dayofmonth' => 'dayofmonth', + 'unix_timestamp' => 'unix_timestamp', + 'now' => 'now', + 'md5' => 'md5', + 'curdate' => 'curdate', + 'rand' => 'rand', + 'from_unixtime' => 'from_unixtime', + 'localtime' => 'now', + 'localtimestamp' => 'now', + 'isnull' => 'isnull', + 'if' => '_if', + 'regexp' => 'regexp', + 'field' => 'field', + 'log' => 'log', + 'least' => 'least', + 'greatest' => 'greatest', + 'get_lock' => 'get_lock', + 'release_lock' => 'release_lock', + 'ucase' => 'ucase', + 'lcase' => 'lcase', + 'unhex' => 'unhex', + 'inet_ntoa' => 'inet_ntoa', + 'inet_aton' => 'inet_aton', + 'datediff' => 'datediff', + 'locate' => 'locate', + 'utc_date' => 'utc_date', + 'utc_time' => 'utc_time', + 'utc_timestamp' => 'utc_timestamp', + 'version' => 'version', + + // Internal helper functions. + '_helper_like_to_glob_pattern' => '_helper_like_to_glob_pattern', ); /** @@ -759,4 +762,86 @@ public function utc_timestamp() { public function version() { return '5.5'; } + + /** + * A helper to covert LIKE pattern to a GLOB pattern for "LIKE BINARY" support. + + * @TODO: Some of the MySQL string specifics described below are likely to + * affect also other patterns than just "LIKE BINARY". We should + * consider applying some of the conversions more broadly. + * + * @param string $pattern + * @return string + */ + public function _helper_like_to_glob_pattern( $pattern ) { + if ( null === $pattern ) { + return null; + } + + /* + * 1. Normalize escaping of "%" and "_" characters. + * + * MySQL has unusual handling for "\%" and "\_" in all string literals. + * While other sequences follow the C-style escaping ("\?" is "?", etc.), + * "\%" resolves to "\%" and "\_" resolves to "\_" (unlike in C strings). + * + * This means that "\%" behaves like "\\%", and "\_" behaves like "\\_". + * To preserve this behavior, we need to add a second backslash in cases + * where only one is used. To do so correctly, we need to: + * + * 1. Skip all double backslash patterns (as "\\" resolves to "\"). + * 2. Add an extra backslash when "\%" or "\_" follows right after. + * + * This may be related to: https://bugs.mysql.com/bug.php?id=84118 + */ + $pattern = preg_replace( '/(^|[^\\\\](?:\\\\{2}))*(\\\\[%_])/', '$1\\\\$2', $pattern ); + + /* + * 2. Unescape C-style escape sequences. + * + * MySQL string literals are represented using C-style encoded strings, + * but the GLOB pattern in SQLite doesn't support such escaping. + */ + $pattern = stripcslashes( $pattern ); + + /* + * 3. Escape characters that have special meaning in GLOB patterns. + * + * We need to: + * 1. Escape "]" as "[]]" to avoid interpreting "[...]" as a character class. + * 2. Escape "*" as "[*]" (must be after 1 to avoid being escaped). + * 3. Escape "?" as "[?]" (must be after 1 to avoid being escaped). + */ + $pattern = str_replace( ']', '[]]', $pattern ); + $pattern = str_replace( '*', '[*]', $pattern ); + $pattern = str_replace( '?', '[?]', $pattern ); + + /* + * 4. Convert LIKE wildcards to GLOB wildcards ("%" -> "*", "_" -> "?"). + * + * We need to convert them only when they don't follow any backslashes, + * or when they follow an even number of backslashes (as "\\" is "\"). + */ + $pattern = preg_replace( '/(^|[^\\\\](?:\\\\{2})*)%/', '$1*', $pattern ); + $pattern = preg_replace( '/(^|[^\\\\](?:\\\\{2})*)_/', '$1?', $pattern ); + + /* + * 5. Unescape LIKE escape sequences. + * + * While in MySQL LIKE patterns, a backslash is usually used to escape + * special characters ("%", "_", and "\"), it works with all characters. + * + * That is: + * SELECT '\\x' prints '\x', but LIKE '\\x' is equivalent to LIKE 'x'. + * + * This is true also for multi-byte characters: + * SELECT '\\©' prints '\©', but LIKE '\\©' is equivalent to LIKE '©'. + * + * However, the multi-byte behavior is likely to depend on the charset. + * For now, we'll assume UTF-8 and thus the "u" modifier for the regex. + */ + $pattern = preg_replace( '/\\\\(.)/u', '$1', $pattern ); + + return $pattern; + } } From 335388b048031aa62ded67854939133a21c279d5 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 10 Jan 2025 10:10:46 +0100 Subject: [PATCH 34/36] Add support for REGEXP functions --- .../sqlite-ast/class-wp-sqlite-driver.php | 25 +++++++++++++++++++ 1 file changed, 25 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index d18d92a1..bd23f349 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -1317,6 +1317,8 @@ private function translate( $ast ) { $token = $ast->get_child_token(); if ( WP_MySQL_Lexer::LIKE_SYMBOL === $token->id ) { return $this->translate_like( $ast ); + } elseif ( WP_MySQL_Lexer::REGEXP_SYMBOL === $token->id ) { + return $this->translate_regexp_functions( $ast ); } return $this->translate_sequence( $ast->get_children() ); case 'systemVariable': @@ -1416,6 +1418,29 @@ private function translate_like( WP_Parser_Node $node ): string { return $this->translate_sequence( $node->get_children() ); } + private function translate_regexp_functions( WP_Parser_Node $node ): string { + $tokens = $node->get_descendant_tokens(); + $is_binary = isset( $tokens[1] ) && WP_MySQL_Lexer::BINARY_SYMBOL === $tokens[1]->id; + + /* + * If the query says REGEXP BINARY, the comparison is byte-by-byte + * and letter casing matters – lowercase and uppercase letters are + * represented using different byte codes. + * + * The REGEXP function can't be easily made to accept two + * parameters, so we'll have to use a hack to get around this. + * + * If the first character of the pattern is a null byte, we'll + * remove it and make the comparison case-sensitive. This should + * be reasonably safe since PHP does not allow null bytes in + * regular expressions anyway. + */ + if ( true === $is_binary ) { + return 'REGEXP CHAR(0) || ' . $this->translate( $node->get_child_node() ); + } + return 'REGEXP ' . $this->translate( $node->get_child_node() ); + } + private function get_sqlite_create_table_statement( string $table_name, ?string $new_table_name = null ): array { // 1. Get table info. $table_info = $this->execute_sqlite_query( From f29464c460727693c1a365fdff827210150734d9 Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 10 Jan 2025 13:57:07 +0100 Subject: [PATCH 35/36] Add support for LEFT function --- .../sqlite-ast/class-wp-sqlite-driver.php | 21 +++++++++++++++++++ 1 file changed, 21 insertions(+) diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index bd23f349..3cefe0f0 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -1321,6 +1321,8 @@ private function translate( $ast ) { return $this->translate_regexp_functions( $ast ); } return $this->translate_sequence( $ast->get_children() ); + case 'runtimeFunctionCall': + return $this->translate_runtime_function_call( $ast ); case 'systemVariable': // @TODO: Emulate some system variables, or use reasonable defaults. // See: https://dev.mysql.com/doc/refman/8.4/en/server-system-variable-reference.html @@ -1441,6 +1443,25 @@ private function translate_regexp_functions( WP_Parser_Node $node ): string { return 'REGEXP ' . $this->translate( $node->get_child_node() ); } + private function translate_runtime_function_call( WP_Parser_Node $node ): string { + $child = $node->get_child(); + if ( $child instanceof WP_Parser_Node ) { + return $this->translate( $child ); + } + + switch ( $child->id ) { + case WP_MySQL_Lexer::LEFT_SYMBOL: + $nodes = $node->get_child_nodes(); + return sprintf( + 'SUBSTRING(%s, 1, %s)', + $this->translate($nodes[0]), + $this->translate($nodes[1]) + ); + default: + return $this->translate_sequence( $node->get_children() ); + } + } + private function get_sqlite_create_table_statement( string $table_name, ?string $new_table_name = null ): array { // 1. Get table info. $table_info = $this->execute_sqlite_query( From 8cfe7f4b0b2ed9df0186d70a9a78349cbea0f86b Mon Sep 17 00:00:00 2001 From: Jan Jakes Date: Fri, 10 Jan 2025 13:57:50 +0100 Subject: [PATCH 36/36] Add support for DATE_ADD and DATE_SUB functions --- tests/WP_SQLite_Driver_Tests.php | 88 +++++++++++++++++++ .../sqlite-ast/class-wp-sqlite-driver.php | 16 ++++ 2 files changed, 104 insertions(+) diff --git a/tests/WP_SQLite_Driver_Tests.php b/tests/WP_SQLite_Driver_Tests.php index 13bbfcf9..30d5eced 100644 --- a/tests/WP_SQLite_Driver_Tests.php +++ b/tests/WP_SQLite_Driver_Tests.php @@ -506,6 +506,94 @@ public function testSelectIndexHintUseGroup() { $this->assertEquals( 1, $result[0]->output ); } + public function testDateAddFunction() { + // second + $result = $this->assertQuery( + 'SELECT DATE_ADD("2008-01-02 13:29:17", INTERVAL 1 SECOND) as output' + ); + $this->assertEquals( '2008-01-02 13:29:18', $result[0]->output ); + + // minute + $result = $this->assertQuery( + 'SELECT DATE_ADD("2008-01-02 13:29:17", INTERVAL 1 MINUTE) as output' + ); + $this->assertEquals( '2008-01-02 13:30:17', $result[0]->output ); + + // hour + $result = $this->assertQuery( + 'SELECT DATE_ADD("2008-01-02 13:29:17", INTERVAL 1 HOUR) as output' + ); + $this->assertEquals( '2008-01-02 14:29:17', $result[0]->output ); + + // day + $result = $this->assertQuery( + 'SELECT DATE_ADD("2008-01-02 13:29:17", INTERVAL 1 DAY) as output' + ); + $this->assertEquals( '2008-01-03 13:29:17', $result[0]->output ); + + // week + $result = $this->assertQuery( + 'SELECT DATE_ADD("2008-01-02 13:29:17", INTERVAL 1 WEEK) as output' + ); + $this->assertEquals( '2008-01-09 13:29:17', $result[0]->output ); + + // month + $result = $this->assertQuery( + 'SELECT DATE_ADD("2008-01-02 13:29:17", INTERVAL 1 MONTH) as output' + ); + $this->assertEquals( '2008-02-02 13:29:17', $result[0]->output ); + + // year + $result = $this->assertQuery( + 'SELECT DATE_ADD("2008-01-02 13:29:17", INTERVAL 1 YEAR) as output' + ); + $this->assertEquals( '2009-01-02 13:29:17', $result[0]->output ); + } + + public function testDateSubFunction() { + // second + $result = $this->assertQuery( + 'SELECT DATE_SUB("2008-01-02 13:29:17", INTERVAL 1 SECOND) as output' + ); + $this->assertEquals( '2008-01-02 13:29:16', $result[0]->output ); + + // minute + $result = $this->assertQuery( + 'SELECT DATE_SUB("2008-01-02 13:29:17", INTERVAL 1 MINUTE) as output' + ); + $this->assertEquals( '2008-01-02 13:28:17', $result[0]->output ); + + // hour + $result = $this->assertQuery( + 'SELECT DATE_SUB("2008-01-02 13:29:17", INTERVAL 1 HOUR) as output' + ); + $this->assertEquals( '2008-01-02 12:29:17', $result[0]->output ); + + // day + $result = $this->assertQuery( + 'SELECT DATE_SUB("2008-01-02 13:29:17", INTERVAL 1 DAY) as output' + ); + $this->assertEquals( '2008-01-01 13:29:17', $result[0]->output ); + + // week + $result = $this->assertQuery( + 'SELECT DATE_SUB("2008-01-02 13:29:17", INTERVAL 1 WEEK) as output' + ); + $this->assertEquals( '2007-12-26 13:29:17', $result[0]->output ); + + // month + $result = $this->assertQuery( + 'SELECT DATE_SUB("2008-01-02 13:29:17", INTERVAL 1 MONTH) as output' + ); + $this->assertEquals( '2007-12-02 13:29:17', $result[0]->output ); + + // year + $result = $this->assertQuery( + 'SELECT DATE_SUB("2008-01-02 13:29:17", INTERVAL 1 YEAR) as output' + ); + $this->assertEquals( '2007-01-02 13:29:17', $result[0]->output ); + } + public function testLeftFunction1Char() { $result = $this->assertQuery( 'SELECT LEFT("abc", 1) as output' diff --git a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php index 3cefe0f0..b6cfb44d 100644 --- a/wp-includes/sqlite-ast/class-wp-sqlite-driver.php +++ b/wp-includes/sqlite-ast/class-wp-sqlite-driver.php @@ -1450,6 +1450,22 @@ private function translate_runtime_function_call( WP_Parser_Node $node ): string } switch ( $child->id ) { + case WP_MySQL_Lexer::DATE_ADD_SYMBOL: + case WP_MySQL_Lexer::DATE_SUB_SYMBOL: + $nodes = $node->get_child_nodes(); + $value = $this->translate( $nodes[1] ); + $unit = $this->translate( $nodes[2] ); + if ( 'WEEK' === $unit ) { + $unit = 'DAY'; + $value = 7 * $value; + } + return sprintf( + "DATETIME(%s, '%s%s %s')", + $this->translate( $nodes[0] ), + WP_MySQL_Lexer::DATE_SUB_SYMBOL === $child->id ? '-' : '+', + $value, + $unit + ); case WP_MySQL_Lexer::LEFT_SYMBOL: $nodes = $node->get_child_nodes(); return sprintf(