Skip to content

Commit de42b1c

Browse files
committed
Implement CREATE INDEX statement
1 parent 6fc6ad0 commit de42b1c

File tree

4 files changed

+451
-122
lines changed

4 files changed

+451
-122
lines changed

tests/WP_SQLite_Driver_Tests.php

Lines changed: 139 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -5375,4 +5375,143 @@ public function testColumnNamesMustBeAscii(): void {
53755375
$this->expectExceptionMessage( 'The SQLite driver only supports ASCII characters in identifiers.' );
53765376
$this->assertQuery( 'CREATE TABLE t (`ńôñ-ášçíì` INT)' );
53775377
}
5378+
5379+
public function testCreateIndex(): void {
5380+
$this->assertQuery( 'CREATE TABLE t (id INT, value TEXT)' );
5381+
$this->assertQuery( 'CREATE INDEX idx_value ON t (value(16))' );
5382+
5383+
// Verify that the index was saved in the information schema.
5384+
$result = $this->assertQuery( 'SHOW INDEX FROM t' );
5385+
$this->assertCount( 1, $result );
5386+
$this->assertEquals(
5387+
(object) array(
5388+
'Table' => 't',
5389+
'Non_unique' => '1',
5390+
'Key_name' => 'idx_value',
5391+
'Seq_in_index' => '1',
5392+
'Column_name' => 'value',
5393+
'Collation' => 'A',
5394+
'Cardinality' => '0',
5395+
'Sub_part' => '16',
5396+
'Packed' => null,
5397+
'Null' => 'YES',
5398+
'Index_type' => 'BTREE',
5399+
'Comment' => '',
5400+
'Index_comment' => '',
5401+
'Visible' => 'YES',
5402+
'Expression' => null,
5403+
),
5404+
$result[0]
5405+
);
5406+
5407+
// Verify that the index exists in the SQLite database.
5408+
$result = $this->engine->execute_sqlite_query( "PRAGMA index_list('t')" )->fetchAll( PDO::FETCH_ASSOC );
5409+
$this->assertCount( 1, $result );
5410+
$this->assertEquals(
5411+
array(
5412+
'seq' => '0',
5413+
'name' => 't__idx_value',
5414+
'unique' => '0',
5415+
'origin' => 'c',
5416+
'partial' => '0',
5417+
),
5418+
$result[0]
5419+
);
5420+
}
5421+
5422+
public function testCreateUniqueIndex(): void {
5423+
$this->assertQuery( 'CREATE TABLE t (id INT, value TEXT)' );
5424+
$this->assertQuery( 'CREATE UNIQUE INDEX idx_value ON t (value(16))' );
5425+
5426+
// Verify that the index was saved in the information schema.
5427+
$result = $this->assertQuery( 'SHOW INDEX FROM t' );
5428+
$this->assertCount( 1, $result );
5429+
$this->assertEquals(
5430+
(object) array(
5431+
'Table' => 't',
5432+
'Non_unique' => '0',
5433+
'Key_name' => 'idx_value',
5434+
'Seq_in_index' => '1',
5435+
'Column_name' => 'value',
5436+
'Collation' => 'A',
5437+
'Cardinality' => '0',
5438+
'Sub_part' => '16',
5439+
'Packed' => null,
5440+
'Null' => 'YES',
5441+
'Index_type' => 'BTREE',
5442+
'Comment' => '',
5443+
'Index_comment' => '',
5444+
'Visible' => 'YES',
5445+
'Expression' => null,
5446+
),
5447+
$result[0]
5448+
);
5449+
5450+
// Verify that the UNIQUE constraint was saved in the information schema.
5451+
$result = $this->assertQuery( 'SELECT * FROM information_schema.table_constraints WHERE table_name = "t"' );
5452+
$this->assertCount( 1, $result );
5453+
$this->assertEquals(
5454+
(object) array(
5455+
'CONSTRAINT_CATALOG' => 'def',
5456+
'CONSTRAINT_SCHEMA' => 'wp',
5457+
'CONSTRAINT_NAME' => 'idx_value',
5458+
'TABLE_SCHEMA' => 'wp',
5459+
'TABLE_NAME' => 't',
5460+
'CONSTRAINT_TYPE' => 'UNIQUE',
5461+
'ENFORCED' => 'YES',
5462+
),
5463+
$result[0]
5464+
);
5465+
5466+
// Verify that the index exists in the SQLite database.
5467+
$result = $this->engine->execute_sqlite_query( "PRAGMA index_list('t')" )->fetchAll( PDO::FETCH_ASSOC );
5468+
$this->assertCount( 1, $result );
5469+
$this->assertEquals(
5470+
array(
5471+
'seq' => '0',
5472+
'name' => 't__idx_value',
5473+
'unique' => '1',
5474+
'origin' => 'c',
5475+
'partial' => '0',
5476+
),
5477+
$result[0]
5478+
);
5479+
}
5480+
5481+
public function testCreateFulltextIndex(): void {
5482+
$this->assertQuery( 'CREATE TABLE t (id INT, value TEXT)' );
5483+
$this->assertQuery( 'CREATE FULLTEXT INDEX idx_value ON t (value)' );
5484+
5485+
$result = $this->assertQuery( 'SHOW INDEX FROM t' );
5486+
$this->assertCount( 1, $result );
5487+
$this->assertEquals( 'FULLTEXT', $result[0]->Index_type );
5488+
}
5489+
5490+
public function testCreateSpatialIndex(): void {
5491+
$this->assertQuery( 'CREATE TABLE t (id INT, value POINT NOT NULL)' );
5492+
$this->assertQuery( 'CREATE SPATIAL INDEX idx_value ON t (value)' );
5493+
5494+
$result = $this->assertQuery( 'SHOW INDEX FROM t' );
5495+
$this->assertCount( 1, $result );
5496+
$this->assertEquals( 'SPATIAL', $result[0]->Index_type );
5497+
}
5498+
5499+
public function testCreateIndexWithComment(): void {
5500+
$this->assertQuery( 'CREATE TABLE t (id INT, value INT)' );
5501+
$this->assertQuery( 'CREATE INDEX idx_value ON t (value) COMMENT "Test comment"' );
5502+
5503+
$result = $this->assertQuery( 'SHOW INDEX FROM t' );
5504+
$this->assertCount( 1, $result );
5505+
$this->assertEquals( 'Test comment', $result[0]->Index_comment );
5506+
}
5507+
5508+
public function testCreateIndexWithDuplicateName(): void {
5509+
$this->assertQuery( 'CREATE TABLE t (id INT, val1 INT, val2 INT)' );
5510+
$this->assertQuery( 'CREATE INDEX idx_value ON t (val1)' );
5511+
5512+
$this->expectException( WP_SQLite_Driver_Exception::class );
5513+
$this->expectExceptionMessage( "1061 Duplicate key name 'idx_value'" );
5514+
5515+
$this->assertQuery( 'CREATE INDEX idx_value ON t (val2)' );
5516+
}
53785517
}

tests/WP_SQLite_Driver_Translation_Tests.php

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -395,9 +395,9 @@ public function testCreateTableWithPrimaryKeyAndAutoincrement(): void {
395395
"SELECT column_name, data_type, is_nullable, character_maximum_length FROM `_wp_sqlite_mysql_information_schema_columns` WHERE table_schema = 'wp' AND table_name = 't3' AND column_name IN ('id')",
396396
'INSERT INTO `_wp_sqlite_mysql_information_schema_statistics` (`table_schema`, `table_name`, `non_unique`, `index_schema`, `index_name`, `seq_in_index`, `column_name`, `collation`, `cardinality`, `sub_part`, `packed`, `nullable`, `index_type`, `comment`, `index_comment`, `is_visible`, `expression`)'
397397
. " VALUES ('wp', 't3', 0, 'wp', 'PRIMARY', 1, 'id', 'A', 0, null, null, '', 'BTREE', '', '', 'YES', null)",
398+
"UPDATE `_wp_sqlite_mysql_information_schema_columns` AS c SET (column_key, is_nullable) = ( SELECT CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'PRI' WHEN MAX(s.non_unique = 0 AND s.seq_in_index = 1) THEN 'UNI' WHEN MAX(s.seq_in_index = 1) THEN 'MUL' ELSE '' END, CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'NO' ELSE c.is_nullable END FROM `_wp_sqlite_mysql_information_schema_statistics` AS s WHERE s.table_schema = c.table_schema AND s.table_name = c.table_name AND s.column_name = c.column_name ) WHERE c.table_schema = 'wp' AND c.table_name = 't3'",
398399
'INSERT INTO `_wp_sqlite_mysql_information_schema_table_constraints` (`table_schema`, `table_name`, `constraint_schema`, `constraint_name`, `constraint_type`)'
399400
. " VALUES ('wp', 't3', 'wp', 'PRIMARY', 'PRIMARY KEY')",
400-
"UPDATE `_wp_sqlite_mysql_information_schema_columns` AS c SET (column_key, is_nullable) = ( SELECT CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'PRI' WHEN MAX(s.non_unique = 0 AND s.seq_in_index = 1) THEN 'UNI' WHEN MAX(s.seq_in_index = 1) THEN 'MUL' ELSE '' END, CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'NO' ELSE c.is_nullable END FROM `_wp_sqlite_mysql_information_schema_statistics` AS s WHERE s.table_schema = c.table_schema AND s.table_name = c.table_name AND s.column_name = c.column_name ) WHERE c.table_schema = 'wp' AND c.table_name = 't3'",
401401
"SELECT * FROM `_wp_sqlite_mysql_information_schema_tables` WHERE table_type = 'BASE TABLE' AND table_schema = 'wp' AND table_name = 't3'",
402402
"SELECT * FROM `_wp_sqlite_mysql_information_schema_columns` WHERE table_schema = 'wp' AND table_name = 't3' ORDER BY ordinal_position",
403403
"SELECT * FROM `_wp_sqlite_mysql_information_schema_statistics` WHERE table_schema = 'wp' AND table_name = 't3' ORDER BY INDEX_NAME = 'PRIMARY' DESC, NON_UNIQUE = '0' DESC, INDEX_TYPE = 'SPATIAL' DESC, INDEX_TYPE = 'BTREE' DESC, INDEX_TYPE = 'FULLTEXT' DESC, ROWID, SEQ_IN_INDEX",
@@ -460,16 +460,16 @@ public function testCreateTableWithStandaloneUniqueIndexes(): void {
460460
"SELECT DISTINCT index_name FROM `_wp_sqlite_mysql_information_schema_statistics` WHERE table_schema = 'wp' AND table_name = 't' AND (index_name = 'id' OR index_name LIKE 'id\_%' ESCAPE '\\')",
461461
'INSERT INTO `_wp_sqlite_mysql_information_schema_statistics` (`table_schema`, `table_name`, `non_unique`, `index_schema`, `index_name`, `seq_in_index`, `column_name`, `collation`, `cardinality`, `sub_part`, `packed`, `nullable`, `index_type`, `comment`, `index_comment`, `is_visible`, `expression`)'
462462
. " VALUES ('wp', 't', 0, 'wp', 'id', 1, 'id', 'A', 0, null, null, 'YES', 'BTREE', '', '', 'YES', null)",
463+
"UPDATE `_wp_sqlite_mysql_information_schema_columns` AS c SET (column_key, is_nullable) = ( SELECT CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'PRI' WHEN MAX(s.non_unique = 0 AND s.seq_in_index = 1) THEN 'UNI' WHEN MAX(s.seq_in_index = 1) THEN 'MUL' ELSE '' END, CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'NO' ELSE c.is_nullable END FROM `_wp_sqlite_mysql_information_schema_statistics` AS s WHERE s.table_schema = c.table_schema AND s.table_name = c.table_name AND s.column_name = c.column_name ) WHERE c.table_schema = 'wp' AND c.table_name = 't'",
463464
'INSERT INTO `_wp_sqlite_mysql_information_schema_table_constraints` (`table_schema`, `table_name`, `constraint_schema`, `constraint_name`, `constraint_type`)'
464465
. " VALUES ('wp', 't', 'wp', 'id', 'UNIQUE')",
465-
"UPDATE `_wp_sqlite_mysql_information_schema_columns` AS c SET (column_key, is_nullable) = ( SELECT CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'PRI' WHEN MAX(s.non_unique = 0 AND s.seq_in_index = 1) THEN 'UNI' WHEN MAX(s.seq_in_index = 1) THEN 'MUL' ELSE '' END, CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'NO' ELSE c.is_nullable END FROM `_wp_sqlite_mysql_information_schema_statistics` AS s WHERE s.table_schema = c.table_schema AND s.table_name = c.table_name AND s.column_name = c.column_name ) WHERE c.table_schema = 'wp' AND c.table_name = 't'",
466466
"SELECT column_name, data_type, is_nullable, character_maximum_length FROM `_wp_sqlite_mysql_information_schema_columns` WHERE table_schema = 'wp' AND table_name = 't' AND column_name IN ('name')",
467467
"SELECT DISTINCT index_name FROM `_wp_sqlite_mysql_information_schema_statistics` WHERE table_schema = 'wp' AND table_name = 't' AND (index_name = 'name' OR index_name LIKE 'name\_%' ESCAPE '\\')",
468468
'INSERT INTO `_wp_sqlite_mysql_information_schema_statistics` (`table_schema`, `table_name`, `non_unique`, `index_schema`, `index_name`, `seq_in_index`, `column_name`, `collation`, `cardinality`, `sub_part`, `packed`, `nullable`, `index_type`, `comment`, `index_comment`, `is_visible`, `expression`)'
469469
. " VALUES ('wp', 't', 0, 'wp', 'name', 1, 'name', 'A', 0, null, null, 'YES', 'BTREE', '', '', 'YES', null)",
470+
"UPDATE `_wp_sqlite_mysql_information_schema_columns` AS c SET (column_key, is_nullable) = ( SELECT CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'PRI' WHEN MAX(s.non_unique = 0 AND s.seq_in_index = 1) THEN 'UNI' WHEN MAX(s.seq_in_index = 1) THEN 'MUL' ELSE '' END, CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'NO' ELSE c.is_nullable END FROM `_wp_sqlite_mysql_information_schema_statistics` AS s WHERE s.table_schema = c.table_schema AND s.table_name = c.table_name AND s.column_name = c.column_name ) WHERE c.table_schema = 'wp' AND c.table_name = 't'",
470471
'INSERT INTO `_wp_sqlite_mysql_information_schema_table_constraints` (`table_schema`, `table_name`, `constraint_schema`, `constraint_name`, `constraint_type`)'
471472
. " VALUES ('wp', 't', 'wp', 'name', 'UNIQUE')",
472-
"UPDATE `_wp_sqlite_mysql_information_schema_columns` AS c SET (column_key, is_nullable) = ( SELECT CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'PRI' WHEN MAX(s.non_unique = 0 AND s.seq_in_index = 1) THEN 'UNI' WHEN MAX(s.seq_in_index = 1) THEN 'MUL' ELSE '' END, CASE WHEN MAX(s.index_name = 'PRIMARY') THEN 'NO' ELSE c.is_nullable END FROM `_wp_sqlite_mysql_information_schema_statistics` AS s WHERE s.table_schema = c.table_schema AND s.table_name = c.table_name AND s.column_name = c.column_name ) WHERE c.table_schema = 'wp' AND c.table_name = 't'",
473473
"SELECT * FROM `_wp_sqlite_mysql_information_schema_tables` WHERE table_type = 'BASE TABLE' AND table_schema = 'wp' AND table_name = 't'",
474474
"SELECT * FROM `_wp_sqlite_mysql_information_schema_columns` WHERE table_schema = 'wp' AND table_name = 't' ORDER BY ordinal_position",
475475
"SELECT * FROM `_wp_sqlite_mysql_information_schema_statistics` WHERE table_schema = 'wp' AND table_name = 't' ORDER BY INDEX_NAME = 'PRIMARY' DESC, NON_UNIQUE = '0' DESC, INDEX_TYPE = 'SPATIAL' DESC, INDEX_TYPE = 'BTREE' DESC, INDEX_TYPE = 'FULLTEXT' DESC, ROWID, SEQ_IN_INDEX",

wp-includes/sqlite-ast/class-wp-sqlite-driver.php

Lines changed: 70 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -878,7 +878,8 @@ private function execute_mysql_query( WP_Parser_Node $node ): void {
878878
$this->execute_create_table_statement( $node );
879879
break;
880880
case 'createIndex':
881-
// TODO: SQLite has a CREATE INDEX statement. We should support it.
881+
$this->execute_create_index_statement( $node );
882+
break;
882883
default:
883884
throw $this->new_not_supported_exception(
884885
sprintf(
@@ -1456,6 +1457,60 @@ private function execute_truncate_table_statement( WP_Parser_Node $node ): void
14561457
$this->set_result_from_affected_rows();
14571458
}
14581459

1460+
/**
1461+
* Translate and execute a MySQL CREATE INDEX statement in SQLite.
1462+
*
1463+
* @param WP_Parser_Node $node The "createStatement" AST node with "createIndex" child.
1464+
* @throws WP_SQLite_Driver_Exception When the query execution fails.
1465+
*/
1466+
private function execute_create_index_statement( WP_Parser_Node $node ): void {
1467+
$this->information_schema_builder->record_create_index( $node );
1468+
1469+
$create_index = $node->get_first_child_node( 'createIndex' );
1470+
$target = $create_index->get_first_child_node( 'createIndexTarget' );
1471+
1472+
$table_name = $this->unquote_sqlite_identifier(
1473+
$this->translate( $target->get_first_child_node( 'tableRef' ) )
1474+
);
1475+
$index_name = $this->unquote_sqlite_identifier(
1476+
$this->translate( $create_index->get_first_child_node( 'indexName' ) )
1477+
);
1478+
$is_unique = $create_index->has_child_token( WP_MySQL_Lexer::UNIQUE_SYMBOL );
1479+
1480+
// Get the key parts.
1481+
$key_list_variants = $target->get_first_child_node( 'keyListVariants' );
1482+
$key_list_nodes = $key_list_variants->get_first_child_node()->get_child_nodes();
1483+
foreach ( $key_list_nodes as $key_list_node ) {
1484+
if ( 'keyPartOrExpression' === $key_list_node->rule_name ) {
1485+
$key_part_node = $key_list_node->get_first_child();
1486+
} else {
1487+
$key_part_node = $key_list_node;
1488+
}
1489+
1490+
if ( 'keyPart' === $key_part_node->rule_name ) {
1491+
$key_part = $this->translate( $key_part_node->get_first_child_node( 'identifier' ) );
1492+
$direction = $key_part_node->get_first_child_node( 'direction' );
1493+
if ( null !== $direction ) {
1494+
$key_part .= ' ' . $this->translate( $direction );
1495+
}
1496+
} else {
1497+
$key_part = $this->translate( $key_part_node );
1498+
}
1499+
$key_parts[] = $key_part;
1500+
}
1501+
1502+
$sqlite_index_name = $this->get_sqlite_index_name( $table_name, $index_name );
1503+
$this->execute_sqlite_query(
1504+
sprintf(
1505+
'CREATE %sINDEX %s ON %s (%s)',
1506+
$is_unique ? 'UNIQUE ' : '',
1507+
$this->quote_sqlite_identifier( $sqlite_index_name ),
1508+
$this->translate( $target->get_first_child_node( 'tableRef' ) ),
1509+
implode( ', ', $key_parts )
1510+
)
1511+
);
1512+
}
1513+
14591514
/**
14601515
* Translate and execute a MySQL SHOW statement in SQLite.
14611516
*
@@ -3426,14 +3481,12 @@ function ( $column ) {
34263481

34273482
// Prefix the original index name with the table name.
34283483
// This is to avoid conflicting index names in SQLite.
3429-
$index_name = $this->quote_sqlite_identifier(
3430-
$table_name . '__' . $info['INDEX_NAME']
3431-
);
3484+
$sqlite_index_name = $this->get_sqlite_index_name( $table_name, $info['INDEX_NAME'] );
34323485

34333486
$query = sprintf(
34343487
'CREATE %sINDEX %s ON %s (',
34353488
$is_unique ? 'UNIQUE ' : '',
3436-
$index_name,
3489+
$this->quote_sqlite_identifier( $sqlite_index_name ),
34373490
$this->quote_sqlite_identifier( $table_name )
34383491
);
34393492
$query .= implode(
@@ -3654,6 +3707,18 @@ function ( $column ) {
36543707
return $sql;
36553708
}
36563709

3710+
/**
3711+
* Get an unique SQLite index name from a MySQL table name and index name.
3712+
*
3713+
* @param string $table_name The MySQL table name.
3714+
* @param string $index_name The MySQL index name.
3715+
* @return string The SQLite index name.
3716+
*/
3717+
private function get_sqlite_index_name( string $mysql_table_name, string $mysql_index_name ): string {
3718+
// Prefix the original index name with the table name.
3719+
// This is to avoid conflicting index names in SQLite.
3720+
return $mysql_table_name . '__' . $mysql_index_name;
3721+
}
36573722

36583723
/**
36593724
* Get an SQLite query to emulate MySQL "ON UPDATE CURRENT_TIMESTAMP".

0 commit comments

Comments
 (0)