Skip to content

Commit

Permalink
Merge pull request #851 from yajra/paging
Browse files Browse the repository at this point in the history
[10.x] fix: pagination when sorting by string with same values
  • Loading branch information
yajra committed May 7, 2024
2 parents 13e8fae + 0b6b1a9 commit 837dad5
Show file tree
Hide file tree
Showing 2 changed files with 22 additions and 23 deletions.
7 changes: 0 additions & 7 deletions src/Oci8/Query/Grammars/OracleGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -177,13 +177,6 @@ protected function compileTableExpression($sql, $constraint, $query)
return "select * from ({$sql}) where rownum {$constraint}";
}

if (! is_null($query->limit && ! is_null($query->offset))) {
$start = $query->offset + 1;
$finish = $query->offset + $query->limit;

return "select t2.* from ( select rownum AS \"rn\", t1.* from ({$sql}) t1 where rownum <= {$finish}) t2 where t2.\"rn\" >= {$start}";
}

return "select t2.* from ( select rownum AS \"rn\", t1.* from ({$sql}) t1 ) t2 where t2.\"rn\" {$constraint}";
}

Expand Down
38 changes: 22 additions & 16 deletions tests/Database/Oci8QueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -863,7 +863,7 @@ public function testSubSelectWhereIns()
$q->select('id')->from('users')->where('age', '>', 25)->take(3);
});
$this->assertEquals(
'select * from "USERS" where "ID" in (select t2.* from ( select rownum AS "rn", t1.* from (select "ID" from "USERS" where "AGE" > ?) t1 where rownum <= 3) t2 where t2."rn" >= 1)',
'select * from "USERS" where "ID" in (select t2.* from ( select rownum AS "rn", t1.* from (select "ID" from "USERS" where "AGE" > ?) t1 ) t2 where t2."rn" between 1 and 3)',
$builder->toSql()
);
$this->assertEquals([25], $builder->getBindings());
Expand All @@ -873,7 +873,7 @@ public function testSubSelectWhereIns()
$q->select('id')->from('users')->where('age', '>', 25)->take(3);
});
$this->assertEquals(
'select * from "USERS" where "ID" not in (select t2.* from ( select rownum AS "rn", t1.* from (select "ID" from "USERS" where "AGE" > ?) t1 where rownum <= 3) t2 where t2."rn" >= 1)',
'select * from "USERS" where "ID" not in (select t2.* from ( select rownum AS "rn", t1.* from (select "ID" from "USERS" where "AGE" > ?) t1 ) t2 where t2."rn" between 1 and 3)',
$builder->toSql()
);
$this->assertEquals([25], $builder->getBindings());
Expand Down Expand Up @@ -1111,7 +1111,7 @@ public function testOffset()
$builder = $this->getBuilder();
$builder->select('*')->from('users')->offset(10);
$this->assertEquals(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 10) t2 where t2."rn" >= 11',
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" >= 11',
$builder->toSql()
);
}
Expand All @@ -1121,35 +1121,35 @@ public function testLimitsAndOffsets()
$builder = $this->getBuilder();
$builder->select('*')->from('users')->offset(5)->limit(10);
$this->assertEquals(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 15) t2 where t2."rn" >= 6',
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 6 and 15',
$builder->toSql()
);

$builder = $this->getBuilder();
$builder->select('*')->from('users')->skip(5)->take(10);
$this->assertEquals(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 15) t2 where t2."rn" >= 6',
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 6 and 15',
$builder->toSql()
);

$builder = $this->getBuilder();
$builder->select('*')->from('users')->skip(-5)->take(10);
$this->assertEquals(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 10) t2 where t2."rn" >= 1',
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 1 and 10',
$builder->toSql()
);

$builder = $this->getBuilder();
$builder->select('*')->from('users')->forPage(2, 15);
$this->assertEquals(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 30) t2 where t2."rn" >= 16',
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 16 and 30',
$builder->toSql()
);

$builder = $this->getBuilder();
$builder->select('*')->from('users')->forPage(-2, 15);
$this->assertEquals(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 15) t2 where t2."rn" >= 1',
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 1 and 15',
$builder->toSql()
);
}
Expand All @@ -1159,14 +1159,14 @@ public function testLimitAndOffsetToPaginateOne()
$builder = $this->getBuilder();
$builder->select('*')->from('users')->offset(0)->limit(1);
$this->assertEquals(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 1) t2 where t2."rn" >= 1',
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 1 and 1',
$builder->toSql()
);

$builder = $this->getBuilder();
$builder->select('*')->from('users')->offset(1)->limit(1);
$this->assertEquals(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 2) t2 where t2."rn" >= 2',
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 2 and 2',
$builder->toSql()
);
}
Expand All @@ -1175,32 +1175,38 @@ public function testForPage()
{
$builder = $this->getBuilder();
$builder->select('*')->from('users')->forPage(2, 15);
$this->assertSame('select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 30) t2 where t2."rn" >= 16',
$this->assertSame(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 16 and 30',
$builder->toSql());

$builder = $this->getBuilder();
$builder->select('*')->from('users')->forPage(0, 15);
$this->assertSame('select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 15) t2 where t2."rn" >= 1',
$this->assertSame(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 1 and 15',
$builder->toSql());

$builder = $this->getBuilder();
$builder->select('*')->from('users')->forPage(-2, 15);
$this->assertSame('select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 15) t2 where t2."rn" >= 1',
$this->assertSame(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 1 and 15',
$builder->toSql());

$builder = $this->getBuilder();
$builder->select('*')->from('users')->forPage(2, 0);
$this->assertSame('select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 0) t2 where t2."rn" >= 1',
$this->assertSame(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 1 and 0',
$builder->toSql());

$builder = $this->getBuilder();
$builder->select('*')->from('users')->forPage(0, 0);
$this->assertSame('select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 0) t2 where t2."rn" >= 1',
$this->assertSame(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 1 and 0',
$builder->toSql());

$builder = $this->getBuilder();
$builder->select('*')->from('users')->forPage(-2, 0);
$this->assertSame('select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 where rownum <= 0) t2 where t2."rn" >= 1',
$this->assertSame(
'select t2.* from ( select rownum AS "rn", t1.* from (select * from "USERS") t1 ) t2 where t2."rn" between 1 and 0',
$builder->toSql());
}

Expand Down

0 comments on commit 837dad5

Please sign in to comment.