Skip to content

Commit f3b4a75

Browse files
authored
Implement disambiguation for unqualified columns in ORDER BY (#232)
Resolves #228. Closes #231.
2 parents f6666fe + f98f1fd commit f3b4a75

File tree

5 files changed

+933
-17
lines changed

5 files changed

+933
-17
lines changed

phpcs.xml.dist

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -31,6 +31,7 @@
3131

3232
<!-- Directories and third party library exclusions. -->
3333
<exclude-pattern>/vendor/*</exclude-pattern>
34+
<exclude-pattern>/node_modules/*</exclude-pattern>
3435
<exclude-pattern>/wordpress/*</exclude-pattern>
3536
<exclude-pattern>/wp-includes/sqlite/class-wp-sqlite-crosscheck-db.php</exclude-pattern>
3637

tests/WP_SQLite_Driver_Tests.php

Lines changed: 253 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -6323,6 +6323,259 @@ public function testTransactionSavepoints(): void {
63236323
$this->assertSame( array(), (array) array_column( $result, 'id' ) );
63246324
}
63256325

6326+
public function testSelectOrderByAmbiguousColumnResolution(): void {
6327+
$this->assertQuery( 'CREATE TABLE t1 (id INT, name TEXT)' );
6328+
$this->assertQuery( 'CREATE TABLE t2 (id INT, name TEXT)' );
6329+
$this->assertQuery( 'INSERT INTO t1 (id, name) VALUES (1, "A1"), (2, "A2")' );
6330+
$this->assertQuery( 'INSERT INTO t2 (id, name) VALUES (1, "B2"), (2, "B1")' );
6331+
6332+
// The "name" column will be resolved to "t1.name" as per the SELECT item.
6333+
$result = $this->assertQuery( 'SELECT t1.name FROM t1 JOIN t2 ON t2.id = t1.id ORDER BY name DESC' );
6334+
$this->assertEquals(
6335+
array(
6336+
(object) array( 'name' => 'A2' ),
6337+
(object) array( 'name' => 'A1' ),
6338+
),
6339+
$result
6340+
);
6341+
6342+
// The "name" column will be resolved to "t2.name" as per the SELECT item.
6343+
$result = $this->assertQuery( 'SELECT t2.name FROM t1 JOIN t2 ON t2.id = t1.id ORDER BY name DESC' );
6344+
$this->assertEquals(
6345+
array(
6346+
(object) array( 'name' => 'B2' ),
6347+
(object) array( 'name' => 'B1' ),
6348+
),
6349+
$result
6350+
);
6351+
6352+
// The "name" column will be resolved to "t1.name", the "id" column will be resolved to "t2.id".
6353+
$this->assertQuery( 'INSERT INTO t1 (id, name) VALUES (3, "A2")' );
6354+
$this->assertQuery( 'INSERT INTO t2 (id, name) VALUES (3, "A2")' );
6355+
$result = $this->assertQuery( 'SELECT t2.id, t1.name FROM t1 JOIN t2 ON t2.id = t1.id ORDER BY name, id DESC' );
6356+
$this->assertEquals(
6357+
array(
6358+
(object) array(
6359+
'id' => '1',
6360+
'name' => 'A1',
6361+
),
6362+
(object) array(
6363+
'id' => '3',
6364+
'name' => 'A2',
6365+
),
6366+
(object) array(
6367+
'id' => '2',
6368+
'name' => 'A2',
6369+
),
6370+
),
6371+
$result
6372+
);
6373+
6374+
// The "name" column will be resolved to "t1.name" in the subquery and to "t2.name" in the root query.
6375+
$result = $this->assertQuery(
6376+
'
6377+
SELECT t2.name, s.name AS subquery_name
6378+
FROM (SELECT t1.id, t1.name FROM t1 JOIN t2 ON t2.id = t1.id ORDER BY name DESC LIMIT 1) s
6379+
JOIN t2 ON true
6380+
ORDER BY name DESC
6381+
'
6382+
);
6383+
$this->assertEquals(
6384+
array(
6385+
(object) array(
6386+
'name' => 'B2',
6387+
'subquery_name' => 'A2',
6388+
),
6389+
(object) array(
6390+
'name' => 'B1',
6391+
'subquery_name' => 'A2',
6392+
),
6393+
(object) array(
6394+
'name' => 'A2',
6395+
'subquery_name' => 'A2',
6396+
),
6397+
),
6398+
$result
6399+
);
6400+
6401+
// Parenthesized column reference can be used in both SELECT and ORDER BY lists.
6402+
$result = $this->assertQuery( 'SELECT (t1.name) FROM t1 JOIN t2 ON t2.id = t1.id ORDER BY (((name))) DESC' );
6403+
$this->assertEquals(
6404+
array(
6405+
(object) array( '(t1.name)' => 'A2' ),
6406+
(object) array( '(t1.name)' => 'A2' ),
6407+
(object) array( '(t1.name)' => 'A1' ),
6408+
),
6409+
$result
6410+
);
6411+
6412+
/*
6413+
* With multiple identical aliases and no ambiguous column references,
6414+
* it just works, although sometimes the order may differ from MySQL.
6415+
* It may be nondeterministic, but it seems like MySQL picks the first
6416+
* non-column alias, while SQLite sorts by the first alias in the list.
6417+
*
6418+
* When we replace "SELECT t1.name" with "SELECT t2.name" in the query
6419+
* below, the SQLite order will differ from MySQL.
6420+
*/
6421+
$result = $this->assertQuery(
6422+
"
6423+
SELECT t1.name AS name, CONCAT(t1.name, '-one') AS name, CONCAT(t2.name, '-two') AS name
6424+
FROM t1 JOIN t2 ON t2.id = t1.id
6425+
ORDER BY name DESC
6426+
"
6427+
);
6428+
$this->assertEquals(
6429+
array(
6430+
(object) array( 'name' => 'B1-two' ),
6431+
(object) array( 'name' => 'A2-two' ),
6432+
(object) array( 'name' => 'B2-two' ),
6433+
),
6434+
$result
6435+
);
6436+
6437+
/*
6438+
* The following query fails with "ambiguous column name" in MySQL, but
6439+
* in SQLite, it works. It's OK to keep this difference as MySQL behaves
6440+
* rather strangely in this case:
6441+
*
6442+
* 1) This is OK in MySQL:
6443+
* SELECT t1.name AS col, 123 AS col ... ORDER BY col
6444+
* 2) This fails in MySQL:
6445+
* SELECT t1.name AS col, t2.name AS col ... ORDER BY col
6446+
*/
6447+
$this->assertQuery( 'SELECT t1.name AS col, t2.name AS col FROM t1 JOIN t2 ON t2.id = t1.id ORDER BY col' );
6448+
}
6449+
6450+
public function testSelectOrderByAmbiguousColumnError(): void {
6451+
$this->assertQuery( 'CREATE TABLE t1 (id INT, name TEXT)' );
6452+
$this->assertQuery( 'CREATE TABLE t2 (id INT, name TEXT)' );
6453+
6454+
$this->expectException( 'WP_SQLite_Driver_Exception' );
6455+
$this->expectExceptionMessage( 'ambiguous column name: name' );
6456+
$this->assertQuery( 'SELECT t1.name, t2.name FROM t1 JOIN t2 ON t2.id = t1.id ORDER BY name DESC' );
6457+
}
6458+
6459+
6460+
public function testSelectOrderByAmbiguousColumnErrorWithoutSelectList(): void {
6461+
$this->assertQuery( 'CREATE TABLE t1 (id INT, name TEXT)' );
6462+
$this->assertQuery( 'CREATE TABLE t2 (id INT, name TEXT)' );
6463+
6464+
$this->expectException( 'WP_SQLite_Driver_Exception' );
6465+
$this->expectExceptionMessage( 'ambiguous column name: name' );
6466+
$this->assertQuery( 'SELECT 1 FROM t1 JOIN t2 ON t2.id = t1.id ORDER BY name' );
6467+
}
6468+
6469+
public function testSelectGroupByAmbiguousColumnResolution(): void {
6470+
$this->assertQuery( 'CREATE TABLE t1 (id INT, name TEXT)' );
6471+
$this->assertQuery( 'CREATE TABLE t2 (id INT, name TEXT)' );
6472+
$this->assertQuery( 'INSERT INTO t1 (id, name) VALUES (1, "A"), (2, "A")' );
6473+
$this->assertQuery( 'INSERT INTO t2 (id, name) VALUES (1, "B1"), (2, "B2")' );
6474+
6475+
// The "name" column will be resolved to "t1.name" as per the SELECT item.
6476+
$result = $this->assertQuery( 'SELECT t1.name FROM t1 JOIN t2 ON t2.id = t1.id GROUP BY name' );
6477+
$this->assertEquals(
6478+
array( (object) array( 'name' => 'A' ) ),
6479+
$result
6480+
);
6481+
6482+
// The "name" column will be resolved to "t2.name" as per the SELECT item.
6483+
$result = $this->assertQuery( 'SELECT t2.name FROM t1 JOIN t2 ON t2.id = t1.id GROUP BY name' );
6484+
$this->assertEquals(
6485+
array(
6486+
(object) array( 'name' => 'B1' ),
6487+
(object) array( 'name' => 'B2' ),
6488+
),
6489+
$result
6490+
);
6491+
6492+
// Parenthesized column reference can be used in both SELECT and GROUP BY lists.
6493+
$result = $this->assertQuery( 'SELECT (t1.name) FROM t1 JOIN t2 ON t2.id = t1.id GROUP BY (((name)))' );
6494+
$this->assertEquals(
6495+
array( (object) array( '(t1.name)' => 'A' ) ),
6496+
$result
6497+
);
6498+
6499+
/*
6500+
* The following query fails with "ambiguous column name" in MySQL, but
6501+
* in SQLite, it works. It's OK to keep this difference as MySQL behaves
6502+
* rather strangely in this case:
6503+
*
6504+
* 1) This is OK in MySQL:
6505+
* SELECT t1.name AS col, 123 AS col ... GROUP BY col
6506+
* 2) This fails in MySQL:
6507+
* SELECT t1.name AS col, t2.name AS col ... GROUP BY col
6508+
*/
6509+
$this->assertQuery( 'SELECT t1.name AS col, t2.name AS col FROM t1 JOIN t2 ON t2.id = t1.id GROUP BY col' );
6510+
}
6511+
6512+
public function testSelectGroupByAmbiguousColumnError(): void {
6513+
$this->assertQuery( 'CREATE TABLE t1 (id INT, name TEXT)' );
6514+
$this->assertQuery( 'CREATE TABLE t2 (id INT, name TEXT)' );
6515+
6516+
$this->expectException( 'WP_SQLite_Driver_Exception' );
6517+
$this->expectExceptionMessage( 'ambiguous column name: name' );
6518+
$this->assertQuery( 'SELECT t1.name, t2.name FROM t1 JOIN t2 ON t2.id = t1.id GROUP BY name' );
6519+
}
6520+
6521+
public function testSelectGroupByAmbiguousColumnErrorWithoutSelectList(): void {
6522+
$this->assertQuery( 'CREATE TABLE t1 (id INT, name TEXT)' );
6523+
$this->assertQuery( 'CREATE TABLE t2 (id INT, name TEXT)' );
6524+
6525+
$this->expectException( 'WP_SQLite_Driver_Exception' );
6526+
$this->expectExceptionMessage( 'ambiguous column name: name' );
6527+
$this->assertQuery( 'SELECT 1 FROM t1 JOIN t2 ON t2.id = t1.id GROUP BY name' );
6528+
}
6529+
6530+
public function testSelectHavingAmbiguousColumnResolution(): void {
6531+
$this->assertQuery( 'CREATE TABLE t1 (id INT, name TEXT)' );
6532+
$this->assertQuery( 'CREATE TABLE t2 (id INT, name TEXT)' );
6533+
$this->assertQuery( 'INSERT INTO t1 (id, name) VALUES (1, "A"), (2, "A")' );
6534+
$this->assertQuery( 'INSERT INTO t2 (id, name) VALUES (1, "B1"), (2, "B2")' );
6535+
6536+
// The "name" column will be resolved to "t1.name" as per the SELECT item.
6537+
$result = $this->assertQuery( 'SELECT t1.name FROM t1 JOIN t2 ON t2.id = t1.id HAVING name' );
6538+
$this->assertEquals( array(), $result );
6539+
6540+
// The "name" column will be resolved to "t2.name" as per the SELECT item.
6541+
$result = $this->assertQuery( 'SELECT t2.name FROM t1 JOIN t2 ON t2.id = t1.id HAVING name' );
6542+
$this->assertEquals( array(), $result );
6543+
6544+
// Parenthesized column reference can be used in both SELECT and GROUP BY lists.
6545+
$result = $this->assertQuery( 'SELECT (t1.name) FROM t1 JOIN t2 ON t2.id = t1.id HAVING (((name)))' );
6546+
$this->assertEquals( array(), $result );
6547+
6548+
/*
6549+
* The following query fails with "ambiguous column name" in MySQL, but
6550+
* in SQLite, it works. It's OK to keep this difference as MySQL behaves
6551+
* rather strangely in this case:
6552+
*
6553+
* 1) This is OK in MySQL:
6554+
* SELECT t1.name AS col, 123 AS col ... HAVING col
6555+
* 2) This fails in MySQL:
6556+
* SELECT t1.name AS col, t2.name AS col ... HAVING col
6557+
*/
6558+
$this->assertQuery( 'SELECT t1.name AS col, t2.name AS col FROM t1 JOIN t2 ON t2.id = t1.id HAVING col' );
6559+
}
6560+
6561+
public function testSelectHavingAmbiguousColumnError(): void {
6562+
$this->assertQuery( 'CREATE TABLE t1 (id INT, name TEXT)' );
6563+
$this->assertQuery( 'CREATE TABLE t2 (id INT, name TEXT)' );
6564+
6565+
$this->expectException( 'WP_SQLite_Driver_Exception' );
6566+
$this->expectExceptionMessage( 'ambiguous column name: name' );
6567+
$this->assertQuery( 'SELECT t1.name, t2.name FROM t1 JOIN t2 ON t2.id = t1.id HAVING name' );
6568+
}
6569+
6570+
public function testSelectHavingAmbiguousColumnErrorWithoutSelectList(): void {
6571+
$this->assertQuery( 'CREATE TABLE t1 (id INT, name TEXT)' );
6572+
$this->assertQuery( 'CREATE TABLE t2 (id INT, name TEXT)' );
6573+
6574+
$this->expectException( 'WP_SQLite_Driver_Exception' );
6575+
$this->expectExceptionMessage( 'ambiguous column name: name' );
6576+
$this->assertQuery( 'SELECT 1 FROM t1 JOIN t2 ON t2.id = t1.id HAVING name' );
6577+
}
6578+
63266579
public function testRollbackNonExistentTransactionSavepoint(): void {
63276580
$this->expectException( 'WP_SQLite_Driver_Exception' );
63286581
$this->expectExceptionMessage( 'no such savepoint: sp1' );

0 commit comments

Comments
 (0)