Skip to content

Commit b870b2a

Browse files
authored
Merge pull request #3 from Automattic/update/mysql-information-schema-full-support
Select information_schema using a nested query to support WHERE, ORDER BY, and AS
2 parents b5a9fba + 70c0ea9 commit b870b2a

File tree

2 files changed

+114
-61
lines changed

2 files changed

+114
-61
lines changed

tests/WP_SQLite_Metadata_Tests.php

Lines changed: 63 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -73,6 +73,69 @@ public function testCountTables() {
7373
self::assertIsNumeric( $count );
7474
}
7575

76+
public function testInformationSchemaTables() {
77+
$result = $this->assertQuery( "SELECT * FROM information_schema.tables WHERE TABLE_NAME = 'wp_options'" );
78+
$this->assertEquals(
79+
array(
80+
'TABLE_CATALOG' => 'def',
81+
'TABLE_SCHEMA' => 'database',
82+
'TABLE_NAME' => 'wp_options',
83+
'TABLE_TYPE' => 'BASE TABLE',
84+
'ENGINE' => 'InnoDB',
85+
'ROW_FORMAT' => 'Dynamic',
86+
'TABLE_COLLATION' => 'utf8mb4_general_ci',
87+
'AUTO_INCREMENT' => null,
88+
'CREATE_TIME' => null,
89+
'UPDATE_TIME' => null,
90+
'CHECK_TIME' => null,
91+
'TABLE_ROWS' => '0',
92+
'AVG_ROW_LENGTH' => '0',
93+
'DATA_LENGTH' => '0',
94+
'MAX_DATA_LENGTH' => '0',
95+
'INDEX_LENGTH' => '0',
96+
'DATA_FREE' => '0',
97+
'CHECKSUM' => null,
98+
'CREATE_OPTIONS' => '',
99+
'VERSION' => '10',
100+
'TABLE_COMMENT' => '',
101+
),
102+
(array) $result[0]
103+
);
104+
105+
$result = $this->assertQuery(
106+
"SELECT
107+
table_name as 'name',
108+
engine AS 'engine',
109+
FLOOR( data_length / 1024 / 1024 ) 'data'
110+
FROM INFORMATION_SCHEMA.TABLES
111+
WHERE TABLE_NAME = 'wp_posts'
112+
ORDER BY name ASC;"
113+
);
114+
115+
$this->assertEquals(
116+
array(
117+
'name' => 'wp_posts',
118+
'engine' => 'InnoDB',
119+
'data' => '0',
120+
),
121+
(array) $result[0]
122+
);
123+
}
124+
125+
public function testInformationSchemaQueryHidesSqliteSystemTables() {
126+
/**
127+
* By default, system tables are not returned.
128+
*/
129+
$result = $this->assertQuery( "SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sqlite_sequence'" );
130+
$this->assertEquals( 0, count( $result ) );
131+
132+
/**
133+
* If we use a custom name for the table_name column, system tables are returned.
134+
*/
135+
$result = $this->assertQuery( "SELECT TABLE_NAME as custom_name FROM INFORMATION_SCHEMA.TABLES WHERE custom_name = 'sqlite_sequence'" );
136+
$this->assertEquals( 1, count( $result ) );
137+
}
138+
76139
private function assertQuery( $sql, $error_substring = null ) {
77140
$retval = $this->engine->query( $sql );
78141
if ( null === $error_substring ) {

wp-includes/sqlite/class-wp-sqlite-translator.php

Lines changed: 51 additions & 61 deletions
Original file line numberDiff line numberDiff line change
@@ -1519,8 +1519,41 @@ private function execute_select() {
15191519

15201520
if ( $table_name && str_starts_with( strtolower( $table_name ), 'information_schema' ) ) {
15211521
$this->is_information_schema_query = true;
1522-
$updated_query = $this->get_information_schema_query( $updated_query );
1523-
$params = array();
1522+
$updated_query = preg_replace(
1523+
'/' . $table_name . '\.tables/i',
1524+
/**
1525+
* TODO: Return real values for hardcoded column values.
1526+
*/
1527+
"(SELECT
1528+
'def' as TABLE_CATALOG,
1529+
'database' as TABLE_SCHEMA,
1530+
name as TABLE_NAME,
1531+
CASE type
1532+
WHEN 'table' THEN 'BASE TABLE'
1533+
WHEN 'view' THEN 'VIEW'
1534+
ELSE type
1535+
END as TABLE_TYPE,
1536+
'InnoDB' as ENGINE,
1537+
10 as VERSION,
1538+
'Dynamic' as ROW_FORMAT,
1539+
0 as TABLE_ROWS,
1540+
0 as AVG_ROW_LENGTH,
1541+
0 as DATA_LENGTH,
1542+
0 as MAX_DATA_LENGTH,
1543+
0 as INDEX_LENGTH,
1544+
0 as DATA_FREE,
1545+
NULL as AUTO_INCREMENT,
1546+
NULL as CREATE_TIME,
1547+
NULL as UPDATE_TIME,
1548+
NULL as CHECK_TIME,
1549+
'utf8mb4_general_ci' as TABLE_COLLATION,
1550+
NULL as CHECKSUM,
1551+
'' as CREATE_OPTIONS,
1552+
'' as TABLE_COMMENT
1553+
FROM sqlite_master
1554+
WHERE type IN ('table', 'view'))",
1555+
$updated_query
1556+
);
15241557
} elseif (
15251558
// Examples: @@SESSION.sql_mode, @@GLOBAL.max_allowed_packet, @@character_set_client
15261559
preg_match( '/@@((SESSION|GLOBAL)\s*\.\s*)?\w+\b/i', $updated_query ) === 1 ||
@@ -2772,51 +2805,6 @@ private function translate_like_escape( $token ) {
27722805
return false;
27732806
}
27742807

2775-
/**
2776-
* Rewrite a query from the MySQL information_schema.
2777-
*
2778-
* @param string $updated_query The query to rewrite.
2779-
*
2780-
* @return string The query for use by SQLite
2781-
*/
2782-
private function get_information_schema_query( $updated_query ) {
2783-
// @TODO: Actually rewrite the columns.
2784-
$normalized_query = preg_replace( '/\s+/', ' ', strtolower( $updated_query ) );
2785-
if ( str_contains( $normalized_query, 'bytes' ) ) {
2786-
// Count rows per table.
2787-
$tables =
2788-
$this->execute_sqlite_query( "SELECT name as `table_name` FROM sqlite_master WHERE type='table' ORDER BY name" )->fetchAll();
2789-
$tables = $this->strip_sqlite_system_tables( $tables );
2790-
2791-
$rows = '(CASE ';
2792-
foreach ( $tables as $table ) {
2793-
$table_name = $table['table_name'];
2794-
$count = $this->execute_sqlite_query( "SELECT COUNT(1) as `count` FROM $table_name" )->fetch();
2795-
$rows .= " WHEN name = '$table_name' THEN {$count['count']} ";
2796-
}
2797-
$rows .= 'ELSE 0 END) ';
2798-
$updated_query =
2799-
"SELECT name as `table_name`, $rows as `rows`, 0 as `bytes` FROM sqlite_master WHERE type='table' ORDER BY name";
2800-
} elseif ( str_contains( $normalized_query, 'count(*)' ) && ! str_contains( $normalized_query, 'table_name =' ) ) {
2801-
// @TODO This is a guess that the caller wants a count of tables.
2802-
$list = array();
2803-
foreach ( $this->sqlite_system_tables as $system_table => $name ) {
2804-
$list [] = "'" . $system_table . "'";
2805-
}
2806-
$list = implode( ', ', $list );
2807-
$sql = "SELECT COUNT(*) FROM sqlite_master WHERE type='table' AND name NOT IN ($list)";
2808-
$table_count = $this->execute_sqlite_query( $sql )->fetch();
2809-
$updated_query = 'SELECT ' . $table_count[0] . ' AS num';
2810-
2811-
$this->is_information_schema_query = false;
2812-
} else {
2813-
$updated_query =
2814-
"SELECT name as `table_name`, 'myisam' as `engine`, 0 as `data_length`, 0 as `index_length`, 0 as `data_free` FROM sqlite_master WHERE type='table' ORDER BY name";
2815-
}
2816-
2817-
return $updated_query;
2818-
}
2819-
28202808
/**
28212809
* Remove system table rows from resultsets of information_schema tables.
28222810
*
@@ -2829,20 +2817,22 @@ private function strip_sqlite_system_tables( $tables ) {
28292817
array_filter(
28302818
$tables,
28312819
function ( $table ) {
2832-
$table_name = false;
2833-
if ( is_array( $table ) ) {
2834-
if ( isset( $table['Name'] ) ) {
2835-
$table_name = $table['Name'];
2836-
} elseif ( isset( $table['table_name'] ) ) {
2837-
$table_name = $table['table_name'];
2838-
}
2839-
} elseif ( is_object( $table ) ) {
2840-
$table_name = property_exists( $table, 'Name' )
2841-
? $table->Name // phpcs:ignore WordPress.NamingConventions.ValidVariableName.UsedPropertyNotSnakeCase
2842-
: $table->table_name;
2820+
/**
2821+
* By default, we assume the table name is in the result set,
2822+
* so we allow empty table names to pass through.
2823+
* Otherwise, if an information_schema table uses a custom name
2824+
* for the name/table_name column, the table would be removed.
2825+
*/
2826+
$table_name = '';
2827+
$table = (array) $table;
2828+
if ( isset( $table['Name'] ) ) {
2829+
$table_name = $table['Name'];
2830+
} elseif ( isset( $table['table_name'] ) ) {
2831+
$table_name = $table['table_name'];
2832+
} elseif ( isset( $table['TABLE_NAME'] ) ) {
2833+
$table_name = $table['TABLE_NAME'];
28432834
}
2844-
2845-
return $table_name && ! array_key_exists( $table_name, $this->sqlite_system_tables );
2835+
return '' === $table_name || ! array_key_exists( $table_name, $this->sqlite_system_tables );
28462836
},
28472837
ARRAY_FILTER_USE_BOTH
28482838
)
@@ -3281,7 +3271,7 @@ private function execute_alter() {
32813271
new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ),
32823272
new WP_SQLite_Token( 'ON', WP_SQLite_Token::TYPE_KEYWORD, WP_SQLite_Token::FLAG_KEYWORD_RESERVED ),
32833273
new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ),
3284-
new WP_SQLite_Token( '"' . $this->table_name . '"', WP_SQLite_Token::TYPE_STRING, WP_SQLite_Token::FLAG_STRING_DOUBLE_QUOTES ),
3274+
new WP_SQLite_Token( "\"$this->table_name\"", WP_SQLite_Token::TYPE_STRING, WP_SQLite_Token::FLAG_STRING_DOUBLE_QUOTES ),
32853275
new WP_SQLite_Token( ' ', WP_SQLite_Token::TYPE_WHITESPACE ),
32863276
new WP_SQLite_Token( '(', WP_SQLite_Token::TYPE_OPERATOR ),
32873277
)

0 commit comments

Comments
 (0)