Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
73 changes: 73 additions & 0 deletions src/Processor/Expression/FunctionEvaluator.php
Original file line number Diff line number Diff line change
Expand Up @@ -99,6 +99,8 @@ public static function evaluate(
return self::sqlCeiling($conn, $scope, $expr, $row, $result);
case 'FLOOR':
return self::sqlFloor($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':
Expand Down Expand Up @@ -1545,4 +1547,75 @@ 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<string, mixed> $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()");
}
}
}
112 changes: 111 additions & 1 deletion tests/EndToEndTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,9 @@
namespace Vimeo\MysqlEngine\Tests;

use PDOException;
use Vimeo\MysqlEngine\Parser\Token;
use Vimeo\MysqlEngine\Query\Expression\ColumnExpression;
use Vimeo\MysqlEngine\TokenType;

class EndToEndTest extends \PHPUnit\Framework\TestCase
{
Expand Down Expand Up @@ -530,6 +533,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');
Expand Down Expand Up @@ -1221,7 +1331,7 @@ public function testUpdate()
$query->execute();
$this->assertSame([['type' => 'villain']], $query->fetchAll(\PDO::FETCH_ASSOC));
}

public function testNegateOperationWithAnd()
{
// greater than
Expand Down