From 0b6b1a9b113bd5113cf3f98d90a490bb7de33f92 Mon Sep 17 00:00:00 2001 From: Arjay Angeles Date: Tue, 7 May 2024 15:05:28 +0800 Subject: [PATCH] Merge pull request #850 from yajra/patch-paging fix: pagination when sorting by string with same values (cherry picked from commit 61681cb02d18c4ed7b0d9a8a66a71595c213850e) --- src/Oci8/Query/Grammars/OracleGrammar.php | 7 ----- tests/Database/Oci8QueryBuilderTest.php | 38 +++++++++++++---------- 2 files changed, 22 insertions(+), 23 deletions(-) diff --git a/src/Oci8/Query/Grammars/OracleGrammar.php b/src/Oci8/Query/Grammars/OracleGrammar.php index d2f6ebbb..d3e0cb0b 100644 --- a/src/Oci8/Query/Grammars/OracleGrammar.php +++ b/src/Oci8/Query/Grammars/OracleGrammar.php @@ -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}"; } diff --git a/tests/Database/Oci8QueryBuilderTest.php b/tests/Database/Oci8QueryBuilderTest.php index 371a43e5..415e985d 100644 --- a/tests/Database/Oci8QueryBuilderTest.php +++ b/tests/Database/Oci8QueryBuilderTest.php @@ -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()); @@ -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()); @@ -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() ); } @@ -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() ); } @@ -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() ); } @@ -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()); }