Skip to content
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
119 changes: 119 additions & 0 deletions tests/WP_SQLite_Ambiguous_Order_By_Tests.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,119 @@
<?php

class WP_SQLite_Ambiguous_Order_By_Tests {
/** @var WP_SQLite_Driver */
private $engine;

/** @var PDO */
private $sqlite;

// Before each test, we create a new database
public function setUp(): void {

Check failure on line 11 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "setUp" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "set_up"

Check failure on line 11 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "setUp" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "set_up"
$this->sqlite = new PDO( 'sqlite::memory:' );

$this->engine = new WP_SQLite_Driver(
new WP_SQLite_Connection( array( 'pdo' => $this->sqlite ) ),
'wp'
);

Check failure on line 18 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Whitespace found at end of line

Check failure on line 18 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Whitespace found at end of line
// Create test tables
$this->engine->query(
"CREATE TABLE t1 (id INT, name TEXT);"

Check failure on line 21 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

String "CREATE TABLE t1 (id INT, name TEXT);" does not require double quotes; use single quotes instead

Check failure on line 21 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

String "CREATE TABLE t1 (id INT, name TEXT);" does not require double quotes; use single quotes instead
);
$this->engine->query(
"CREATE TABLE t2 (t1_id INT, name TEXT);"

Check failure on line 24 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

String "CREATE TABLE t2 (t1_id INT, name TEXT);" does not require double quotes; use single quotes instead

Check failure on line 24 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

String "CREATE TABLE t2 (t1_id INT, name TEXT);" does not require double quotes; use single quotes instead
);

Check failure on line 26 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Whitespace found at end of line

Check failure on line 26 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Whitespace found at end of line
// Insert test data
$this->engine->query( 'INSERT INTO t1 (id, name) VALUES (1, "T1 A");' );
$this->engine->query( 'INSERT INTO t1 (id, name) VALUES (2, "T1 B");' );
$this->engine->query( 'INSERT INTO t2 (t1_id, name) VALUES (1, "T2 B");' );
$this->engine->query( 'INSERT INTO t2 (t1_id, name) VALUES (2, "T2 A");' );
}

private function assertQuery( $sql, $error_substring = null ) {

Check failure on line 34 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "assertQuery" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "assert_query"

Check failure on line 34 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "assertQuery" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "assert_query"
$retval = $this->engine->query( $sql );
if ( null === $error_substring ) {
if ( false === $retval ) {
throw new Exception( "Query failed: $sql" );
}
return $this->engine->get_query_results();
} else {
if ( false !== $retval ) {
throw new Exception( "Query should have failed but didn't: $sql" );
}
// For error tests, we just need to confirm it failed as expected
return null;
}
}

private function assertEquals( $expected, $actual, $message = '' ) {

Check failure on line 50 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "assertEquals" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "assert_equals"

Check failure on line 50 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "assertEquals" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "assert_equals"
if ( $expected !== $actual ) {
throw new Exception( "Assertion failed: expected $expected, got $actual. $message" );
}
}

private function assertCount( $expected, $array ) {

Check warning on line 56 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

It is recommended not to use reserved keyword "array" as function parameter name. Found: $array

Check failure on line 56 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "assertCount" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "assert_count"

Check warning on line 56 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

It is recommended not to use reserved keyword "array" as function parameter name. Found: $array

Check failure on line 56 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "assertCount" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "assert_count"
$actual = count( $array );
if ( $expected !== $actual ) {
throw new Exception( "Count assertion failed: expected $expected items, got $actual" );
}
}

public function testOrderByUnqualifiedColumnResolvedFromSelect() {

Check failure on line 63 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "testOrderByUnqualifiedColumnResolvedFromSelect" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "test_order_by_unqualified_column_resolved_from_select"

Check failure on line 63 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "testOrderByUnqualifiedColumnResolvedFromSelect" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "test_order_by_unqualified_column_resolved_from_select"
// Test case 1: SELECT t1.name should resolve ORDER BY name to t1.name
$result = $this->assertQuery( 'SELECT t1.name FROM t1 JOIN t2 ON t2.t1_id = t1.id ORDER BY name;' );
$this->assertCount( 2, $result );
$this->assertEquals( 'T1 A', $result[0]->name );
$this->assertEquals( 'T1 B', $result[1]->name );
}

public function testOrderByUnqualifiedColumnResolvedFromSelectDifferentTable() {

Check failure on line 71 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "testOrderByUnqualifiedColumnResolvedFromSelectDifferentTable" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "test_order_by_unqualified_column_resolved_from_select_different_table"

Check failure on line 71 in tests/WP_SQLite_Ambiguous_Order_By_Tests.php

View workflow job for this annotation

GitHub Actions / Check code style

Method name "testOrderByUnqualifiedColumnResolvedFromSelectDifferentTable" in class WP_SQLite_Ambiguous_Order_By_Tests is not in snake case format, try "test_order_by_unqualified_column_resolved_from_select_different_table"
// Test case 2: SELECT t2.name should resolve ORDER BY name to t2.name
$result = $this->assertQuery( 'SELECT t2.name FROM t1 JOIN t2 ON t2.t1_id = t1.id ORDER BY name;' );
$this->assertCount( 2, $result );
$this->assertEquals( 'T2 A', $result[0]->name );
$this->assertEquals( 'T2 B', $result[1]->name );
}

public function testOrderByAmbiguousColumnStillFails() {
// Test case 3: SELECT t1.name, t2.name should still fail for ORDER BY name (truly ambiguous)
$this->assertQuery(
'SELECT t1.name, t2.name FROM t1 JOIN t2 ON t2.t1_id = t1.id ORDER BY name;',
'ambiguous column name'
);
}

public function testOrderByColumnNotInSelectStillFails() {
// Test case 4: SELECT t1.id should still fail for ORDER BY name (name not in SELECT)
$this->assertQuery(
'SELECT t1.id FROM t1 JOIN t2 ON t2.t1_id = t1.id ORDER BY name;',
'ambiguous column name'
);
}

public function testOrderByQualifiedColumnStillWorks() {
// Existing qualified ORDER BY should continue to work
$result = $this->assertQuery( 'SELECT t1.name FROM t1 JOIN t2 ON t2.t1_id = t1.id ORDER BY t1.name;' );
$this->assertCount( 2, $result );
$this->assertEquals( 'T1 A', $result[0]->name );
$this->assertEquals( 'T1 B', $result[1]->name );
}

public function testOrderByWithoutJoinStillWorks() {
// Simple ORDER BY without JOINs should continue to work
$result = $this->assertQuery( 'SELECT name FROM t1 ORDER BY name;' );
$this->assertCount( 2, $result );
$this->assertEquals( 'T1 A', $result[0]->name );
$this->assertEquals( 'T1 B', $result[1]->name );
}

public function testOrderByMultipleColumnsWithQualification() {
// Test ORDER BY with multiple columns where some can be qualified
$result = $this->assertQuery( 'SELECT t1.name, t1.id FROM t1 JOIN t2 ON t2.t1_id = t1.id ORDER BY name, id;' );
$this->assertCount( 2, $result );
// Should order by t1.name, t1.id
$this->assertEquals( 'T1 A', $result[0]->name );
$this->assertEquals( 'T1 B', $result[1]->name );
}
}
213 changes: 213 additions & 0 deletions wp-includes/sqlite-ast/class-wp-sqlite-driver.php
Original file line number Diff line number Diff line change
Expand Up @@ -2485,6 +2485,217 @@
return $value;
}

/**
* Translate a MySQL queryExpression with ORDER BY ambiguous column fix.
*
* When an ORDER BY clause contains unqualified column references that would be
* ambiguous in SQLite but are unambiguous in the SELECT list, we qualify them
* using the SELECT list context.
*
* @param WP_Parser_Node $node The "queryExpression" AST node.
* @return string The translated query fragment.
* @throws WP_SQLite_Driver_Exception When the translation fails.
*/
private function translate_query_expression_with_order_by_fix( WP_Parser_Node $node ): string {
// Check if this queryExpression has an orderClause
$order_clause = $node->get_first_descendant_node( 'orderClause' );
if ( null === $order_clause ) {
// No ORDER BY clause, proceed with normal translation
return $this->translate_sequence( $node->get_children() );
}

// Extract column qualifications from SELECT list
$select_column_qualifications = $this->extract_select_column_qualifications( $node );

if ( empty( $select_column_qualifications ) ) {
// No qualified columns in SELECT, proceed with normal translation
return $this->translate_sequence( $node->get_children() );
}

// Translate all parts, but handle ORDER BY clause specially
$parts = array();
foreach ( $node->get_children() as $child ) {
if ( $child instanceof WP_Parser_Node && 'orderClause' === $child->rule_name ) {
$parts[] = $this->translate_order_clause_with_qualification( $child, $select_column_qualifications );
} else {
$part = $this->translate( $child );
if ( null !== $part ) {
$parts[] = $part;
}
}
}

return implode( ' ', $parts );
}

/**
* Extract column qualifications from the SELECT list of a query.
*
* Returns an associative array mapping unqualified column names to their
* qualified equivalents when there's exactly one qualified reference.
*
* @param WP_Parser_Node $query_expression The queryExpression node.
* @return array Map of unqualified name => qualified name.
*/
private function extract_select_column_qualifications( WP_Parser_Node $query_expression ): array {
$qualifications = array();

// Find all querySpecification nodes (there could be multiple in UNION queries)
$query_specs = $query_expression->get_descendant_nodes( 'querySpecification' );

foreach ( $query_specs as $query_spec ) {
$select_item_list = $query_spec->get_first_child_node( 'selectItemList' );
if ( null === $select_item_list ) {
continue;
}

foreach ( $select_item_list->get_child_nodes( 'selectItem' ) as $select_item ) {
$this->analyze_select_item_for_qualification( $select_item, $qualifications );
}
}

// Filter to only include unambiguous qualifications
$unambiguous = array();
foreach ( $qualifications as $unqualified => $qualified_list ) {
if ( count( $qualified_list ) === 1 ) {
$unambiguous[ $unqualified ] = $qualified_list[0];
}
}

return $unambiguous;
}

/**
* Analyze a SELECT item to extract column qualifications.
*
* @param WP_Parser_Node $select_item The selectItem node.
* @param array $qualifications Reference to qualifications array.
*/
private function analyze_select_item_for_qualification( WP_Parser_Node $select_item, array &$qualifications ): void {
// Look for columnRef nodes in the select item
$column_refs = $select_item->get_descendant_nodes( 'columnRef' );

foreach ( $column_refs as $column_ref ) {
$field_identifier = $column_ref->get_first_descendant_node( 'fieldIdentifier' );
if ( null === $field_identifier ) {
continue;
}

$identifiers = $field_identifier->get_descendant_nodes( 'identifier' );

// We're interested in qualified column references (table.column)
if ( count( $identifiers ) === 2 ) {
$table_name = $this->unquote_sqlite_identifier( $this->translate( $identifiers[0] ) );

Check warning on line 2588 in wp-includes/sqlite-ast/class-wp-sqlite-driver.php

View workflow job for this annotation

GitHub Actions / Check code style

Equals sign not aligned with surrounding assignments; expected 5 spaces but found 1 space

Check warning on line 2588 in wp-includes/sqlite-ast/class-wp-sqlite-driver.php

View workflow job for this annotation

GitHub Actions / Check code style

Equals sign not aligned with surrounding assignments; expected 5 spaces but found 1 space
$column_name = $this->unquote_sqlite_identifier( $this->translate( $identifiers[1] ) );

Check warning on line 2589 in wp-includes/sqlite-ast/class-wp-sqlite-driver.php

View workflow job for this annotation

GitHub Actions / Check code style

Equals sign not aligned with surrounding assignments; expected 4 spaces but found 1 space

Check warning on line 2589 in wp-includes/sqlite-ast/class-wp-sqlite-driver.php

View workflow job for this annotation

GitHub Actions / Check code style

Equals sign not aligned with surrounding assignments; expected 4 spaces but found 1 space
$qualified_name = $this->translate( $column_ref );

// Store the qualification mapping
if ( ! isset( $qualifications[ $column_name ] ) ) {
$qualifications[ $column_name ] = array();
}
if ( ! in_array( $qualified_name, $qualifications[ $column_name ], true ) ) {
$qualifications[ $column_name ][] = $qualified_name;
}
}
}
}

/**
* Translate an ORDER BY clause with column qualification.
*
* @param WP_Parser_Node $order_clause The orderClause node.
* @param array $qualifications Map of unqualified => qualified names.
* @return string The translated ORDER BY clause.
*/
private function translate_order_clause_with_qualification( WP_Parser_Node $order_clause, array $qualifications ): string {
$parts = array();

foreach ( $order_clause->get_children() as $child ) {
if ( $child instanceof WP_Parser_Node && 'orderList' === $child->rule_name ) {
$parts[] = $this->translate_order_list_with_qualification( $child, $qualifications );
} else {
$part = $this->translate( $child );
if ( null !== $part ) {
$parts[] = $part;
}
}
}

return implode( ' ', $parts );
}

/**
* Translate an ORDER BY list with column qualification.
*
* @param WP_Parser_Node $order_list The orderList node.
* @param array $qualifications Map of unqualified => qualified names.
* @return string The translated ORDER BY list.
*/
private function translate_order_list_with_qualification( WP_Parser_Node $order_list, array $qualifications ): string {
$parts = array();

foreach ( $order_list->get_child_nodes( 'orderExpression' ) as $order_expr ) {
$parts[] = $this->translate_order_expression_with_qualification( $order_expr, $qualifications );
}

return implode( ', ', $parts );
}

/**
* Translate an ORDER BY expression with column qualification.
*
* @param WP_Parser_Node $order_expr The orderExpression node.
* @param array $qualifications Map of unqualified => qualified names.
* @return string The translated ORDER BY expression.
*/
private function translate_order_expression_with_qualification( WP_Parser_Node $order_expr, array $qualifications ): string {
$parts = array();

foreach ( $order_expr->get_children() as $child ) {
if ( $child instanceof WP_Parser_Node && 'expr' === $child->rule_name ) {
$parts[] = $this->translate_expr_with_qualification( $child, $qualifications );
} else {
$part = $this->translate( $child );
if ( null !== $part ) {
$parts[] = $part;
}
}
}

return implode( ' ', $parts );
}

/**
* Translate an expression with column qualification for ORDER BY.
*
* @param WP_Parser_Node $expr The expr node.
* @param array $qualifications Map of unqualified => qualified names.
* @return string The translated expression.
*/
private function translate_expr_with_qualification( WP_Parser_Node $expr, array $qualifications ): string {
// Check if this expression is a simple unqualified column reference
$column_ref = $expr->get_first_descendant_node( 'columnRef' );
if ( null !== $column_ref ) {
$field_identifier = $column_ref->get_first_descendant_node( 'fieldIdentifier' );
if ( null !== $field_identifier ) {
$identifiers = $field_identifier->get_descendant_nodes( 'identifier' );

// Check if this is an unqualified column reference (just column name)
if ( count( $identifiers ) === 1 ) {
$column_name = $this->unquote_sqlite_identifier( $this->translate( $identifiers[0] ) );

// If we have a qualification for this column, use it
if ( isset( $qualifications[ $column_name ] ) ) {
return $qualifications[ $column_name ];
}
}
}
}

// Not a simple unqualified column reference, or no qualification available
return $this->translate( $expr );
}

/**
* Translate a MySQL AST node or token to an SQLite query fragment.
*
Expand Down Expand Up @@ -2512,6 +2723,8 @@

$rule_name = $node->rule_name;
switch ( $rule_name ) {
case 'queryExpression':
return $this->translate_query_expression_with_order_by_fix( $node );
case 'querySpecification':
// Translate "HAVING ..." without "GROUP BY ..." to "GROUP BY 1 HAVING ...".
if ( $node->has_child_node( 'havingClause' ) && ! $node->has_child_node( 'groupByClause' ) ) {
Expand Down
Loading