Skip to content
Merged
Show file tree
Hide file tree
Changes from 1 commit
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
Next Next commit
Inject database name in queries dynamically
  • Loading branch information
JanJakes committed Oct 14, 2025
commit b489eb72d8ee2b60a776fc25f32f4bc9b64a0109
107 changes: 107 additions & 0 deletions tests/WP_SQLite_Driver_Tests.php
Original file line number Diff line number Diff line change
Expand Up @@ -9244,4 +9244,111 @@ public function testCheckConstraintNotEnforced(): void {
$result[0]->{'Create Table'}
);
}

public function testDynamicDatabaseName(): void {
// Create a setter for the private property "$db_name".
$set_db_name = Closure::bind(
function ( $name ) {
$this->main_db_name = $name;
},
$this->engine,
WP_SQLite_Driver::class
);

// Default database name.
$result = $this->assertQuery( 'SELECT schema_name FROM information_schema.schemata ORDER BY schema_name' );
$this->assertEquals(
array(
(object) array( 'SCHEMA_NAME' => 'information_schema' ),
(object) array( 'SCHEMA_NAME' => 'wp' ),
),
$result
);

// Change the database name.
$set_db_name( 'wp_test_new' );
$result = $this->assertQuery( 'SELECT schema_name FROM information_schema.schemata ORDER BY schema_name' );
$this->assertEquals(
array(
(object) array( 'SCHEMA_NAME' => 'information_schema' ),
(object) array( 'SCHEMA_NAME' => 'wp_test_new' ),
),
$result
);
}

public function testDynamicDatabaseNameComplexScenario(): void {
// Create a setter for the private property "$db_name".
$set_db_name = Closure::bind(
function ( $name ) {
$this->main_db_name = $name;
},
$this->engine,
WP_SQLite_Driver::class
);

$this->assertQuery( 'CREATE TABLE t (id INT, db_name TEXT)' );
$this->assertQuery( 'INSERT INTO t (id, db_name) VALUES (1, "wp")' );
$this->assertQuery( 'INSERT INTO t (id, db_name) VALUES (2, "wp_test_new")' );
$this->assertQuery( 'INSERT INTO t (id, db_name) VALUES (3, "other")' );

$set_db_name( 'wp_test_new' );

$result = $this->assertQuery(
"SELECT sub.id, sub.table_schema, sub.table_name, sub.column_name
FROM (
SELECT * FROM information_schema.columns c
JOIN t ON t.db_name = CONCAT(COALESCE(c.table_schema, 'default'), '')
JOIN information_schema.schemata s ON s.schema_name = c.table_schema
WHERE c.table_name = 't'
) sub
ORDER BY ordinal_position"
);
$this->assertEquals(
array(
(object) array(
'id' => '2',
'TABLE_SCHEMA' => 'wp_test_new',
'TABLE_NAME' => 't',
'COLUMN_NAME' => 'id',
),
(object) array(
'id' => '2',
'TABLE_SCHEMA' => 'wp_test_new',
'TABLE_NAME' => 't',
'COLUMN_NAME' => 'db_name',
),
),
$result
);
}

public function testDynamicDatabaseNameWithWildcards(): void {
// Create a setter for the private property "$db_name".
$set_db_name = Closure::bind(
function ( $name ) {
$this->main_db_name = $name;
},
$this->engine,
WP_SQLite_Driver::class
);

// Default database name.
$result = $this->assertQuery(
'SELECT * FROM information_schema.schemata s'
);
$this->assertEquals( 'information_schema', $result[0]->SCHEMA_NAME );
$this->assertEquals( 'wp', $result[1]->SCHEMA_NAME );

// Default database name.
$set_db_name( 'wp_test_new' );
$result = $this->assertQuery(
'SELECT s.*
FROM information_schema.schemata s
LEFT JOIN information_schema.tables t ON t.table_schema = s.schema_name
ORDER BY s.schema_name'
);
$this->assertEquals( 'information_schema', $result[0]->SCHEMA_NAME );
$this->assertEquals( 'wp_test_new', $result[1]->SCHEMA_NAME );
}
}
98 changes: 90 additions & 8 deletions wp-includes/sqlite-ast/class-wp-sqlite-driver.php
Original file line number Diff line number Diff line change
Expand Up @@ -3005,6 +3005,8 @@ private function translate( $node ): ?string {
return $this->translate_query_expression( $node );
case 'querySpecification':
return $this->translate_query_specification( $node );
case 'tableRef':
return $this->translate_table_ref( $node );
case 'qualifiedIdentifier':
case 'tableRefWithWildcard':
$parts = $node->get_descendant_nodes( 'identifier' );
Expand Down Expand Up @@ -3404,14 +3406,7 @@ private function translate_qualified_identifier(

// Database-level object name (table, view, procedure, trigger, etc.).
if ( null !== $object_node ) {
if ( $is_information_schema ) {
$object_name = $this->unquote_sqlite_identifier(
$this->translate_sequence( $object_node->get_children() )
);
$parts[] = $this->information_schema_builder->get_table_name( false, $object_name );
} else {
$parts[] = $this->translate( $object_node );
}
$parts[] = $this->translate( $object_node );
}

// Object child name (column, index, etc.).
Expand Down Expand Up @@ -3939,6 +3934,93 @@ public function translate_select_item( WP_Parser_Node $node ): string {
return sprintf( '%s AS %s', $item, $alias );
}

/**
* Translate a MySQL table reference to SQLite.
*
* When the table reference targets an information schema table, we replace
* it with a subquery, injecting the configured database name dynamically.
*
* For example, the following query:
*
* SELECT *, t.*, t.table_schema FROM information_schema.tables t
*
* Will be translated to:
*
* SELECT *, `t`.*, `t`.`table_schema` FROM (
* SELECT
* `TABLE_CATALOG`,
* IIF(`TABLE_SCHEMA` = 'information_schema', `TABLE_SCHEMA`, 'database_name') AS `TABLE_SCHEMA`,
* `TABLE_NAME`,
* ...
* FROM `_wp_sqlite_mysql_information_schema_tables` AS `tables`
* ) `t`
*
* The same logic will be applied to table references in JOIN clauses as well.
*
* @param WP_Parser_Node $node The "tableRef" AST node.
* @return string The translated value.
* @throws WP_SQLite_Driver_Exception When the translation fails.
*/
public function translate_table_ref( WP_Parser_Node $node ): string {
// Information schema is currently accessible only in read-only queries.
if ( ! $this->is_readonly ) {
return $this->translate_sequence( $node->get_children() );
}

// The table reference is in "<schema>.<table>" or "<table>" format.
$parts = $node->get_descendant_nodes( 'identifier' );
$table = array_pop( $parts );
$schema = array_pop( $parts );

$schema_name = $schema ? $this->unquote_sqlite_identifier( $this->translate( $schema ) ) : null;
$table_name = $this->unquote_sqlite_identifier( $this->translate( $table ) );

// When the table reference targets an information schema table,
// we need to inject the configured database name dynamically.
if (
( null === $schema_name && 'information_schema' === $this->db_name )
|| ( null !== $schema_name && 'information_schema' === strtolower( $schema_name ) )
) {
$table_is_temporary = $this->information_schema_builder->temporary_table_exists( $table_name );
$sqlite_table_name = $this->information_schema_builder->get_table_name( $table_is_temporary, $table_name );

// We need to fetch the SQLite column information, because the information
// schema tables don't contain records for the information schema itself.
$columns = $this->execute_sqlite_query(
'SELECT name FROM pragma_table_info(?)',
array( $sqlite_table_name )
)->fetchAll( PDO::FETCH_COLUMN );

// List all columns in the table, replacing columns targeting database
// name columns with the configured database name.
$expanded_list = array();
foreach ( $columns as $column ) {
$quoted_column = $this->quote_sqlite_identifier( $column );
if ( str_contains( strtolower( $column ), 'schema' ) ) {
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

this is quite permissive – can we explicitly list the tables and columns we're interested in?

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@adamziel Ah, sure, we can! In this place, we know for sure that we're dealing with an information schema table column, so maybe we could also check if it contains schema_ or _schema, although listing is also easy—this should cover it:

'SCHEMA_NAME',
'TABLE_SCHEMA',
'VIEW_SCHEMA',
'INDEX_SCHEMA',
'CONSTRAINT_SCHEMA',
'UNIQUE_CONSTRAINT_SCHEMA',
'REFERENCED_TABLE_SCHEMA',
'TRIGGER_SCHEMA',

Or we could even list the exact columns for each table.

$expanded_list[] = sprintf(
"IIF(%s = 'information_schema', %s, %s) AS %s",
$quoted_column,
$quoted_column,
$this->connection->quote( $this->main_db_name ),
strtoupper( $quoted_column )
);
} else {
$expanded_list[] = $quoted_column;
}
}
$column_list = implode( ', ', $expanded_list );

// Compose information schema subquery.
return sprintf(
'(SELECT %s FROM %s AS %s)',
$column_list,
$this->quote_sqlite_identifier( $sqlite_table_name ),
$this->quote_sqlite_identifier( $table_name )
);
}
return $this->translate_sequence( $node->get_children() );
}

/**
* Recreate an existing table using data in the information schema.
*
Expand Down