Skip to content

Commit cbcdaa5

Browse files
authored
Dynamic database name (#266)
This PR replaces #262. It is a simpler solution to the same problem: When a table reference targets an information schema table, we replace it with a subquery, injecting the configured database name dynamically: ```sql -- 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. --- With the new SQLite driver, we keep running into issues with missing and incorrect database name values (#197, #203, #226, #260, #261, and other issues). Thinking through this further, I came to the conclusion that to provide maximum flexibility and portability, it would be best to provide an API in the shape of: _"Mount `my-sqlite-file.sqlite` as `my-db-name`."_ Even if we consider adding multi-database support one day, it would still be great to allow mounting additional SQLite files under dynamic database names. I don't see any downsides to doing this, except maybe that we'll have to choose some database name in some scenarios, such as in database admin tools. However, in these cases we can use a reasonable default or the file name. This is a WIP pull request demonstrating the simplest approach. For it to be merged, I only need to resolve how the existing database name values should be treated.
1 parent 3951308 commit cbcdaa5

6 files changed

+889
-628
lines changed

tests/WP_SQLite_Driver_Tests.php

Lines changed: 159 additions & 36 deletions
Original file line numberDiff line numberDiff line change
@@ -5998,42 +5998,6 @@ public function testDatabaseNameEmpty(): void {
59985998
new WP_SQLite_Driver( $connection, '' );
59995999
}
60006000

6001-
public function testDatabaseNameMismatch(): void {
6002-
$pdo = new PDO( 'sqlite::memory:' );
6003-
$connection = new WP_SQLite_Connection( array( 'pdo' => $pdo ) );
6004-
6005-
// Create a driver with database name 'db-one'.
6006-
new WP_SQLite_Driver( $connection, 'db-one' );
6007-
6008-
// Create another driver with the same name - no errors.
6009-
new WP_SQLite_Driver( $connection, 'db-one' );
6010-
6011-
// Create a driver with a different name - failure.
6012-
$this->expectException( WP_SQLite_Driver_Exception::class );
6013-
$this->expectExceptionMessage( "Incorrect database name. The database was created with name 'db-one', but 'db-two' is used in the current session." );
6014-
new WP_SQLite_Driver( $connection, 'db-two' );
6015-
}
6016-
6017-
public function testDatabaseNameMismatchWithExistingInformationSchemaTableData(): void {
6018-
$pdo = new PDO( 'sqlite::memory:' );
6019-
$connection = new WP_SQLite_Connection( array( 'pdo' => $pdo ) );
6020-
6021-
// Create a driver with database name 'db-one'.
6022-
$driver = new WP_SQLite_Driver( $connection, 'db-one' );
6023-
6024-
// Create a table so that there is a record in the information schema.
6025-
$driver->query( 'CREATE TABLE t (id INT)' );
6026-
6027-
// Delete all variables, including driver version and database name.
6028-
$pdo->exec( sprintf( 'DELETE FROM %s', WP_SQLite_Driver::GLOBAL_VARIABLES_TABLE_NAME ) );
6029-
6030-
// Create a driver with a different name - failure.
6031-
// An information schema record with a different database name already exists.
6032-
$this->expectException( WP_SQLite_Driver_Exception::class );
6033-
$this->expectExceptionMessage( "Incorrect database name. The database was created with name 'db-one', but 'db-two' is used in the current session." );
6034-
new WP_SQLite_Driver( $connection, 'db-two' );
6035-
}
6036-
60376001
public function testSelectColumnNames(): void {
60386002
$this->assertQuery( 'CREATE TABLE t (id INT, name VARCHAR(255))' );
60396003
$this->assertQuery( 'INSERT INTO t (id, name) VALUES (1, "John"), (2, "Jane")' );
@@ -9244,4 +9208,163 @@ public function testCheckConstraintNotEnforced(): void {
92449208
$result[0]->{'Create Table'}
92459209
);
92469210
}
9211+
9212+
public function testDynamicDatabaseName(): void {
9213+
// Create a setter for the private property "$db_name".
9214+
$set_db_name = Closure::bind(
9215+
function ( $name ) {
9216+
$this->main_db_name = $name;
9217+
},
9218+
$this->engine,
9219+
WP_SQLite_Driver::class
9220+
);
9221+
9222+
// Default database name.
9223+
$result = $this->assertQuery( 'SELECT schema_name FROM information_schema.schemata ORDER BY schema_name' );
9224+
$this->assertEquals(
9225+
array(
9226+
(object) array( 'SCHEMA_NAME' => 'information_schema' ),
9227+
(object) array( 'SCHEMA_NAME' => 'wp' ),
9228+
),
9229+
$result
9230+
);
9231+
9232+
// Change the database name.
9233+
$set_db_name( 'wp_test_new' );
9234+
$result = $this->assertQuery( 'SELECT schema_name FROM information_schema.schemata ORDER BY schema_name' );
9235+
$this->assertEquals(
9236+
array(
9237+
(object) array( 'SCHEMA_NAME' => 'information_schema' ),
9238+
(object) array( 'SCHEMA_NAME' => 'wp_test_new' ),
9239+
),
9240+
$result
9241+
);
9242+
9243+
// Ensure it works with table aliases.
9244+
$result = $this->assertQuery( 'SELECT s.schema_name FROM information_schema.schemata AS s' );
9245+
$this->assertEquals(
9246+
array(
9247+
(object) array( 'SCHEMA_NAME' => 'information_schema' ),
9248+
(object) array( 'SCHEMA_NAME' => 'wp_test_new' ),
9249+
),
9250+
$result
9251+
);
9252+
}
9253+
9254+
public function testDynamicDatabaseNameComplexScenario(): void {
9255+
// Create a setter for the private property "$db_name".
9256+
$set_db_name = Closure::bind(
9257+
function ( $name ) {
9258+
$this->main_db_name = $name;
9259+
},
9260+
$this->engine,
9261+
WP_SQLite_Driver::class
9262+
);
9263+
9264+
$this->assertQuery( 'CREATE TABLE t (id INT, db_name TEXT)' );
9265+
$this->assertQuery( 'INSERT INTO t (id, db_name) VALUES (1, "wp")' );
9266+
$this->assertQuery( 'INSERT INTO t (id, db_name) VALUES (2, "wp_test_new")' );
9267+
$this->assertQuery( 'INSERT INTO t (id, db_name) VALUES (3, "other")' );
9268+
9269+
$set_db_name( 'wp_test_new' );
9270+
9271+
$result = $this->assertQuery(
9272+
"SELECT sub.id, sub.table_schema, sub.table_name, sub.column_name
9273+
FROM (
9274+
SELECT * FROM information_schema.columns c
9275+
JOIN t ON t.db_name = CONCAT(COALESCE(c.table_schema, 'default'), '')
9276+
JOIN information_schema.schemata s ON s.schema_name = c.table_schema
9277+
WHERE c.table_name = 't'
9278+
) sub
9279+
ORDER BY ordinal_position"
9280+
);
9281+
$this->assertEquals(
9282+
array(
9283+
(object) array(
9284+
'id' => '2',
9285+
'TABLE_SCHEMA' => 'wp_test_new',
9286+
'TABLE_NAME' => 't',
9287+
'COLUMN_NAME' => 'id',
9288+
),
9289+
(object) array(
9290+
'id' => '2',
9291+
'TABLE_SCHEMA' => 'wp_test_new',
9292+
'TABLE_NAME' => 't',
9293+
'COLUMN_NAME' => 'db_name',
9294+
),
9295+
),
9296+
$result
9297+
);
9298+
}
9299+
9300+
public function testDynamicDatabaseNameWithWildcards(): void {
9301+
// Create a setter for the private property "$db_name".
9302+
$set_db_name = Closure::bind(
9303+
function ( $name ) {
9304+
$this->main_db_name = $name;
9305+
},
9306+
$this->engine,
9307+
WP_SQLite_Driver::class
9308+
);
9309+
9310+
// Default database name.
9311+
$result = $this->assertQuery(
9312+
'SELECT * FROM information_schema.schemata s'
9313+
);
9314+
$this->assertEquals( 'information_schema', $result[0]->SCHEMA_NAME );
9315+
$this->assertEquals( 'wp', $result[1]->SCHEMA_NAME );
9316+
9317+
// Default database name.
9318+
$set_db_name( 'wp_test_new' );
9319+
$result = $this->assertQuery(
9320+
'SELECT s.*
9321+
FROM information_schema.schemata s
9322+
LEFT JOIN information_schema.tables t ON t.table_schema = s.schema_name
9323+
ORDER BY s.schema_name'
9324+
);
9325+
$this->assertEquals( 'information_schema', $result[0]->SCHEMA_NAME );
9326+
$this->assertEquals( 'wp_test_new', $result[1]->SCHEMA_NAME );
9327+
}
9328+
9329+
public function testDynamicDatabaseNameWithUseStatement(): void {
9330+
// Ensure "information_schema.tables" is empty.
9331+
$this->assertQuery( 'DROP TABLE _options, _dates' );
9332+
$result = $this->assertQuery( 'SELECT * FROM information_schema.tables' );
9333+
$this->assertCount( 0, $result );
9334+
9335+
// Create a "tables" table in the "wp" database.
9336+
$this->assertQuery( 'CREATE TABLE tables (id INT)' );
9337+
$this->assertQuery( 'INSERT INTO tables (id) VALUES (1), (2)' );
9338+
9339+
// Now, unqualified "tables" refers to the "wp.tables".
9340+
$result = $this->assertQuery( 'SELECT * FROM tables' );
9341+
$this->assertCount( 2, $result );
9342+
$this->assertEquals( array( (object) array( 'id' => '1' ), (object) array( 'id' => '2' ) ), $result );
9343+
9344+
// Qualified references should work as well.
9345+
$result = $this->assertQuery( 'SELECT * FROM wp.tables' );
9346+
$this->assertCount( 2, $result );
9347+
$this->assertEquals( array( (object) array( 'id' => '1' ), (object) array( 'id' => '2' ) ), $result );
9348+
9349+
$result = $this->assertQuery( 'SELECT * FROM information_schema.tables' );
9350+
$this->assertCount( 1, $result );
9351+
$this->assertEquals( 'tables', $result[0]->TABLE_NAME );
9352+
9353+
// Switch to the "information_schema" database.
9354+
$this->assertQuery( 'USE information_schema' );
9355+
9356+
// Now, unqualified "tables" refers to the "information_schema.tables".
9357+
$result = $this->assertQuery( 'SELECT * FROM tables' );
9358+
$this->assertCount( 1, $result );
9359+
$this->assertEquals( 'tables', $result[0]->TABLE_NAME );
9360+
9361+
// Qualified references should still work.
9362+
$result = $this->assertQuery( 'SELECT * FROM wp.tables' );
9363+
$this->assertCount( 2, $result );
9364+
$this->assertEquals( array( (object) array( 'id' => '1' ), (object) array( 'id' => '2' ) ), $result );
9365+
9366+
$result = $this->assertQuery( 'SELECT * FROM information_schema.tables' );
9367+
$this->assertCount( 1, $result );
9368+
$this->assertEquals( 'tables', $result[0]->TABLE_NAME );
9369+
}
92479370
}

0 commit comments

Comments
 (0)