Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add support for ON UPDATE CURRENT_TIMESTAMP columns #150

Merged
merged 3 commits into from
Aug 9, 2024
Merged
Show file tree
Hide file tree
Changes from 2 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
149 changes: 149 additions & 0 deletions tests/WP_SQLite_Translator_Tests.php
Original file line number Diff line number Diff line change
Expand Up @@ -1027,6 +1027,155 @@ public function testAlterTableAddNotNullVarcharColumn() {
);
}

public function testColumnWithOnUpdate() {
// CREATE TABLE with ON UPDATE
$this->assertQuery(
'CREATE TABLE _tmp_table (
id int(11) NOT NULL,
created_at timestamp NULL ON UPDATE CURRENT_TIMESTAMP
);'
);
$results = $this->assertQuery( 'DESCRIBE _tmp_table;' );
$this->assertEquals(
array(
(object) array(
'Field' => 'id',
'Type' => 'int(11)',
'Null' => 'NO',
'Key' => '',
'Default' => '0',
'Extra' => '',
),
(object) array(
'Field' => 'created_at',
'Type' => 'timestamp',
'Null' => 'YES',
'Key' => '',
'Default' => null,
'Extra' => '',
),
),
$results
);

// ADD COLUMN with ON UPDATE
$this->assertQuery(
'ALTER TABLE _tmp_table ADD COLUMN updated_at timestamp NULL ON UPDATE CURRENT_TIMESTAMP'
);
$results = $this->assertQuery( 'DESCRIBE _tmp_table;' );
$this->assertEquals(
array(
(object) array(
'Field' => 'id',
'Type' => 'int(11)',
'Null' => 'NO',
'Key' => '',
'Default' => '0',
'Extra' => '',
),
(object) array(
'Field' => 'created_at',
'Type' => 'timestamp',
'Null' => 'YES',
'Key' => '',
'Default' => null,
'Extra' => '',
),
(object) array(
'Field' => 'updated_at',
'Type' => 'timestamp',
'Null' => 'YES',
'Key' => '',
'Default' => null,
'Extra' => '',
),
),
$results
);

// assert ON UPDATE triggers
$results = $this->assertQuery( "SELECT * FROM sqlite_master WHERE type = 'trigger'" );
$this->assertEquals(
array(
(object) array(
'type' => 'trigger',
'name' => '___tmp_table_created_at_on_update__',
'tbl_name' => '_tmp_table',
'rootpage' => '0',
'sql' => "CREATE TRIGGER \"___tmp_table_created_at_on_update__\"\n\t\t\tAFTER UPDATE ON \"_tmp_table\"\n\t\t\tFOR EACH ROW\n\t\t\tBEGIN\n\t\t\t UPDATE \"_tmp_table\" SET \"created_at\" = CURRENT_TIMESTAMP WHERE id = NEW.id;\n\t\t\tEND",
),
(object) array(
'type' => 'trigger',
'name' => '___tmp_table_updated_at_on_update__',
'tbl_name' => '_tmp_table',
'rootpage' => '0',
'sql' => "CREATE TRIGGER \"___tmp_table_updated_at_on_update__\"\n\t\t\tAFTER UPDATE ON \"_tmp_table\"\n\t\t\tFOR EACH ROW\n\t\t\tBEGIN\n\t\t\t UPDATE \"_tmp_table\" SET \"updated_at\" = CURRENT_TIMESTAMP WHERE id = NEW.id;\n\t\t\tEND",
),
),
$results
);

// on INSERT, no timestamps are expected
$this->assertQuery( 'INSERT INTO _tmp_table (id) VALUES (1)' );
$result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE id = 1' );
$this->assertNull( $result[0]->created_at );
$this->assertNull( $result[0]->updated_at );

// on UPDATE, we expect timestamps in form YYYY-MM-DD HH:MM:SS
$this->assertQuery( 'UPDATE _tmp_table SET id = 2 WHERE id = 1' );
$result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE id = 2' );
$this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $result[0]->created_at );
$this->assertRegExp( '/\d\d\d\d-\d\d-\d\d \d\d:\d\d:\d\d/', $result[0]->updated_at );

// drop ON UPDATE
$this->assertQuery(
'ALTER TABLE _tmp_table
CHANGE created_at created_at timestamp NULL,
CHANGE COLUMN updated_at updated_at timestamp NULL'
);
$results = $this->assertQuery( 'DESCRIBE _tmp_table;' );
$this->assertEquals(
array(
(object) array(
'Field' => 'id',
'Type' => 'int(11)',
'Null' => 'NO',
'Key' => '',
'Default' => '0',
'Extra' => '',
),
(object) array(
'Field' => 'created_at',
'Type' => 'timestamp',
'Null' => 'YES',
'Key' => '',
'Default' => null,
'Extra' => '',
),
(object) array(
'Field' => 'updated_at',
'Type' => 'timestamp',
'Null' => 'YES',
'Key' => '',
'Default' => null,
'Extra' => '',
),
),
$results
);

// assert ON UPDATE triggers are removed
$results = $this->assertQuery( "SELECT * FROM sqlite_master WHERE type = 'trigger'" );
$this->assertEquals( array(), $results );

// now, no timestamps are expected
$this->assertQuery( 'INSERT INTO _tmp_table (id) VALUES (10)' );
$this->assertQuery( 'UPDATE _tmp_table SET id = 11 WHERE id = 10' );
$result = $this->assertQuery( 'SELECT * FROM _tmp_table WHERE id = 11' );
$this->assertNull( $result[0]->created_at );
$this->assertNull( $result[0]->updated_at );
}

public function testAlterTableWithColumnFirstAndAfter() {
$this->assertQuery(
"CREATE TABLE _tmp_table (
Expand Down
100 changes: 94 additions & 6 deletions wp-includes/sqlite/class-wp-sqlite-translator.php
Original file line number Diff line number Diff line change
Expand Up @@ -864,6 +864,7 @@ private function execute_create_table() {
$table = $this->parse_create_table();

$definitions = array();
$on_updates = array();
bgrgicak marked this conversation as resolved.
Show resolved Hide resolved
foreach ( $table->fields as $field ) {
/*
* Do not include the inline PRIMARY KEY definition
Expand All @@ -877,6 +878,10 @@ private function execute_create_table() {
}

$definitions[] = $this->make_sqlite_field_definition( $field );
if ( $field->on_update ) {
$on_updates[ $field->name ] = $field->on_update;
}

$this->update_data_type_cache(
$table->name,
$field->name,
Expand Down Expand Up @@ -917,6 +922,12 @@ private function execute_create_table() {
$constraint->value
);
}

foreach ( $table->fields as $field ) {
if ( $field->on_update ) {
$this->add_column_on_update_current_timestamp( $table->name, $field->name );
}
}
bgrgicak marked this conversation as resolved.
Show resolved Hide resolved
}

/**
Expand Down Expand Up @@ -1054,6 +1065,7 @@ private function parse_mysql_create_table_field() {
$result->default = false;
$result->auto_increment = false;
$result->primary_key = false;
$result->on_update = false;

$field_name_token = $this->rewriter->skip(); // Field name.
$this->rewriter->add( new WP_SQLite_Token( "\n", WP_SQLite_Token::TYPE_WHITESPACE ) );
Expand Down Expand Up @@ -1108,6 +1120,22 @@ private function parse_mysql_create_table_field() {
continue;
}

if (
$token->matches(
WP_SQLite_Token::TYPE_KEYWORD,
WP_SQLite_Token::FLAG_KEYWORD_RESERVED,
array( 'ON UPDATE' )
) && $this->rewriter->peek()->matches(
WP_SQLite_Token::TYPE_KEYWORD,
WP_SQLite_Token::FLAG_KEYWORD_RESERVED,
array( 'CURRENT_TIMESTAMP' )
)
) {
$this->rewriter->skip();
$result->on_update = true;
continue;
}

if ( $this->is_create_table_field_terminator( $token, $definition_depth ) ) {
$this->rewriter->add( $token );
break;
Expand Down Expand Up @@ -2927,6 +2955,7 @@ private function execute_alter() {
$op_subject = strtoupper( $op_raw_subject );
$mysql_index_type = $this->normalize_mysql_index_type( $op_subject );
$is_index_op = (bool) $mysql_index_type;
$on_update = false;

if ( 'ADD' === $op_type && ! $is_index_op ) {
if ( 'COLUMN' === $op_subject ) {
Expand All @@ -2947,18 +2976,44 @@ private function execute_alter() {
)
);

// Drop "FIRST" and "AFTER <another-column>", as these are not supported in SQLite.
$column_position = $this->rewriter->peek(
$comma = $this->rewriter->peek(
array(
'type' => WP_SQLite_Token::TYPE_OPERATOR,
'value' => ',',
)
);

// Handle "ON UPDATE CURRENT_TIMESTAMP".
$on_update_token = $this->rewriter->peek(
array(
'type' => WP_SQLite_Token::TYPE_KEYWORD,
'value' => array( 'FIRST', 'AFTER' ),
'value' => array( 'ON UPDATE' ),
)
);

$comma = $this->rewriter->peek(
if ( $on_update_token && ( ! $comma || $on_update_token->position < $comma->position ) ) {
$this->rewriter->consume(
array(
'type' => WP_SQLite_Token::TYPE_KEYWORD,
'value' => array( 'ON UPDATE' ),
)
);
if ( $this->rewriter->peek()->matches(
WP_SQLite_Token::TYPE_KEYWORD,
WP_SQLite_Token::FLAG_KEYWORD_RESERVED,
array( 'CURRENT_TIMESTAMP' )
) ) {
$this->rewriter->drop_last();
$this->rewriter->skip();
$on_update = $column_name;
}
}

// Drop "FIRST" and "AFTER <another-column>", as these are not supported in SQLite.
$column_position = $this->rewriter->peek(
array(
'type' => WP_SQLite_Token::TYPE_OPERATOR,
'value' => ',',
'type' => WP_SQLite_Token::TYPE_KEYWORD,
'value' => array( 'FIRST', 'AFTER' ),
)
);

Expand Down Expand Up @@ -3205,9 +3260,17 @@ private function execute_alter() {
)
);
$this->rewriter->drop_last();

$on_update_trigger_name = $this->get_column_on_update_current_timestamp_trigger_name( $this->table_name, $op_subject );
$this->execute_sqlite_query( "DROP TRIGGER IF EXISTS \"$on_update_trigger_name\"" );

$this->execute_sqlite_query(
$this->rewriter->get_updated_query()
);

if ( $on_update ) {
$this->add_column_on_update_current_timestamp( $this->table_name, $on_update );
}
} while ( $comma );

$this->results = 1;
Expand Down Expand Up @@ -4258,4 +4321,29 @@ private function generate_index_name( $table, $original_index_name ) {
// to allow easier splitting on __ later.
return preg_replace( '/_{2,}/', '_', $table ) . '__' . $original_index_name;
}

/**
* @param string $table
* @param string $column
*/
private function add_column_on_update_current_timestamp( $table, $column ) {
$trigger_name = $this->get_column_on_update_current_timestamp_trigger_name( $table, $column );
$this->execute_sqlite_query(
"CREATE TRIGGER \"$trigger_name\"
AFTER UPDATE ON \"$table\"
FOR EACH ROW
BEGIN
UPDATE \"$table\" SET \"$column\" = CURRENT_TIMESTAMP WHERE id = NEW.id;
END"
);
}

/**
* @param string $table
* @param string $column
* @return string
*/
private function get_column_on_update_current_timestamp_trigger_name( $table, $column ) {
return "__{$table}_{$column}_on_update__";
}
}
Loading