Skip to content

Commit

Permalink
Merge pull request #43 from orocrm/1.0
Browse files Browse the repository at this point in the history
BAP-9655: Doctrine extensions: TIMESTAMPDIFF function does not work properly in PostgeSQL
  • Loading branch information
x86demon authored Jul 17, 2017
2 parents fe381b8 + 027a738 commit 1c51d29
Show file tree
Hide file tree
Showing 4 changed files with 220 additions and 83 deletions.
127 changes: 72 additions & 55 deletions src/Oro/ORM/Query/AST/Platform/Functions/Postgresql/Timestampdiff.php
Original file line number Diff line number Diff line change
Expand Up @@ -4,13 +4,9 @@

use Doctrine\ORM\Query\AST\Node;
use Doctrine\ORM\Query\SqlWalker;

use Oro\ORM\Query\AST\Functions\Cast as CastDQL;
use Oro\ORM\Query\AST\Functions\Numeric\TimestampDiff as BaseFunction;
use Oro\ORM\Query\AST\Functions\SimpleFunction;
use Oro\ORM\Query\AST\Platform\Functions\PlatformFunctionNode;

class Timestampdiff extends PlatformFunctionNode
class Timestampdiff extends AbstractTimestampAwarePlatformFunctionNode
{
/**
* {@inheritdoc}
Expand All @@ -24,17 +20,7 @@ public function getSql(SqlWalker $sqlWalker)
/** @var Node $secondDateNode */
$secondDateNode = $this->parameters[BaseFunction::VAL2_KEY];

$castFunction = new Cast(
array(
CastDQL::PARAMETER_KEY => sprintf(
'ROUND(%s)',
$this->getSqlByUnit($unit, $firstDateNode, $secondDateNode, $sqlWalker)
),
CastDQL::TYPE_KEY => 'INT'
)
);

return $castFunction->getSql($sqlWalker);
return $this->getSqlByUnit($unit, $firstDateNode, $secondDateNode, $sqlWalker);
}

/**
Expand All @@ -50,6 +36,7 @@ public function getSql(SqlWalker $sqlWalker)
protected function getSqlByUnit($unit, Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
$method = 'getDiffFor' . ucfirst(strtolower($unit));

return call_user_func(array($this, $method), $firstDateNode, $secondDateNode, $sqlWalker);
}

Expand All @@ -59,15 +46,12 @@ protected function getSqlByUnit($unit, Node $firstDateNode, Node $secondDateNode
* @param SqlWalker $sqlWalker
* @return string
*/
protected function getDiffForSecond(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
protected function getDiffForMicrosecond(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
$firstDateTimestampFunction = new Timestamp(array(SimpleFunction::PARAMETER_KEY => $firstDateNode));
$secondDateTimestampFunction = new Timestamp(array(SimpleFunction::PARAMETER_KEY => $secondDateNode));

return sprintf(
'(EXTRACT(EPOCH FROM %s) - EXTRACT(EPOCH FROM %s))',
$secondDateTimestampFunction->getSql($sqlWalker),
$firstDateTimestampFunction->getSql($sqlWalker)
'EXTRACT(MICROSECOND FROM %s - %s)',
$this->getTimestampValue($secondDateNode, $sqlWalker),
$this->getTimestampValue($firstDateNode, $sqlWalker)
);
}

Expand All @@ -77,9 +61,11 @@ protected function getDiffForSecond(Node $firstDateNode, Node $secondDateNode, S
* @param SqlWalker $sqlWalker
* @return string
*/
protected function getDiffForMicrosecond(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
protected function getDiffForSecond(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
return $this->getDiffForSecond($firstDateNode, $secondDateNode, $sqlWalker) . ' * 1000000';
return $this->getFloorValue(
$this->getRawDiffForSecond($firstDateNode, $secondDateNode, $sqlWalker)
);
}

/**
Expand All @@ -90,7 +76,9 @@ protected function getDiffForMicrosecond(Node $firstDateNode, Node $secondDateNo
*/
protected function getDiffForMinute(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
return $this->getDiffForSecond($firstDateNode, $secondDateNode, $sqlWalker) . ' / 60';
return $this->getFloorValue(
$this->getRawDiffForSecond($firstDateNode, $secondDateNode, $sqlWalker) . ' / 60'
);
}

/**
Expand All @@ -101,7 +89,9 @@ protected function getDiffForMinute(Node $firstDateNode, Node $secondDateNode, S
*/
protected function getDiffForHour(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
return $this->getDiffForSecond($firstDateNode, $secondDateNode, $sqlWalker) . ' / 3600';
return $this->getFloorValue(
$this->getRawDiffForSecond($firstDateNode, $secondDateNode, $sqlWalker) . ' / 3600'
);
}

/**
Expand All @@ -112,13 +102,10 @@ protected function getDiffForHour(Node $firstDateNode, Node $secondDateNode, Sql
*/
protected function getDiffForDay(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
$firstDateTimestampFunction = new Timestamp(array(SimpleFunction::PARAMETER_KEY => $firstDateNode));
$secondDateTimestampFunction = new Timestamp(array(SimpleFunction::PARAMETER_KEY => $secondDateNode));

return sprintf(
'EXTRACT(DAY FROM %s - %s)',
$secondDateTimestampFunction->getSql($sqlWalker),
$firstDateTimestampFunction->getSql($sqlWalker)
$this->getTimestampValue($secondDateNode, $sqlWalker),
$this->getTimestampValue($firstDateNode, $sqlWalker)
);
}

Expand All @@ -130,7 +117,9 @@ protected function getDiffForDay(Node $firstDateNode, Node $secondDateNode, SqlW
*/
protected function getDiffForWeek(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
return $this->getDiffForDay($firstDateNode, $secondDateNode, $sqlWalker) . ' / 7';
return $this->getFloorValue(
$this->getDiffForDay($firstDateNode, $secondDateNode, $sqlWalker) . ' / 7'
);
}

/**
Expand All @@ -139,15 +128,20 @@ protected function getDiffForWeek(Node $firstDateNode, Node $secondDateNode, Sql
* @param SqlWalker $sqlWalker
* @return string
*/
protected function getDiffForYear(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
protected function getDiffForMonth(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
$firstDateYearFunction = new Year(array(SimpleFunction::PARAMETER_KEY => $firstDateNode));
$secondDateYearFunction = new Year(array(SimpleFunction::PARAMETER_KEY => $secondDateNode));
$firstDateTimestamp = $this->getTimestampValue($firstDateNode, $sqlWalker);
$secondDateTimestamp = $this->getTimestampValue($secondDateNode, $sqlWalker);

$months = sprintf(
'EXTRACT(MONTH from %s)',
$this->getAge($firstDateTimestamp, $secondDateTimestamp)
);

return sprintf(
'(%s - %s)',
$secondDateYearFunction->getSql($sqlWalker),
$firstDateYearFunction->getSql($sqlWalker)
'(%s * 12 + %s)',
$this->getDiffForYear($firstDateNode, $secondDateNode, $sqlWalker),
$months
);
}

Expand All @@ -157,16 +151,10 @@ protected function getDiffForYear(Node $firstDateNode, Node $secondDateNode, Sql
* @param SqlWalker $sqlWalker
* @return string
*/
protected function getDiffForMonth(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
protected function getDiffForQuarter(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
$firstDateMonthFunction = new Month(array(SimpleFunction::PARAMETER_KEY => $firstDateNode));
$secondDateMonthFunction = new Month(array(SimpleFunction::PARAMETER_KEY => $secondDateNode));

return sprintf(
'%s * 12 + (%s - %s)',
$this->getDiffForYear($firstDateNode, $secondDateNode, $sqlWalker),
$secondDateMonthFunction->getSql($sqlWalker),
$firstDateMonthFunction->getSql($sqlWalker)
return $this->getFloorValue(
$this->getDiffForMonth($firstDateNode, $secondDateNode, $sqlWalker) . ' / 3'
);
}

Expand All @@ -176,16 +164,45 @@ protected function getDiffForMonth(Node $firstDateNode, Node $secondDateNode, Sq
* @param SqlWalker $sqlWalker
* @return string
*/
protected function getDiffForQuarter(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
protected function getDiffForYear(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
$firstDateTimestamp = $this->getTimestampValue($firstDateNode, $sqlWalker);
$secondDateTimestamp = $this->getTimestampValue($secondDateNode, $sqlWalker);

return sprintf('EXTRACT(YEAR from %s)', $this->getAge($firstDateTimestamp, $secondDateTimestamp));
}

/**
* @param string $firstDateTimestamp
* @param string $secondDateTimestamp
* @return string
*/
protected function getAge($firstDateTimestamp, $secondDateTimestamp)
{
return sprintf('age(%s, %s)', $secondDateTimestamp, $firstDateTimestamp);
}

/**
* @param string $value
* @return string
*/
protected function getFloorValue($value)
{
$firstDateQuarterFunction = new Quarter(array(SimpleFunction::PARAMETER_KEY => $firstDateNode));
$secondDateQuarterFunction = new Quarter(array(SimpleFunction::PARAMETER_KEY => $secondDateNode));
return sprintf('FLOOR(%s)', $value);
}

/**
* @param Node $firstDateNode
* @param Node $secondDateNode
* @param SqlWalker $sqlWalker
* @return string
*/
protected function getRawDiffForSecond(Node $firstDateNode, Node $secondDateNode, SqlWalker $sqlWalker)
{
return sprintf(
'%s * 4 + (%s - %s)',
$this->getDiffForYear($firstDateNode, $secondDateNode, $sqlWalker),
$secondDateQuarterFunction->getSql($sqlWalker),
$firstDateQuarterFunction->getSql($sqlWalker)
'EXTRACT(EPOCH FROM %s - %s)',
$this->getTimestampValue($secondDateNode, $sqlWalker),
$this->getTimestampValue($firstDateNode, $sqlWalker)
);
}
}
13 changes: 10 additions & 3 deletions tests/Oro/Tests/ORM/AST/Query/Functions/fixtures/mysql/cast.yml
Original file line number Diff line number Diff line change
@@ -1,10 +1,17 @@
#INT
- functions:
- { name: "cast", className: "Oro\\ORM\\Query\\AST\\Functions\\Cast", type: "numeric" }
dql: "SELECT CAST('123' as int) FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: "SELECT CAST('123' AS signed) AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1"
dql: "SELECT CAST(12 as int) FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: "SELECT CAST(12 AS signed) AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1"
expectedResult:
- 123
- 12

- functions:
- { name: "cast", className: "Oro\\ORM\\Query\\AST\\Functions\\Cast", type: "numeric" }
dql: "SELECT CAST('12' as int) FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: "SELECT CAST('12' AS signed) AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1"
expectedResult:
- 12

#INTEGER
- functions:
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -7,15 +7,29 @@

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(SECOND, '2014-01-01 00:00:00', '2014-01-01 00:00:10') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(SECOND, '2014-01-01 00:00:00', '2014-01-01 00:00:10') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
dql: "SELECT TIMESTAMPDIFF(MICROSECOND, '2014-01-01 00:00:00.121212', '2014-01-01 00:00:03') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(MICROSECOND, '2014-01-01 00:00:00.121212', '2014-01-01 00:00:03') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 10
- 2878788

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(SECOND, '2014-01-01 00:00:00.123', '2014-01-01 00:00:10') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(SECOND, '2014-01-01 00:00:00.123', '2014-01-01 00:00:10') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 9

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(SECOND, '2014-01-01 00:00:00.111', '2014-01-01 00:00:07.845') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(SECOND, '2014-01-01 00:00:00.111', '2014-01-01 00:00:07.845') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 7

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(MINUTE, '2014-01-01 00:00:00', '2014-01-01 00:10:10') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(MINUTE, '2014-01-01 00:00:00', '2014-01-01 00:10:10') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
dql: "SELECT TIMESTAMPDIFF(MINUTE, '2014-01-01 00:00:00', '2014-01-01 00:10:40') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(MINUTE, '2014-01-01 00:00:00', '2014-01-01 00:10:40') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 10

Expand All @@ -33,6 +47,20 @@
expectedResult:
- 10

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(DAY, '2016-01-01 00:00:00', '2017-01-01 00:00:00') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(DAY, '2016-01-01 00:00:00', '2017-01-01 00:00:00') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 366

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(DAY, '2016-01-01 00:00:00', '2017-01-02 00:10:00') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(DAY, '2016-01-01 00:00:00', '2017-01-02 00:10:00') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 367

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(WEEK, '2014-01-01 00:00:00', '2014-03-15 10:10:10') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
Expand All @@ -42,10 +70,24 @@

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(MONTH, '2014-01-01 00:00:00', '2014-03-15 10:10:10') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(MONTH, '2014-01-01 00:00:00', '2014-03-15 10:10:10') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
dql: "SELECT TIMESTAMPDIFF(MONTH, '2016-01-01 00:00:00', '2017-01-01 00:00:00') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(MONTH, '2016-01-01 00:00:00', '2017-01-01 00:00:00') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 2
- 12

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(MONTH, '2016-01-01 00:00:01', '2017-01-01 00:00:00') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(MONTH, '2016-01-01 00:00:01', '2017-01-01 00:00:00') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 11

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(MONTH, '2016-01-01 00:00:01', '2017-02-01 00:00:02') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(MONTH, '2016-01-01 00:00:01', '2017-02-01 00:00:02') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 13

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
Expand All @@ -56,7 +98,22 @@

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(YEAR, '2014-01-01 00:00:00', '2015-04-15 10:10:10') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(YEAR, '2014-01-01 00:00:00', '2015-04-15 10:10:10') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
dql: "SELECT TIMESTAMPDIFF(QUARTER, '2016-01-01 00:00:01', '2016-06-01 00:00:00') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(QUARTER, '2016-01-01 00:00:01', '2016-06-01 00:00:00') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 1

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(YEAR, '2016-01-01 00:00:00', '2017-01-01 00:00:00') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(YEAR, '2016-01-01 00:00:00', '2017-01-01 00:00:00') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 1

- functions:
- { name: "timestampdiff", className: "Oro\\ORM\\Query\\AST\\Functions\\Numeric\\TimestampDiff", type: "numeric" }
dql: "SELECT TIMESTAMPDIFF(YEAR, '2016-01-01 00:00:01', '2017-01-01 00:00:00') FROM Oro\\Entities\\Foo f WHERE f.id = 1"
sql: SELECT TIMESTAMPDIFF(YEAR, '2016-01-01 00:00:01', '2017-01-01 00:00:00') AS sclr0 FROM test_foo t0_ WHERE t0_.id = 1
expectedResult:
- 0

Loading

0 comments on commit 1c51d29

Please sign in to comment.