diff --git a/.github/workflows/phpunit.yml b/.github/workflows/phpunit.yml index a1bbf1a6..8ff67292 100644 --- a/.github/workflows/phpunit.yml +++ b/.github/workflows/phpunit.yml @@ -10,6 +10,8 @@ jobs: build: runs-on: ubuntu-latest + env: + XDEBUG_MODE: off steps: - uses: actions/checkout@v2 @@ -23,7 +25,7 @@ jobs: echo "::set-output name=dir::$(composer config cache-files-dir)" - name: Cache Composer packages - uses: actions/cache@v2 + uses: actions/cache@v4 with: path: ${{ steps.composer-cache.outputs.dir }} key: ${{ runner.os }}-composer-${{ hashFiles('**/composer.lock') }} diff --git a/.github/workflows/psalm.yml b/.github/workflows/psalm.yml index a7acc498..87311635 100644 --- a/.github/workflows/psalm.yml +++ b/.github/workflows/psalm.yml @@ -19,7 +19,7 @@ jobs: echo "::set-output name=dir::$(composer config cache-files-dir)" - name: Cache Composer packages - uses: actions/cache@v2 + uses: actions/cache@v4 with: path: ${{ steps.composer-cache.outputs.dir }} key: ${{ runner.os }}-composer-${{ hashFiles('**/composer.lock') }} diff --git a/src/FakePdo.php b/src/FakePdo.php new file mode 100644 index 00000000..6774a1a3 --- /dev/null +++ b/src/FakePdo.php @@ -0,0 +1,27 @@ + $options any options + * @return PDO + */ + public static function getFakePdo( + string $connection_string, + string $username, + string $password, + array $options + ): PDO { + if (\PHP_MAJOR_VERSION === 8) { + return new Php8\FakePdo($connection_string, $username, $password, $options); + } + + return new Php7\FakePdo($connection_string, $username, $password, $options); + } +} diff --git a/src/FakePdoStatementTrait.php b/src/FakePdoStatementTrait.php index abaad45c..ce33ca36 100644 --- a/src/FakePdoStatementTrait.php +++ b/src/FakePdoStatementTrait.php @@ -74,6 +74,7 @@ public function __construct(FakePdoInterface $conn, string $sql, ?\PDO $real) * @param int $type * @return bool */ + #[\ReturnTypeWillChange] public function bindValue($key, $value, $type = \PDO::PARAM_STR) : bool { if (\is_string($key) && $key[0] !== ':') { @@ -99,6 +100,7 @@ public function bindValue($key, $value, $type = \PDO::PARAM_STR) : bool * @param mixed $driverOptions * @return bool */ + #[\ReturnTypeWillChange] public function bindParam($key, &$value, $type = PDO::PARAM_STR, $maxLength = null, $driverOptions = null): bool { if (\is_string($key) && $key[0] !== ':') { @@ -331,12 +333,13 @@ public function rowCount() : int * @param int $cursor_orientation * @param int $cursor_offset */ + #[\ReturnTypeWillChange] public function fetch( $fetch_style = -123, $cursor_orientation = \PDO::FETCH_ORI_NEXT, $cursor_offset = 0 ) { - if ($fetch_style === -123) { + if ($fetch_style === -123 || (defined('PDO::FETCH_DEFAULT') && $fetch_style === \PDO::FETCH_DEFAULT)) { $fetch_style = $this->fetchMode; } @@ -391,6 +394,7 @@ public function fetch( * @param int $column * @return null|scalar */ + #[\ReturnTypeWillChange] public function fetchColumn($column = 0) { /** @var array|false $row */ @@ -411,7 +415,7 @@ public function fetchColumn($column = 0) */ public function universalFetchAll(int $fetch_style = -123, ...$args) : array { - if ($fetch_style === -123) { + if ($fetch_style === -123 || (defined('PDO::FETCH_DEFAULT') && $fetch_style === \PDO::FETCH_DEFAULT)) { $fetch_style = $this->fetchMode; $fetch_argument = $this->fetchArgument; $ctor_args = $this->fetchConstructorArgs; diff --git a/src/FakePdoTrait.php b/src/FakePdoTrait.php index bb2d26d1..c206f2d4 100644 --- a/src/FakePdoTrait.php +++ b/src/FakePdoTrait.php @@ -63,6 +63,7 @@ public function __construct(string $dsn, string $username = '', string $passwd = $this->server = Server::getOrCreate('primary'); } + #[\ReturnTypeWillChange] public function setAttribute($key, $value) { if ($key === \PDO::ATTR_EMULATE_PREPARES) { @@ -132,6 +133,7 @@ public function useStrictMode() : bool return $this->strict_mode; } + #[\ReturnTypeWillChange] public function beginTransaction() { if (Server::hasSnapshot('transaction')) { @@ -142,11 +144,13 @@ public function beginTransaction() return true; } + #[\ReturnTypeWillChange] public function commit() { return Server::deleteSnapshot('transaction'); } + #[\ReturnTypeWillChange] public function rollback() { if (!Server::hasSnapshot('transaction')) { @@ -157,6 +161,7 @@ public function rollback() return true; } + #[\ReturnTypeWillChange] public function inTransaction() { return Server::hasSnapshot('transaction'); @@ -166,6 +171,7 @@ public function inTransaction() * @param string $statement * @return int|false */ + #[\ReturnTypeWillChange] public function exec($statement) { $statement = trim($statement); @@ -188,6 +194,7 @@ public function exec($statement) * @param int $parameter_type * @return string */ + #[\ReturnTypeWillChange] public function quote($string, $parameter_type = \PDO::PARAM_STR) { // @see https://github.com/php/php-src/blob/php-8.0.2/ext/mysqlnd/mysqlnd_charset.c#L860-L878 diff --git a/src/Parser/FromParser.php b/src/Parser/FromParser.php index b8361ea0..da70a328 100644 --- a/src/Parser/FromParser.php +++ b/src/Parser/FromParser.php @@ -295,7 +295,26 @@ private function buildJoin(string $left_table, Token $token) } } + /* + * Unlike other clauses (e.g., FROM), the buildJoin advances the pointer to the specified keyword (e.g., FORCE). + * Therefore, the pointer needs to be adjusted. + * For instance, in "FROM a FORCE INDEX ...", processing for other clauses ends just before the identifier (a), + * but for the JOIN clause, the pointer advances to "FORCE". + * To address this issue, we adjusted the pointer before and after calling SQLParser::skipIndexHints(), + * and modified the code to advance the pointer to the closing parenthesis ')' if necessary. + */ + $this->pointer--; $this->pointer = SQLParser::skipIndexHints($this->pointer, $this->tokens); + $this->pointer++; + if ($this->tokens[$this->pointer]->type === TokenType::SEPARATOR + && $this->tokens[$this->pointer]->value === ")") { + $this->pointer++; + } + $next = $this->tokens[$this->pointer] ?? null; + if ($next === null) { + /** @psalm-suppress LessSpecificReturnStatement */ + return $table; + } if ($table['join_type'] === JoinType::NATURAL || $table['join_type'] === JoinType::CROSS) { return $table; diff --git a/src/Php8/FakePdo.php b/src/Php8/FakePdo.php index 4c93b8a0..c56aba93 100644 --- a/src/Php8/FakePdo.php +++ b/src/Php8/FakePdo.php @@ -14,9 +14,16 @@ class FakePdo extends PDO implements FakePdoInterface * @param array $options * @return FakePdoStatement */ + #[\ReturnTypeWillChange] public function prepare($statement, array $options = []) { - return new FakePdoStatement($this, $statement, $this->real); + $statement = new FakePdoStatement($this, $statement, $this->real); + + if ($this->defaultFetchMode) { + $statement->setFetchMode($this->defaultFetchMode); + } + + return $statement; } /** @@ -25,6 +32,7 @@ public function prepare($statement, array $options = []) * @param mixed ...$fetchModeArgs * @return FakePdoStatement */ + #[\ReturnTypeWillChange] public function query(string $statement, ?int $mode = PDO::ATTR_DEFAULT_FETCH_MODE, mixed ...$fetchModeArgs) { $sth = $this->prepare($statement); diff --git a/src/Php8/FakePdoStatement.php b/src/Php8/FakePdoStatement.php index 252378f4..8156ba08 100644 --- a/src/Php8/FakePdoStatement.php +++ b/src/Php8/FakePdoStatement.php @@ -10,6 +10,7 @@ class FakePdoStatement extends \PDOStatement * @param ?array $params * @return bool */ + #[\ReturnTypeWillChange] public function execute(?array $params = null) { return $this->universalExecute($params); @@ -41,6 +42,7 @@ public function setFetchMode(int $mode, ...$args) : bool * @param array|null $ctorArgs * @return false|T */ + #[\ReturnTypeWillChange] public function fetchObject(?string $class = \stdClass::class, ?array $ctorArgs = null) { return $this->universalFetchObject($class, $ctorArgs); diff --git a/src/Processor/CreateProcessor.php b/src/Processor/CreateProcessor.php index cb1acf80..49daffe0 100644 --- a/src/Processor/CreateProcessor.php +++ b/src/Processor/CreateProcessor.php @@ -50,6 +50,7 @@ final class CreateProcessor 'utf32' => 'utf32_general_ci', 'utf8' => 'utf8_general_ci', 'utf8mb4' => 'utf8mb4_general_ci', + 'utf8mb3' => 'utf8mb3_general_ci' ]; public static function makeTableDefinition( @@ -277,8 +278,8 @@ private static function getIntegerDefinitionColumn(Query\MysqlColumnType $stmt) */ private static function getTextDefinitionColumn(Query\MysqlColumnType $stmt) { - $collation = null; - $character_set = null; + $collation = $stmt->collation; + $character_set = $stmt->character_set; switch (strtoupper($stmt->type)) { case DataType::TEXT: diff --git a/src/Processor/Expression/BinaryOperatorEvaluator.php b/src/Processor/Expression/BinaryOperatorEvaluator.php index 2cca6e79..bced418c 100644 --- a/src/Processor/Expression/BinaryOperatorEvaluator.php +++ b/src/Processor/Expression/BinaryOperatorEvaluator.php @@ -152,7 +152,7 @@ public static function evaluate( return !$expr->negatedInt; } - return $l_value == $r_value ? 1 : 0 ^ $expr->negatedInt; + return ($l_value == $r_value ? 1 : 0 ) ^ $expr->negatedInt; case '<>': case '!=': @@ -165,35 +165,35 @@ public static function evaluate( return $expr->negatedInt; } - return $l_value != $r_value ? 1 : 0 ^ $expr->negatedInt; + return ($l_value != $r_value ? 1 : 0) ^ $expr->negatedInt; case '>': if ($as_string) { - return (string) $l_value > (string) $r_value ? 1 : 0 ^ $expr->negatedInt; + return ((string) $l_value > (string) $r_value ? 1 : 0) ^ $expr->negatedInt; } - return (float) $l_value > (float) $r_value ? 1 : 0 ^ $expr->negatedInt; + return ((float) $l_value > (float) $r_value ? 1 : 0 ) ^ $expr->negatedInt; // no break case '>=': if ($as_string) { - return (string) $l_value >= (string) $r_value ? 1 : 0 ^ $expr->negatedInt; + return ((string) $l_value >= (string) $r_value ? 1 : 0) ^ $expr->negatedInt; } - return (float) $l_value >= (float) $r_value ? 1 : 0 ^ $expr->negatedInt; + return ((float) $l_value >= (float) $r_value ? 1 : 0) ^ $expr->negatedInt; case '<': if ($as_string) { - return (string) $l_value < (string) $r_value ? 1 : 0 ^ $expr->negatedInt; + return ((string) $l_value < (string) $r_value ? 1 : 0) ^ $expr->negatedInt; } - return (float) $l_value < (float) $r_value ? 1 : 0 ^ $expr->negatedInt; + return ((float) $l_value < (float) $r_value ? 1 : 0) ^ $expr->negatedInt; case '<=': if ($as_string) { - return (string) $l_value <= (string) $r_value ? 1 : 0 ^ $expr->negatedInt; + return ((string) $l_value <= (string) $r_value ? 1 : 0) ^ $expr->negatedInt; } - return (float) $l_value <= (float) $r_value ? 1 : 0 ^ $expr->negatedInt; + return ((float) $l_value <= (float) $r_value ? 1 : 0) ^ $expr->negatedInt; } // PHPCS thinks there's a fallthrough here, but there provably is not @@ -226,8 +226,18 @@ public static function evaluate( case 'MOD': return \fmod((double) $left_number, (double) $right_number); case '/': + // Ensure division by 0 cannot occur and 0 divided by anything is also 0 + if ($right_number === 0 || $left_number === 0) { + return 0; + } + return $left_number / $right_number; case 'DIV': + // Ensure division by 0 cannot occur and 0 divided by anything is also 0 + if ($right_number === 0 || $left_number === 0) { + return 0; + } + return (int) ($left_number / $right_number); case '-': return $left_number - $right_number; diff --git a/src/Processor/Expression/FunctionEvaluator.php b/src/Processor/Expression/FunctionEvaluator.php index 9be41f00..b82d27a5 100644 --- a/src/Processor/Expression/FunctionEvaluator.php +++ b/src/Processor/Expression/FunctionEvaluator.php @@ -11,6 +11,7 @@ use Vimeo\MysqlEngine\Query\Expression\FunctionExpression; use Vimeo\MysqlEngine\Query\Expression\IntervalOperatorExpression; use Vimeo\MysqlEngine\Schema\Column; +use Vimeo\MysqlEngine\TokenType; final class FunctionEvaluator { @@ -65,12 +66,16 @@ public static function evaluate( return self::sqlConcatWS($conn, $scope, $expr, $row, $result); case 'CONCAT': return self::sqlConcat($conn, $scope, $expr, $row, $result); + case 'GROUP_CONCAT': + return self::sqlGroupConcat($conn, $scope, $expr, $row, $result); case 'FIELD': return self::sqlColumn($conn, $scope, $expr, $row, $result); case 'BINARY': return self::sqlBinary($conn, $scope, $expr, $row, $result); case 'FROM_UNIXTIME': return self::sqlFromUnixtime($conn, $scope, $expr, $row, $result); + case 'UNIX_TIMESTAMP': + return self::sqlUnixTimestamp($conn, $scope, $expr, $row, $result); case 'GREATEST': return self::sqlGreatest($conn, $scope, $expr, $row, $result); case 'VALUES': @@ -89,6 +94,15 @@ public static function evaluate( return self::sqlDateAdd($conn, $scope, $expr, $row, $result); case 'ROUND': return self::sqlRound($conn, $scope, $expr, $row, $result); + case 'CEIL': + case 'CEILING': + return self::sqlCeiling($conn, $scope, $expr, $row, $result); + case 'FLOOR': + return self::sqlFloor($conn, $scope, $expr, $row, $result); + case 'CONVERT_TZ': + return self::sqlConvertTz($conn, $scope, $expr, $row, $result); + case 'TIMESTAMPDIFF': + return self::sqlTimestampdiff($conn, $scope, $expr, $row, $result); case 'DATEDIFF': return self::sqlDateDiff($conn, $scope, $expr, $row, $result); case 'DAY': @@ -104,6 +118,8 @@ public static function evaluate( return self::sqlInetAton($conn, $scope, $expr, $row, $result); case 'INET_NTOA': return self::sqlInetNtoa($conn, $scope, $expr, $row, $result); + case 'LEAST': + return self::sqlLeast($conn, $scope, $expr, $row, $result); } throw new ProcessorException("Function " . $expr->functionName . " not implemented yet"); @@ -136,8 +152,34 @@ public static function getColumnSchema( case 'MOD': return new Column\IntColumn(false, 10); + case 'AVG': return new Column\FloatColumn(10, 2); + + case 'CEIL': + case 'CEILING': + case 'FLOOR': + // from MySQL docs: https://dev.mysql.com/doc/refman/5.6/en/mathematical-functions.html#function_ceil + // For exact-value numeric arguments, the return value has an exact-value numeric type. For string or + // floating-point arguments, the return value has a floating-point type. But... + // + // mysql> CREATE TEMPORARY TABLE `temp` SELECT FLOOR(1.2); + // Query OK, 1 row affected (0.00 sec) + // Records: 1 Duplicates: 0 Warnings: 0 + // + // mysql> describe temp; + // +------------+--------+------+-----+---------+-------+ + // | Field | Type | Null | Key | Default | Extra | + // +------------+--------+------+-----+---------+-------+ + // | FLOOR(1.2) | bigint | NO | | 0 | NULL | + // +------------+--------+------+-----+---------+-------+ + // 1 row in set (0.00 sec) + if ($expr->args[0]->getType() == TokenType::STRING_CONSTANT) { + return new Column\DoubleColumn(10, 2); + } + + return new Column\BigInt(false, 10); + case 'IF': $if = Evaluator::getColumnSchema($expr->args[1], $scope, $columns); $else = Evaluator::getColumnSchema($expr->args[2], $scope, $columns); @@ -311,9 +353,13 @@ private static function sqlCount( } /** - * @param array $columns + * @param FakePdoInterface $conn + * @param Scope $scope + * @param FunctionExpression $expr + * @param QueryResult $result * - * @return ?numeric + * @return float|int|mixed|string|null + * @throws ProcessorException */ private static function sqlSum( FakePdoInterface $conn, @@ -326,6 +372,11 @@ private static function sqlSum( $sum = 0; if (!$result->rows) { + $isQueryWithoutFromClause = empty($result->columns); + if ($expr instanceof FunctionExpression && $isQueryWithoutFromClause) { + return self::evaluate($conn, $scope, $expr, [], $result); + } + return null; } @@ -399,14 +450,20 @@ private static function sqlMin( $value = Evaluator::evaluate($conn, $scope, $expr, $row, $result); - if (!\is_scalar($value)) { + if (!\is_scalar($value) && !\is_null($value)) { throw new \TypeError('Bad min value'); } $values[] = $value; } - return self::castAggregate(\min($values), $expr, $result); + $min_value = \min($values); + + if ($min_value === null) { + return null; + } + + return self::castAggregate($min_value, $expr, $result); } /** @@ -434,14 +491,20 @@ private static function sqlMax( $value = Evaluator::evaluate($conn, $scope, $expr, $row, $result); - if (!\is_scalar($value)) { + if (!\is_scalar($value) && !\is_null($value)) { throw new \TypeError('Bad max value'); } $values[] = $value; } - return self::castAggregate(\max($values), $expr, $result); + $max_value = \max($values); + + if ($max_value === null) { + return null; + } + + return self::castAggregate($max_value, $expr, $result); } /** @@ -845,6 +908,32 @@ private static function sqlFromUnixtime( return \date('Y-m-d H:i:s', (int) $column); } + /** + * @param array $row + */ + private static function sqlUnixTimestamp( + FakePdoInterface $conn, + Scope $scope, + FunctionExpression $expr, + array $row, + QueryResult $result + ) : ?int { + $args = $expr->args; + + switch (\count($args)) { + case 0: + return time(); + case 1: + $column = Evaluator::evaluate($conn, $scope, $args[0], $row, $result); + if (!\is_string($column)) { + return null; + } + return \strtotime($column) ?: null; + default: + throw new ProcessorException("MySQL UNIX_TIMESTAMP() SQLFake only implemented for 0 or 1 argument"); + } + } + /** * @param array $row * @@ -872,6 +961,27 @@ private static function sqlConcat( return $final_concat; } + /** + * @param array $row + */ + private static function sqlGroupConcat( + FakePdoInterface $conn, + Scope $scope, + FunctionExpression $expr, + array $row, + QueryResult $result + ): string { + $args = $expr->args; + + $final_concat = ""; + foreach ($args as $arg) { + $val = (string) Evaluator::evaluate($conn, $scope, $arg, $row, $result); + $final_concat .= $val; + } + + return $final_concat; + } + /** * @param array $row * @@ -1349,6 +1459,72 @@ private static function sqlInetNtoa( return long2ip((int)$subject); } + /** + * @param array $row + * @return float|0 + */ + private static function sqlCeiling( + FakePdoInterface $conn, + Scope $scope, + FunctionExpression $expr, + array $row, + QueryResult $result + ) { + $args = $expr->args; + + if (\count($args) !== 1) { + throw new ProcessorException("MySQL CEILING function must be called with one argument (got " . count($args) . ")"); + } + + $subject = Evaluator::evaluate($conn, $scope, $args[0], $row, $result); + + if (!is_numeric($subject)) { + // CEILING() returns 0 if it does not understand its argument. + return 0; + } + + $value = ceil(floatval($subject)); + + if (!$value) { + return 0; + } + + return $value; + } + + /** + * @param array $row + * @return float|0 + */ + private static function sqlFloor( + FakePdoInterface $conn, + Scope $scope, + FunctionExpression $expr, + array $row, + QueryResult $result + ) { + $args = $expr->args; + + if (\count($args) !== 1) { + throw new ProcessorException("MySQL FLOOR function must be called with one argument"); + } + + $subject = Evaluator::evaluate($conn, $scope, $args[0], $row, $result); + + if (!is_numeric($subject)) { + // FLOOR() returns 0 if it does not understand its argument. + return 0; + } + + $value = floor(floatval($subject)); + + if (!$value) { + return 0; + } + + return $value; + } + private static function getPhpIntervalFromExpression( FakePdoInterface $conn, Scope $scope, @@ -1384,4 +1560,181 @@ private static function getPhpIntervalFromExpression( throw new ProcessorException('MySQL INTERVAL unit ' . $expr->unit . ' not supported yet'); } } + + /** + * @param FakePdoInterface $conn + * @param Scope $scope + * @param FunctionExpression $expr + * @param array $row + * @param QueryResult $result + * + * @return string|null + * @throws ProcessorException + */ + private static function sqlConvertTz( + FakePdoInterface $conn, + Scope $scope, + FunctionExpression $expr, + array $row, + QueryResult $result) + { + $args = $expr->args; + + if (count($args) !== 3) { + throw new \InvalidArgumentException("CONVERT_TZ() requires exactly 3 arguments"); + } + + if ($args[0] instanceof ColumnExpression && empty($row)) { + return null; + } + + /** @var string|null $dtValue */ + $dtValue = Evaluator::evaluate($conn, $scope, $args[0], $row, $result); + /** @var string|null $fromTzValue */ + $fromTzValue = Evaluator::evaluate($conn, $scope, $args[1], $row, $result); + /** @var string|null $toTzValue */ + $toTzValue = Evaluator::evaluate($conn, $scope, $args[2], $row, $result); + + if ($dtValue === null || $fromTzValue === null || $toTzValue === null) { + return null; + } + + try { + $dt = new \DateTime($dtValue, new \DateTimeZone($fromTzValue)); + $dt->setTimezone(new \DateTimeZone($toTzValue)); + return $dt->format('Y-m-d H:i:s'); + } catch (\Exception $e) { + return null; + } + } + + /** + * @param FakePdoInterface $conn + * @param Scope $scope + * @param FunctionExpression $expr + * @param array $row + * @param QueryResult $result + * + * @return int + * @throws ProcessorException + */ + private static function sqlTimestampdiff( + FakePdoInterface $conn, + Scope $scope, + FunctionExpression $expr, + array $row, + QueryResult $result + ) { + $args = $expr->args; + + if (\count($args) !== 3) { + throw new ProcessorException("MySQL TIMESTAMPDIFF() function must be called with three arguments"); + } + + if (!$args[0] instanceof ColumnExpression) { + throw new ProcessorException("MySQL TIMESTAMPDIFF() function should be called with a unit for interval"); + } + + /** @var string|null $unit */ + $unit = $args[0]->columnExpression; + /** @var string|int|float|null $start */ + $start = Evaluator::evaluate($conn, $scope, $args[1], $row, $result); + /** @var string|int|float|null $end */ + $end = Evaluator::evaluate($conn, $scope, $args[2], $row, $result); + + try { + $dtStart = new \DateTime((string) $start); + $dtEnd = new \DateTime((string) $end); + } catch (\Exception $e) { + throw new ProcessorException("Invalid datetime value passed to TIMESTAMPDIFF()"); + } + + $interval = $dtStart->diff($dtEnd); + + // Calculate difference in seconds for fine-grained units + $seconds = $dtEnd->getTimestamp() - $dtStart->getTimestamp(); + + switch (strtoupper((string)$unit)) { + case 'MICROSECOND': + return $seconds * 1000000; + case 'SECOND': + return $seconds; + case 'MINUTE': + return (int) floor($seconds / 60); + case 'HOUR': + return (int) floor($seconds / 3600); + case 'DAY': + return (int) $interval->days * ($seconds < 0 ? -1 : 1); + case 'WEEK': + return (int) floor($interval->days / 7) * ($seconds < 0 ? -1 : 1); + case 'MONTH': + return ($interval->y * 12 + $interval->m) * ($seconds < 0 ? -1 : 1); + case 'QUARTER': + $months = $interval->y * 12 + $interval->m; + return (int) floor($months / 3) * ($seconds < 0 ? -1 : 1); + case 'YEAR': + return $interval->y * ($seconds < 0 ? -1 : 1); + default: + throw new ProcessorException("Unsupported unit '$unit' in TIMESTAMPDIFF()"); + } + } + + /** + * @param FakePdoInterface $conn + * @param Scope $scope + * @param FunctionExpression $expr + * @param array $row + * @param QueryResult $result + * + * @return mixed|null + * @throws ProcessorException + */ + private static function sqlLeast( + FakePdoInterface $conn, + Scope $scope, + FunctionExpression $expr, + array $row, + QueryResult $result + ) + { + $args = $expr->args; + + if (\count($args) < 2) { + throw new ProcessorException("Incorrect parameter count in the call to native function 'LEAST'"); + } + + $is_any_float = false; + $is_any_string = false; + $precision = 0; + $evaluated_args = []; + + foreach ($args as $arg) { + /** @var string|int|float|null $evaluated_arg */ + $evaluated_arg = Evaluator::evaluate($conn, $scope, $arg, $row, $result); + if (is_null($evaluated_arg)) { + return null; + } + + if (is_float($evaluated_arg)) { + $is_any_float = true; + $precision = max($precision, strlen(substr(strrchr((string) $evaluated_arg, "."), 1))); + } + + $is_any_string = $is_any_string || is_string($evaluated_arg); + $evaluated_args[] = $evaluated_arg; + } + + if ($is_any_string) { + $evaluated_str_args = array_map(function($arg) { + return (string) $arg; + }, $evaluated_args); + return min($evaluated_str_args); + } + + if ($is_any_float) { + return number_format((float) min($evaluated_args), $precision); + } + + return min($evaluated_args); + } } diff --git a/src/Processor/Expression/VariableEvaluator.php b/src/Processor/Expression/VariableEvaluator.php index c029e606..cccf6e0e 100644 --- a/src/Processor/Expression/VariableEvaluator.php +++ b/src/Processor/Expression/VariableEvaluator.php @@ -1,6 +1,8 @@ variableName, '@') === 0) { + return self::getSystemVariable(substr($expr->variableName, 1)); + } + if (\array_key_exists($expr->variableName, $scope->variables)) { return $scope->variables[$expr->variableName]; } return null; } + + /** + * @param string $variableName + * + * @return string + * @throws ProcessorException + */ + private static function getSystemVariable(string $variableName): string + { + switch ($variableName) { + case 'session.time_zone': + return date_default_timezone_get(); + default: + throw new ProcessorException("System variable $variableName is not supported yet!"); + } + } } diff --git a/src/Processor/SelectProcessor.php b/src/Processor/SelectProcessor.php index 53a3120d..fa9f004c 100644 --- a/src/Processor/SelectProcessor.php +++ b/src/Processor/SelectProcessor.php @@ -301,7 +301,7 @@ function ($expr) { $parts = \explode(".%.", (string) $col); if ($expr->tableName() !== null) { - list($col_table_name, $col_name) = $parts; + [$col_table_name, $col_name] = $parts; if ($col_table_name == $expr->tableName()) { if (!\array_key_exists($col, $formatted_row)) { $formatted_row[$col_name] = $val; @@ -320,11 +320,15 @@ function ($expr) { continue; } + /** + * Evaluator case \Vimeo\MysqlEngine\Query\Expression\SubqueryExpression::class: + * should ensure the value of $val is never an array, and only the value of the + * column requested, but we'll leave this code just to make sure of that. + */ $val = Expression\Evaluator::evaluate($conn, $scope, $expr, $row, $group_result); $name = $expr->name; - if ($expr instanceof SubqueryExpression) { - assert(\is_array($val), 'subquery results must be KeyedContainer'); + if ($expr instanceof SubqueryExpression && \is_array($val)) { if (\count($val) > 1) { throw new ProcessorException("Subquery returned more than one row"); } @@ -477,7 +481,7 @@ private static function getSelectSchema( $parts = \explode(".", $column_id); if ($expr_table_name = $expr->tableName()) { - list($column_table_name) = $parts; + [$column_table_name] = $parts; if ($column_table_name === $expr_table_name) { $columns[$column_id] = $from_column; diff --git a/src/Query/Expression/BinaryOperatorExpression.php b/src/Query/Expression/BinaryOperatorExpression.php index 13c45b32..a7cb1365 100644 --- a/src/Query/Expression/BinaryOperatorExpression.php +++ b/src/Query/Expression/BinaryOperatorExpression.php @@ -69,8 +69,8 @@ public function __construct( */ public function negate() { - $this->negated = true; - $this->negatedInt = 1; + $this->negated = !$this->negated; + $this->negatedInt = $this->negated ? 1 : 0; } /** diff --git a/src/Schema/Column/CharacterColumn.php b/src/Schema/Column/CharacterColumn.php index 7dd7bf44..93d286cd 100644 --- a/src/Schema/Column/CharacterColumn.php +++ b/src/Schema/Column/CharacterColumn.php @@ -67,12 +67,13 @@ public function getPhpCode() : string } } - return '(new \\' . static::class . '(' - . $this->max_string_length - . ($this->character_set !== null && $this->collation !== null - ? ', \'' . $this->character_set . '\'' . ', \'' . $this->collation . '\'' - : '') - . '))' + $args = [ + $this->max_string_length, + $this->character_set === null ? 'null' : "'{$this->character_set}'", + $this->collation === null ? 'null' : "'{$this->collation}'", + ]; + + return '(new \\' . static::class . '(' . implode(', ', $args) . '))' . $default . $this->getNullablePhp(); } diff --git a/src/Schema/Column/TextTrait.php b/src/Schema/Column/TextTrait.php index a9c0635e..99ba9a27 100644 --- a/src/Schema/Column/TextTrait.php +++ b/src/Schema/Column/TextTrait.php @@ -8,12 +8,13 @@ trait TextTrait public function getPhpCode() : string { $default = $this->getDefault() !== null ? '\'' . $this->getDefault() . '\'' : 'null'; - - return '(new \\' . static::class . '(' - . ($this->character_set !== null && $this->collation !== null - ? ', \'' . $this->character_set . '\'' . ', \'' . $this->collation . '\'' - : '') - . '))' + + $args = [ + $this->character_set === null ? 'null' : "'{$this->character_set}'", + $this->collation === null ? 'null' : "'{$this->collation}'", + ]; + + return '(new \\' . static::class . '(' . implode(', ', $args) . '))' . ($this->hasDefault() ? '->setDefault(' . $default . ')' : '') . $this->getNullablePhp(); } diff --git a/tests/CreateTableParseTest.php b/tests/CreateTableParseTest.php index 35bc0712..52407068 100644 --- a/tests/CreateTableParseTest.php +++ b/tests/CreateTableParseTest.php @@ -1,10 +1,9 @@ parse($query); + $create_queries = (new CreateTableParser)->parse($query); - $this->assertCount(5, $create_queries); + $this->assertNotEmpty($create_queries); + + $table_defs = []; foreach ($create_queries as $create_query) { - $table = \Vimeo\MysqlEngine\Processor\CreateProcessor::makeTableDefinition( + $table = CreateProcessor::makeTableDefinition( $create_query, 'foo' ); + $table_defs[$table->name] = $table; $new_table_php_code = $table->getPhpCode(); $new_table = eval('return ' . $new_table_php_code . ';'); - $this->assertSame(\var_export($table, true), \var_export($new_table, true)); + $this->assertSame(\var_export($table, true), \var_export($new_table, true), + "The table definition for {$table->name} did not match the generated php version."); } + + // specific parsing checks + $this->assertInstanceOf(TableDefinition::class, $table_defs['tweets']); + $this->assertEquals('utf8mb4', $table_defs['tweets']->columns['title']->getCharacterSet()); + $this->assertEquals('utf8mb4_unicode_ci', $table_defs['tweets']->columns['title']->getCollation()); + $this->assertEquals('utf8mb4', $table_defs['tweets']->columns['text']->getCharacterSet()); + $this->assertEquals('utf8mb4_unicode_ci', $table_defs['tweets']->columns['text']->getCollation()); + + $this->assertInstanceOf(TableDefinition::class, $table_defs['texts']); + $this->assertEquals('utf8mb4', $table_defs['texts']->columns['title_char_col']->getCharacterSet()); + $this->assertEquals('utf8mb4_unicode_ci', $table_defs['texts']->columns['title_char_col']->getCollation()); + $this->assertNull($table_defs['texts']->columns['title_col']->getCharacterSet()); + $this->assertEquals('utf8mb4_unicode_ci', $table_defs['texts']->columns['title_col']->getCollation()); + $this->assertNull($table_defs['texts']->columns['title']->getCharacterSet()); + $this->assertNull($table_defs['texts']->columns['title']->getCollation()); } } diff --git a/tests/EndToEndTest.php b/tests/EndToEndTest.php index a594140e..1d5352dc 100644 --- a/tests/EndToEndTest.php +++ b/tests/EndToEndTest.php @@ -10,6 +10,29 @@ public function tearDown() : void \Vimeo\MysqlEngine\Server::reset(); } + public function testSumWithEmptyResultSetReturnsNull() + { + $sql = " + SELECT + SUM( + IF( + id > 1, + 0, + 1 + ) + ) + FROM + video_game_characters + WHERE + id > 100; + "; + + $pdo = self::getConnectionToFullDB(); + $query= $pdo->query($sql); + + $this->assertNull($query->fetchColumn()); + } + public function testSelectEmptyResults() { $pdo = self::getConnectionToFullDB(); @@ -34,6 +57,50 @@ public function testInvalidQuery() $this->assertSame([], $query->fetchAll(\PDO::FETCH_ASSOC)); } + public function testSelectWithDefaultFetchAssoc() + { + $pdo = self::getConnectionToFullDB(); + $pdo->setAttribute(\PDO::ATTR_DEFAULT_FETCH_MODE, \PDO::FETCH_ASSOC); + + $query = $pdo->prepare("SELECT id FROM `video_game_characters` WHERE `id` > :id ORDER BY `id` ASC"); + $query->bindValue(':id', 14); + $query->execute(); + + $this->assertSame( + [ + ['id' => '15'], + ['id' => '16'] + ], + $query->fetchAll() + ); + } + + public function testSelectFetchDefault() + { + if (!defined('PDO::FETCH_DEFAULT')) { + $this->markTestSkipped('PHP version does not support PDO::FETCH_DEFAULT'); + } + + $pdo = self::getConnectionToFullDB(); + + $query = $pdo->prepare("SELECT id FROM `video_game_characters` WHERE `id` > :id ORDER BY `id` ASC"); + $query->bindValue(':id', 14); + $query->execute(); + + $this->assertSame( + ['id' => '15', 0 => '15'], + $query->fetch(\PDO::FETCH_DEFAULT) + ); + + $this->assertSame( + [ + ['id' => '15', 0 => '15'], + ['id' => '16', 0 => '16'] + ], + $query->fetchAll(\PDO::FETCH_DEFAULT) + ); + } + public function testSelectFetchAssoc() { $pdo = self::getConnectionToFullDB(); @@ -225,6 +292,27 @@ public function testLeftJoinWithCount() ); } + public function testLeftJoinSkipIndex() + { + $pdo = self::getConnectionToFullDB(false); + + $query = $pdo->prepare( + "SELECT `id` + FROM `video_game_characters` FORCE INDEX (`PRIMARY`) + LEFT JOIN `character_tags` FORCE INDEX (`PRIMARY`) + ON `character_tags`.`character_id` = `video_game_characters`.`id` + LIMIT 1" + ); + $query->execute(); + + $this->assertSame( + [ + ['id' => 1] + ], + $query->fetchAll(\PDO::FETCH_ASSOC) + ); + } + public function testMaxValueAliasedToColumnName() { $pdo = self::getConnectionToFullDB(false); @@ -465,6 +553,113 @@ public function testDateArithhmetic() ); } + /** + * Test various timestamp differences using the TIMESTAMPDIFF function. + * + * This method verifies the calculation of differences in seconds, minutes, + * hours, days, months, and years. + */ + public function testTimestampDiff(): void + { + // Get a PDO instance for MySQL. + $pdo = self::getPdo('mysql:host=localhost;dbname=testdb'); + $pdo->setAttribute(\PDO::ATTR_EMULATE_PREPARES, false); + + // Prepare a single query with multiple TIMESTAMPDIFF calls. + $query = $pdo->prepare( + 'SELECT + TIMESTAMPDIFF(SECOND, \'2020-01-01 00:00:00\', \'2020-01-01 00:01:40\') as `second_diff`, + TIMESTAMPDIFF(MINUTE, \'2020-01-01 00:00:00\', \'2020-01-01 01:30:00\') as `minute_diff`, + TIMESTAMPDIFF(HOUR, \'2020-01-02 00:00:00\', \'2020-01-01 00:00:00\') as `hour_diff`, + TIMESTAMPDIFF(DAY, \'2020-01-01\', \'2020-01-10\') as `day_diff`, + TIMESTAMPDIFF(MONTH, \'2019-01-01\', \'2020-04-01\') as `month_diff`, + TIMESTAMPDIFF(YEAR, \'2010-05-15\', \'2020-05-15\') as `year_diff`' + ); + + $query->execute(); + + $results = $query->fetchAll(\PDO::FETCH_ASSOC); + $castedResults = array_map(function($row) { + return array_map('intval', $row); + }, $results); + + $this->assertSame( + [[ + 'second_diff' => 100, + 'minute_diff' => 90, + 'hour_diff' => -24, + 'day_diff' => 9, + 'month_diff' => 15, + 'year_diff' => 10, + ]], + $castedResults + ); + } + + public function testTimestampDiffThrowsExceptionWithWrongArgumentCount(): void + { + $this->expectException(\UnexpectedValueException::class); + $this->expectExceptionMessage('MySQL TIMESTAMPDIFF() function must be called with three arguments'); + + $pdo = self::getPdo('mysql:host=localhost;dbname=testdb'); + $pdo->setAttribute(\PDO::ATTR_EMULATE_PREPARES, false); + + $query = $pdo->prepare( + 'SELECT + TIMESTAMPDIFF(SECOND, \'2020-01-01 00:00:00\', \'2020-01-01 00:01:40\', \'2020-01-01 00:01:40\')', + ); + + $query->execute(); + } + + public function testTimestampDiffThrowsExceptionIfFirstArgNotColumnExpression(): void + { + $this->expectException(\UnexpectedValueException::class); + $this->expectExceptionMessage('MySQL TIMESTAMPDIFF() function should be called with a unit for interval'); + + $pdo = self::getPdo('mysql:host=localhost;dbname=testdb'); + $pdo->setAttribute(\PDO::ATTR_EMULATE_PREPARES, false); + + $query = $pdo->prepare( + 'SELECT + TIMESTAMPDIFF(\'2020-01-01 00:00:00\', \'2020-01-01 00:01:40\', \'2020-01-01 00:01:40\')', + ); + + $query->execute(); + } + + public function testTimestampDiffThrowsExceptionWithWrongDates(): void + { + $this->expectException(\UnexpectedValueException::class); + $this->expectExceptionMessage('Invalid datetime value passed to TIMESTAMPDIFF()'); + + $pdo = self::getPdo('mysql:host=localhost;dbname=testdb'); + $pdo->setAttribute(\PDO::ATTR_EMULATE_PREPARES, false); + + $query = $pdo->prepare( + 'SELECT + TIMESTAMPDIFF(SECOND, \'2020-01-01 00:0140\', \'2020-01-01 00:01:40\')', + ); + + $query->execute(); + } + + public function testTimestampDiffThrowsExceptionWithWrongInterval(): void + { + $this->expectException(\UnexpectedValueException::class); + $this->expectExceptionMessage('Unsupported unit \'CENTURY\' in TIMESTAMPDIFF()'); + + $pdo = self::getPdo('mysql:host=localhost;dbname=testdb'); + $pdo->setAttribute(\PDO::ATTR_EMULATE_PREPARES, false); + + $query = $pdo->prepare( + 'SELECT + TIMESTAMPDIFF(CENTURY, \'2020-01-01 00:01:40\', \'2020-01-01 00:01:40\')', + ); + + $query->execute(); + } + public function testCurDateFunction() { $pdo = self::getPdo('mysql:foo'); @@ -607,6 +802,52 @@ public function testRound() ); } + public function testCeil() + { + $pdo = self::getPdo('mysql:foo'); + $pdo->setAttribute(\PDO::ATTR_EMULATE_PREPARES, false); + + $query = $pdo->prepare('SELECT CEIL(3.1) AS a, CEILING(4.7) AS b, CEIL("abc") AS c, CEIL(5) AS d, CEIL("5.5") AS e'); + + $query->execute(); + + $this->assertSame( + [ + [ + 'a' => 4, + 'b' => 5, + 'c' => 0.0, + 'd' => 5, + 'e' => 6.0, + ], + ], + $query->fetchAll(\PDO::FETCH_ASSOC) + ); + } + + public function testFloor() + { + $pdo = self::getPdo('mysql:foo'); + $pdo->setAttribute(\PDO::ATTR_EMULATE_PREPARES, false); + + $query = $pdo->prepare('SELECT FLOOR(3.1) AS a, FLOOR(4.7) AS b, FLOOR("abc") AS c, FLOOR(5) AS d, FLOOR("6.5") AS e'); + + $query->execute(); + + $this->assertSame( + [ + [ + 'a' => 3, + 'b' => 4, + 'c' => 0.0, + 'd' => 5, + 'e' => 6.0, + ], + ], + $query->fetchAll(\PDO::FETCH_ASSOC) + ); + } + public function testIsInFullSubquery() { $pdo = self::getConnectionToFullDB(false); @@ -1092,6 +1333,101 @@ public function testSelectNullableFields() ); } + public function testUpdate() + { + $pdo = self::getConnectionToFullDB(false); + + // before update + $query = $pdo->prepare("SELECT `type` FROM `video_game_characters` WHERE `id` = 3"); + $query->execute(); + $this->assertSame([['type' => 'hero']], $query->fetchAll(\PDO::FETCH_ASSOC)); + + // prepare update + $query = $pdo->prepare("UPDATE `video_game_characters` SET `type` = 'villain' WHERE `id` = 3 LIMIT 1"); + $query->execute(); + + // after update + $query = $pdo->prepare("SELECT `type` FROM `video_game_characters` WHERE `id` = 3"); + $query->execute(); + $this->assertSame([['type' => 'villain']], $query->fetchAll(\PDO::FETCH_ASSOC)); + } + + public function testNegateOperationWithAnd() + { + // greater than + $pdo = self::getConnectionToFullDB(false); + $query = $pdo->prepare("SELECT COUNT(*) as 'count' FROM `video_game_characters` WHERE `console` = :console AND NOT (`powerups` > :powerups)"); + $query->bindValue(':console', 'nes'); + $query->bindValue(':powerups', 3); + $query->execute(); + + $this->assertSame([['count' => 8]], $query->fetchAll(\PDO::FETCH_ASSOC)); + + // equals + $query = $pdo->prepare("SELECT COUNT(*) as 'count' FROM `video_game_characters` WHERE `console` = :console AND NOT (`powerups` = :powerups)"); + $query->bindValue(':console', 'nes'); + $query->bindValue(':powerups', 0); + $query->execute(); + + $this->assertSame([['count' => 2]], $query->fetchAll(\PDO::FETCH_ASSOC)); + } + + public function testNegateOperationWithOr() + { + // greater than + $pdo = self::getConnectionToFullDB(false); + $query = $pdo->prepare("SELECT COUNT(*) as 'count' FROM `video_game_characters` WHERE `console` = :console OR NOT (`powerups` > :powerups)"); + $query->bindValue(':console', 'nes'); + $query->bindValue(':powerups', 3); + $query->execute(); + + $this->assertSame([['count' => 16]], $query->fetchAll(\PDO::FETCH_ASSOC)); + + // equals + $query = $pdo->prepare("SELECT COUNT(*) as 'count' FROM `video_game_characters` WHERE `console` = :console OR NOT (`powerups` = :powerups)"); + $query->bindValue(':console', 'nes'); + $query->bindValue(':powerups', 0); + $query->execute(); + + $this->assertSame([['count' => 9]], $query->fetchAll(\PDO::FETCH_ASSOC)); + } + + public function testNullEvaluation() + { + $pdo = self::getConnectionToFullDB(false); + + // case 1, where console value is null + $query = $pdo->prepare("SELECT COUNT(*) as 'count' FROM `video_game_characters` WHERE (:console IS NULL AND `console` = 'gameboy') OR NOT (:console IS NULL)"); + $query->bindValue(':console', NULL); + $query->execute(); + $this->assertSame([['count' => 1]], $query->fetchAll(\PDO::FETCH_ASSOC)); + + // case 2, where console value is not null + $query = $pdo->prepare("SELECT COUNT(*) as 'count' FROM `video_game_characters` WHERE (:console IS NULL AND `console` = 'gameboy') OR NOT (:console IS NULL)"); + $query->bindValue(':console', 'all'); + $query->execute(); + $this->assertSame([['count' => 16]], $query->fetchAll(\PDO::FETCH_ASSOC)); + } + + public function testNullWithDoubleNegativeEvaluation() + { + $pdo = self::getConnectionToFullDB(false); + + //case 1, where console value is not null + $query = $pdo->prepare("SELECT COUNT(*) as 'count' FROM `video_game_characters` WHERE (:console IS NOT NULL AND `console` = :console) OR NOT (:console IS NOT NULL)"); + $query->bindValue(':console', 'gameboy'); + $query->execute(); + + $this->assertSame([['count' => 1]], $query->fetchAll(\PDO::FETCH_ASSOC)); + + //case 1, where console value is null + $query = $pdo->prepare("SELECT COUNT(*) as 'count' FROM `video_game_characters` WHERE (:console IS NOT NULL AND `console` = :console) OR NOT (:console IS NOT NULL)"); + $query->bindValue(':console', NULL); + $query->execute(); + + $this->assertSame([['count' => 16]], $query->fetchAll(\PDO::FETCH_ASSOC)); + } + private static function getPdo(string $connection_string, bool $strict_mode = false) : \PDO { $options = $strict_mode ? [\PDO::MYSQL_ATTR_INIT_COMMAND => 'SET sql_mode="STRICT_ALL_TABLES"'] : []; @@ -1119,4 +1455,125 @@ private static function getConnectionToFullDB(bool $emulate_prepares = true, boo return $pdo; } + + /** + * @dataProvider leastArgumentsProvider + * @param array $args + * @param string|int|float|null $expected_value + */ + public function testLeast($args, $expected_value): void + { + // Get a PDO instance for MySQL. + $pdo = self::getPdo('mysql:host=localhost;dbname=testdb'); + $pdo->setAttribute(\PDO::ATTR_EMULATE_PREPARES, false); + + $args_str = implode(', ', array_map(function ($arg) { + return is_null($arg) ? 'null' : (string) $arg; + }, $args)); + + $query = $pdo->prepare(sprintf('SELECT LEAST(%s) as result', $args_str)); + $query->execute(); + + $result = $query->fetch(\PDO::FETCH_ASSOC); + $this->assertEquals( + ['result' => $expected_value], $result, + sprintf('Actual result is does not match the expected. Actual is: %s', print_r($result, true))); + } + + public function leastArgumentsProvider(): iterable + { + yield 'Should properly work with at least one \'null\' argument' => [ + 'args' => [1,2,null,42], + 'expected_value' => null + ]; + yield 'Should properly get the least integer argument' => [ + 'args' => [-1, 1,2,42], + 'expected_value' => '-1' + ]; + yield 'Should properly work with decimal argument' => [ + 'args' => [0.00, 0.1,2,42, -0.001], + 'expected_value' => '-0.001' + ]; + yield 'Should return proper precision if any argument is a float' => [ + 'args' => [1, 2.0001 , 42, 1.001], + 'expected_value' => '1.0000' + ]; + yield 'Should properly work with at least one string argument' => [ + 'args' => [1,2, "'null'", "'nulla'"], + 'expected_value' => '1' + ]; + yield 'Should properly work all string args' => [ + 'args' => ["'A'","'B'","'C'"], + 'expected_value' => 'A' + ]; + yield 'Should lexicographically compare #1' => [ + 'args' => ["'AA'","'AB'","'AC'"], + 'expected_value' => 'AA' + ]; + yield 'Should lexicographically compare #2' => [ + 'args' => ["'AA'","'AB'","'AC'", 1], + 'expected_value' => '1' + ]; + } + + /** @dataProvider leastWithExceptionProvider */ + public function testLeastThrowsExceptionWithWrongArgumentCount(array $args): void + { + $this->expectException(\UnexpectedValueException::class); + $this->expectExceptionMessage('Incorrect parameter count in the call to native function \'LEAST\''); + + $pdo = self::getPdo('mysql:host=localhost;dbname=testdb'); + $pdo->setAttribute(\PDO::ATTR_EMULATE_PREPARES, false); + + $args_str = implode(', ', array_map(fn ($arg) => strval($arg), $args)); + $query = $pdo->prepare(sprintf('SELECT LEAST(%s)', $args_str),); + + $query->execute(); + } + + public function leastWithExceptionProvider(): iterable + { + yield ['Should fail with single argument' => [1]]; + yield ['Should fail without any arguments' => []]; + } + + public function testNestedFunctions() + { + $pdo = self::getConnectionToFullDB(); + + $query = $pdo->prepare(" + SELECT + SUM( + TIMESTAMPDIFF( + SECOND, + CONVERT_TZ('2025-12-31 22:59:59', 'Europe/Kyiv', 'Europe/Kyiv'), + CONVERT_TZ('2025-12-31 23:59:59', 'Europe/Kyiv', 'Europe/Kyiv') + ) + ) + "); + $query->execute(); + + $this->assertSame(3600, (int)$query->fetchColumn()); + } + + public function testNestedFunctionsFromDB() + { + $pdo = self::getConnectionToFullDB(); + $count = $pdo->query("SELECT COUNT(*) FROM video_game_characters")->fetchColumn(); + + $query = $pdo->prepare(" + SELECT SUM( + TIMESTAMPDIFF( + SECOND, + CONVERT_TZ(`created_on`, 'Europe/Kyiv', 'Europe/Kyiv'), + CONVERT_TZ(`created_on` + INTERVAL 1 SECOND, 'Europe/Kyiv', 'Europe/Kyiv') + ) + ) + FROM `video_game_characters` + "); + + $query->execute(); + + $this->assertSame((int)$count, (int)$query->fetchColumn()); + } } diff --git a/tests/FunctionEvaluatorTest.php b/tests/FunctionEvaluatorTest.php new file mode 100644 index 00000000..cc188dba --- /dev/null +++ b/tests/FunctionEvaluatorTest.php @@ -0,0 +1,163 @@ +prepare($sql); + $query->execute(); + /** @var array> $result */ + $result = $query->fetchAll(\PDO::FETCH_ASSOC); + + if ($is_db_number) { + $this->assertNotEmpty($result); + $this->assertNotNull($result[0]['max']); + } else { + $this->assertSame([['max' => $expected]], $result); + } + } + + public static function maxValueProvider(): array + { + return [ + 'null when no rows' => [ + 'sql' => 'SELECT MAX(null) as `max` FROM `video_game_characters`', + 'expected' => null, + 'is_db_number' => false, + ], + 'max of scalar values' => [ + 'sql' => 'SELECT MAX(10) as `max` FROM `video_game_characters`', + 'expected' => '10', + 'is_db_number' => false, + ], + 'max in DB values' => [ + 'sql' => 'SELECT MAX(id) as `max` FROM `video_game_characters`', + 'expected' => '', + 'is_db_number' => true, + ], + ]; + } + + /** + * @dataProvider minValueProvider + */ + public function testSqlMin(string $sql, ?string $expected, bool $is_db_number) : void + { + $query = self::getConnectionToFullDB()->prepare($sql); + $query->execute(); + /** @var array> $result */ + $result = $query->fetchAll(\PDO::FETCH_ASSOC); + + if ($is_db_number) { + $this->assertNotEmpty($result); + $this->assertNotNull($result[0]['min']); + } else { + $this->assertSame([['min' => $expected]], $result); + } + } + + public static function minValueProvider(): array + { + return [ + 'null when no rows' => [ + 'sql' => 'SELECT MIN(null) as `min` FROM `video_game_characters`', + 'expected' => null, + 'is_db_number' => false, + ], + 'min of scalar values' => [ + 'sql' => 'SELECT MIN(10) as `min` FROM `video_game_characters`', + 'expected' => '10', + 'is_db_number' => false, + ], + 'min in DB values' => [ + 'sql' => 'SELECT MIN(id) as `min` FROM `video_game_characters`', + 'expected' => '', + 'is_db_number' => true, + ], + ]; + } + + private static function getPdo(string $connection_string, bool $strict_mode = false) : \PDO + { + $options = $strict_mode ? [\PDO::MYSQL_ATTR_INIT_COMMAND => 'SET sql_mode="STRICT_ALL_TABLES"'] : []; + + if (\PHP_MAJOR_VERSION === 8) { + return new \Vimeo\MysqlEngine\Php8\FakePdo($connection_string, '', '', $options); + } + + return new \Vimeo\MysqlEngine\Php7\FakePdo($connection_string, '', '', $options); + } + + /** + * @dataProvider convertTzProvider + */ + public function testConvertTz(string $sql, ?string $expected) + { + $query = self::getConnectionToFullDB()->prepare($sql); + $query->execute(); + + $this->assertSame($expected, $query->fetch(\PDO::FETCH_COLUMN)); + } + + private static function convertTzProvider(): array + { + return [ + 'normal conversion' => [ + 'sql' => "SELECT CONVERT_TZ('2025-09-23 02:30:00', 'UTC', 'Europe/Kyiv');", + 'expected' => "2025-09-23 05:30:00", + ], + 'same tz' => [ + 'sql' => "SELECT CONVERT_TZ('2025-12-31 23:59:59', 'Europe/Kyiv', 'Europe/Kyiv');", + 'expected' => "2025-12-31 23:59:59", + ], + 'crossing DST' => [ + 'sql' => "SELECT CONVERT_TZ('2025-07-01 12:00:00', 'America/New_York', 'UTC');", + 'expected' => "2025-07-01 16:00:00", + ], + 'null date' => [ + 'sql' => "SELECT CONVERT_TZ(NULL, 'UTC', 'Europe/Kyiv');", + 'expected' => null, + ], + 'invalid timezone' => [ + 'sql' => "SELECT CONVERT_TZ('2025-09-23 02:30:00', 'Invalid/Zone', 'UTC');", + 'expected' => null, + ], + 'invalid date' => [ + 'sql' => "SELECT CONVERT_TZ('not-a-date', 'UTC', 'UTC');", + 'expected' => null, + ] + ]; + } + + private static function getConnectionToFullDB(bool $emulate_prepares = true, bool $strict_mode = false) : \PDO + { + $pdo = self::getPdo('mysql:foo;dbname=test;', $strict_mode); + + $pdo->setAttribute(\PDO::ATTR_EMULATE_PREPARES, $emulate_prepares); + + // create table + $pdo->prepare(file_get_contents(__DIR__ . '/fixtures/create_table.sql'))->execute(); + + // insertData + $pdo->prepare(file_get_contents(__DIR__ . '/fixtures/bulk_character_insert.sql'))->execute(); + $pdo->prepare(file_get_contents(__DIR__ . '/fixtures/bulk_enemy_insert.sql'))->execute(); + $pdo->prepare(file_get_contents(__DIR__ . '/fixtures/bulk_tag_insert.sql'))->execute(); + + return $pdo; + } +} \ No newline at end of file diff --git a/tests/VariableEvaluatorTest.php b/tests/VariableEvaluatorTest.php new file mode 100644 index 00000000..adb33543 --- /dev/null +++ b/tests/VariableEvaluatorTest.php @@ -0,0 +1,66 @@ +getPdo() + ->prepare('SELECT @@session.time_zone'); + $query->execute(); + $result = $query->fetch(\PDO::FETCH_COLUMN); + + $this->assertSame(date_default_timezone_get(), $result); + } + + public function testNotImplementedGlobalVariable(): void + { + $this->expectException(\UnexpectedValueException::class); + $this->expectExceptionMessage("The SQL code SELECT @@collation_server; could not be evaluated"); + + $query = $this->getPdo() + ->prepare('SELECT @@collation_server;'); + $query->execute(); + $result = $query->fetch(\PDO::FETCH_COLUMN); + + $this->assertSame(date_default_timezone_get(), $result); + } + + public function testVariable(): void + { + $sql = " + SELECT (@var := @var + 2) AS `counter` + FROM (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) AS `virtual_rows` + CROSS JOIN (SELECT @var := 0) AS `vars`; + "; + + $query = $this->getPdo() + ->prepare($sql); + $query->execute(); + $result = $query->fetchAll(\PDO::FETCH_ASSOC); + $counters = array_map('intval', array_column($result, 'counter')); + $this->assertSame([2,4,6], $counters); + } + + private function getPdo(bool $strict_mode = false): \PDO + { + $connection_string = 'mysql:foo;dbname=test;'; + $options = $strict_mode ? [\PDO::MYSQL_ATTR_INIT_COMMAND => 'SET sql_mode="STRICT_ALL_TABLES"'] : []; + + if (\PHP_MAJOR_VERSION === 8) { + return new \Vimeo\MysqlEngine\Php8\FakePdo($connection_string, '', '', $options); + } + + return new \Vimeo\MysqlEngine\Php7\FakePdo($connection_string, '', '', $options); + } +} diff --git a/tests/fixtures/create_table.sql b/tests/fixtures/create_table.sql index f207482c..de2ff8a4 100644 --- a/tests/fixtures/create_table.sql +++ b/tests/fixtures/create_table.sql @@ -60,4 +60,25 @@ CREATE TABLE `orders` `created_on` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, `modified_on` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (`id`) -)ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci; \ No newline at end of file +) +ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci; + +CREATE TABLE `tweets` ( + `id` int(10) UNSIGNED NOT NULL AUTO_INCREMENT, + `title` varchar(256) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci, + `text` text CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci, + PRIMARY KEY (`id`) +) +ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci; + +CREATE TABLE `texts` ( + `id` int(10) UNSIGNED NOT NULL AUTO_INCREMENT, + `title_char_col` varchar(256) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci, + `title_col` varchar(256) COLLATE utf8mb4_unicode_ci, + `title` varchar(256) + `text_char_col` text CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci, + `text_col` text COLLATE utf8mb4_unicode_ci, + `text` text, + PRIMARY KEY (`id`) +) +ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci;