Skip to content

Commit

Permalink
Two versions of selectRowNumber for postgreSQL
Browse files Browse the repository at this point in the history
  • Loading branch information
Tomasz Narloch committed Jan 21, 2017
1 parent ec061e5 commit be84faa
Show file tree
Hide file tree
Showing 3 changed files with 92 additions and 19 deletions.
1 change: 0 additions & 1 deletion libraries/joomla/database/driver/postgresql.php
Original file line number Diff line number Diff line change
Expand Up @@ -140,7 +140,6 @@ public function connect()
pg_set_error_verbosity($this->connection, PGSQL_ERRORS_DEFAULT);
pg_query($this->connection, 'SET standard_conforming_strings=off');
pg_query($this->connection, 'SET escape_string_warning=off');
pg_query($this->connection, 'CREATE TEMP SEQUENCE ROW_NUMBER');
}

/**
Expand Down
33 changes: 32 additions & 1 deletion libraries/joomla/database/query/postgresql.php
Original file line number Diff line number Diff line change
Expand Up @@ -66,8 +66,19 @@ public function __toString()
switch ($this->type)
{
case 'select':
if ($this->selectRowNumber)
if ($this->selectRowNumber && $this->selectRowNumber['native'] === false)
{
// Workaround for postgresql version less than 8.4.0
try
{
$this->db->setQuery('CREATE TEMP SEQUENCE ROW_NUMBER');
$this->db->execute();
}
catch (JDatabaseExceptionExecuting $e)
{
// Do nothing, sequence exists
}

$orderBy = $this->selectRowNumber['orderBy'];
$orderColumnAlias = $this->selectRowNumber['orderColumnAlias'];

Expand Down Expand Up @@ -123,6 +134,16 @@ public function __toString()
$query .= (string) $this->where;
}

if ($this->selectRowNumber)
{
if ($this->order)
{
$query .= (string) $this->order;
}

break;
}

if ($this->group)
{
$query .= (string) $this->group;
Expand Down Expand Up @@ -745,6 +766,16 @@ public function selectRowNumber($orderBy, $orderColumnAlias)
{
$this->validateRowNumber($orderBy, $orderColumnAlias);

if (version_compare($this->db->getVersion(), '8.4.0') >= 0)
{
$this->selectRowNumber['native'] = true;
$this->select("ROW_NUMBER() OVER (ORDER BY $orderBy) AS $orderColumnAlias");
}
else
{
$this->selectRowNumber['native'] = false;
}

return $this;
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -190,19 +190,23 @@ public function test__toStringSelect()
*/
public function test__toStringSelectRowNumber()
{
$this->dbo->expects($this->exactly(6))
->method('getVersion')
->will($this->onConsecutiveCalls('8.3.18', '8.3.22', '8.3.23', '8.4.0', '9.1.24', '9.5.5'));

$this->_instance
->select('id')
->selectRowNumber('ordering', 'new_ordering')
->from('a')
->where('catid = 1');

$this->assertEquals(
PHP_EOL . "SELECT w.*, nextval('ROW_NUMBER') - 1 AS new_ordering FROM (" .
PHP_EOL . "SELECT id" .
PHP_EOL . "FROM a" .
PHP_EOL . "WHERE catid = 1" .
PHP_EOL . 'SELECT w.*, nextval(\'ROW_NUMBER\') - 1 AS new_ordering FROM (' .
PHP_EOL . 'SELECT id' .
PHP_EOL . 'FROM a' .
PHP_EOL . 'WHERE catid = 1' .
PHP_EOL . 'ORDER BY ordering' .
PHP_EOL . ") w,(SELECT setval('ROW_NUMBER', 1)) AS r",
PHP_EOL . ') w,(SELECT setval(\'ROW_NUMBER\', 1)) AS r',
(string) $this->_instance
);

Expand All @@ -214,26 +218,65 @@ public function test__toStringSelectRowNumber()
->where('catid = 1');

$this->assertEquals(
PHP_EOL . "SELECT w.*, nextval('ROW_NUMBER') - 1 AS \"ordering\" FROM (" .
PHP_EOL . "SELECT id" .
PHP_EOL . "FROM a" .
PHP_EOL . "WHERE catid = 1" .
PHP_EOL . 'SELECT w.*, nextval(\'ROW_NUMBER\') - 1 AS "ordering" FROM (' .
PHP_EOL . 'SELECT id' .
PHP_EOL . 'FROM a' .
PHP_EOL . 'WHERE catid = 1' .
PHP_EOL . 'ORDER BY ordering DESC' .
PHP_EOL . ") w,(SELECT setval('ROW_NUMBER', 1)) AS r",
PHP_EOL . ') w,(SELECT setval(\'ROW_NUMBER\', 1)) AS r',
(string) $this->_instance
);

$this->_instance
->clear('select')
->selectRowNumber('ordering DESC', $this->_instance->quoteName('ordering'));
->selectRowNumber('ordering ASC', $this->_instance->quoteName('ordering'));

$this->assertEquals(
PHP_EOL . "SELECT nextval('ROW_NUMBER') - 1 AS \"ordering\" FROM (" .
PHP_EOL . "SELECT 1" .
PHP_EOL . "FROM a" .
PHP_EOL . "WHERE catid = 1" .
PHP_EOL . 'ORDER BY ordering DESC' .
PHP_EOL . ") w,(SELECT setval('ROW_NUMBER', 1)) AS r",
PHP_EOL . 'SELECT nextval(\'ROW_NUMBER\') - 1 AS "ordering" FROM (' .
PHP_EOL . 'SELECT 1' .
PHP_EOL . 'FROM a' .
PHP_EOL . 'WHERE catid = 1' .
PHP_EOL . 'ORDER BY ordering ASC' .
PHP_EOL . ') w,(SELECT setval(\'ROW_NUMBER\', 1)) AS r',
(string) $this->_instance
);

$this->_instance
->clear()
->select('id')
->selectRowNumber('ordering', 'new_ordering')
->from('a')
->where('catid = 1');

$this->assertEquals(
PHP_EOL . 'SELECT id,ROW_NUMBER() OVER (ORDER BY ordering) AS new_ordering' .
PHP_EOL . 'FROM a' .
PHP_EOL . 'WHERE catid = 1',
(string) $this->_instance
);

$this->_instance
->clear()
->selectRowNumber('ordering DESC', $this->_instance->quoteName('ordering'))
->select('id')
->from('a')
->where('catid = 1');

$this->assertEquals(
PHP_EOL . 'SELECT ROW_NUMBER() OVER (ORDER BY ordering DESC) AS "ordering",id' .
PHP_EOL . 'FROM a' .
PHP_EOL . 'WHERE catid = 1',
(string) $this->_instance
);

$this->_instance
->clear('select')
->selectRowNumber('ordering ASC', $this->_instance->quoteName('ordering'));

$this->assertEquals(
PHP_EOL . 'SELECT ROW_NUMBER() OVER (ORDER BY ordering ASC) AS "ordering"' .
PHP_EOL . 'FROM a' .
PHP_EOL . 'WHERE catid = 1',
(string) $this->_instance
);
}
Expand Down

0 comments on commit be84faa

Please sign in to comment.