├── README.md └── mysql-revisioning.php /README.md: -------------------------------------------------------------------------------- 1 | # Versioning MySQL data 2 | As a developer you’re probably using a versioning control system, like subversion or git, to safeguard your data. Advantages of using a VCS are that you can walk to the individual changes for a document, see who made each change and revert back to specific revision if needed. These are features which would also be nice for data stored in a database. With the use of triggers we can implement versioning for data stored in a MySQL db. 3 | 4 | ### BEWARE! This is a prove of concept. Do not use this in a production environment. 5 | 6 | ## How it works 7 | 8 | ### The revisioning table 9 | We will not store the different versions of the records in the original table. We want this solution to be in the database layer instead of putting all the logic in the application layer. Instead we’ll create a new table, which stores all the different versions and lives next to the original table, which only contains the current version of each record. This revisioning table is copy of the original table, with a couple of additional fields. 10 | 11 | ``` 12 | CREATE TABLE `_revision_mytable` LIKE `mytable`; 13 | 14 | ALTER TABLE `_revision_mytable` 15 | CHANGE `id` `id` int(10) unsigned, 16 | DROP PRIMARY KEY, 17 | ADD `_revision` bigint unsigned AUTO_INCREMENT, 18 | ADD `_revision_previous` bigint unsigned NULL, 19 | ADD `_revision_action` enum('INSERT','UPDATE') default NULL, 20 | ADD `_revision_user_id` int(10) unsigned NULL, 21 | ADD `_revision_timestamp` datetime NULL default NULL, 22 | ADD `_revision_comment` text NULL, 23 | ADD PRIMARY KEY (`_revision`), 24 | ADD INDEX (`_revision_previous`), 25 | ADD INDEX `org_primary` (`id`); 26 | ``` 27 | 28 | The most important field is `_revision`. This field contains a unique identifier for a version of a record from the table. Since this is the unique identifier in the revisioning table, the original id field becomes a normal (indexed) field. 29 | 30 | We’ll also store some additional information in the revisioning table. The `_revision_previous` field hold the revision nr of the version that was updated to create this revision. Field `_revision_action` holds the action that was executed to create this revision. This field has an extra function that will discussed later. The user id and timestamp are useful for blaming changes on someone. We can add some comment per revision. 31 | 32 | The database user is probably always the same. Storing this in the user id field is not useful. Instead, we can set variable @auth_id after logging in and on connecting to the database to the session user. 33 | 34 | ## Altering the original table 35 | The original table needs 2 additional fields: `_revision` and `_revision_comment`. The `_revision` field holds the current active version. The field can also be used to revert to a different revision. The value of `_revision_comment` set on an update or insert will end up in the revisioning table. The field in the original table will always be empty. 36 | 37 | ``` 38 | ALTER TABLE `mytable` 39 | ADD `_revision` bigint unsigned NULL, 40 | ADD `_revision_comment` text NULL, 41 | ADD UNIQUE INDEX (`_revision`); 42 | ``` 43 | 44 | ### The history table 45 | 46 | Saving each version is not enough. Since we can revert back to older revisions and of course delete the record altogether, we want to store which version of the record was enabled at what time. The history table only needs to hold the revision number and a timestamp. We’ll add the primary key fields, so it’s easier to query. A user id field is included to blame. 47 | 48 | ``` 49 | CREATE TABLE `_revhistory_mytable` ( 50 | `id` int(10) unsigned, 51 | `_revision` bigint unsigned NULL, 52 | `_revhistory_user_id` int(10) unsigned NULL, 53 | `_revhistory_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP, 54 | INDEX (`id`), 55 | INDEX (_revision), 56 | INDEX (_revhistory_user_id), 57 | INDEX (_revhistory_timestamp) 58 | ) ENGINE=InnoDB; 59 | ``` 60 | 61 | ## How to use 62 | Inserting, updating and deleting data should work as normal, including the INSERT … ON DUPLICATE KEY UPDATE syntax. When updating the _revision field shouldn’t be changed. 63 | 64 | To switch to a different version, we would do something like 65 | 66 | ``` 67 | UPDATE mytable SET _revision=$rev WHERE id=$id; 68 | ``` 69 | However if the record has been deleted, there will be no record in the original table, therefore the update won’t do anything. Instead we could insert a record, specifying the revision. 70 | 71 | ``` 72 | INSERT INTO mytable SET _revision=$rev; 73 | ``` 74 | We can combine these two into a statement that works either way. 75 | 76 | ``` 77 | INSERT INTO mytable SET id=$id, _revision=$rev ON DUPLICATE KEY UPDATE _revision=VALUES(_revision); 78 | ``` 79 | The above query shows that there an additional constraint. The only thing that indicates that different versions is of the same record, is the primary key. Therefore value of the primary key can’t change on update. This might mean that some tables need to start using surrogate keys if they are not. 80 | 81 | ### On Insert 82 | Let’s dive into the triggers. We’ll start with before insert. This trigger should get the values of a revision when the _revision field is set, or otherwise add a new row to the revision table. 83 | 84 | ``` 85 | CREATE TRIGGER `mytable-beforeinsert` BEFORE INSERT ON `mytable` 86 | FOR EACH ROW BEGIN 87 | DECLARE `var-id` int(10) unsigned; 88 | DECLARE `var-title` varchar(45); 89 | DECLARE `var-body` text; 90 | DECLARE `var-_revision` BIGINT UNSIGNED; 91 | DECLARE revisionCursor CURSOR FOR SELECT `id`, `title`, `body` FROM `_revision_mytable` WHERE `_revision`=`var-_revision` LIMIT 1; 92 | 93 | IF NEW.`_revision` IS NULL THEN 94 | INSERT INTO `_revision_mytable` (`_revision_comment`, `_revision_user_id`, `_revision_timestamp`) VALUES (NEW.`_revision_comment`, @auth_uid, NOW()); 95 | SET NEW.`_revision` = LAST_INSERT_ID(); 96 | ELSE 97 | SET `var-_revision`=NEW.`_revision`; 98 | OPEN revisionCursor; 99 | FETCH revisionCursor INTO `var-id`, `var-title`, `var-body`; 100 | CLOSE revisionCursor; 101 | 102 | SET NEW.`id` = `var-id`, NEW.`title` = `var-title`, NEW.`body` = `var-body`; 103 | END IF; 104 | 105 | SET NEW.`_revision_comment` = NULL; 106 | END 107 | 108 | CREATE TRIGGER `mytable-afterinsert` AFTER INSERT ON `mytable` 109 | FOR EACH ROW BEGIN 110 | UPDATE `_revision_mytable` SET `id` = NEW.`id`, `title` = NEW.`title`, `body` = NEW.`body`, `_revision_action`='INSERT' WHERE `_revision`=NEW.`_revision` AND `_revision_action` IS NULL; 111 | INSERT INTO `_revhistory_mytable` VALUES (NEW.`id`, NEW.`_revision`, @auth_uid, NOW()); 112 | END 113 | ``` 114 | 115 | If the `_revision` field is NULL, we insert a new row into the revision table. This action is primarily to get a revision number. We set the comment, user id and timestamp. We won’t set the values, action and previous id yet. The insert might fail or be converted into an update action by insert on duplicate key update. If the insert action fails, we’ll have an unused row in the revisioning table. This is a problem, since the primary key has not been set, so it won’t show up anywhere. We can clean up these phantom records once in a while to keep the table clean. 116 | 117 | When `_revision` is set, we use a cursor to get the values from the revision table. We can’t fetch to values directly into NEW, therefore we first fetch them into variables and than copy that into NEW. 118 | 119 | After insert, we’ll update the revision, setting the values and the action. However, the insert might have been an undelete action. In that case `_revision_action` is already set and we don’t need to update the revision. We also add an entry in the history table. 120 | 121 | ### On Update 122 | The before and after update trigger do more or less the same as the before and after insert trigger. 123 | 124 | ``` 125 | CREATE TRIGGER `mytable-beforeupdate` BEFORE UPDATE ON `mytable` 126 | FOR EACH ROW BEGIN 127 | DECLARE `var-id` int(10) unsigned; 128 | DECLARE `var-title` varchar(45); 129 | DECLARE `var-body` text; 130 | DECLARE `var-_revision` BIGINT UNSIGNED; 131 | DECLARE `var-_revision_action` enum('INSERT','UPDATE','DELETE'); 132 | DECLARE revisionCursor CURSOR FOR SELECT `id`, `title`, `body`, `_revision_action` FROM `_revision_mytable` WHERE `_revision`=`var-_revision` LIMIT 1; 133 | 134 | IF NEW.`_revision` = OLD.`_revision` THEN 135 | SET NEW.`_revision` = NULL; 136 | 137 | ELSEIF NEW.`_revision` IS NOT NULL THEN 138 | SET `var-_revision` = NEW.`_revision`; 139 | 140 | OPEN revisionCursor; 141 | FETCH revisionCursor INTO `var-id`, `var-title`, `var-body`, `var-_revision_action`; 142 | CLOSE revisionCursor; 143 | 144 | IF `var-_revision_action` IS NOT NULL THEN 145 | SET NEW.`id` = `var-id`, NEW.`title` = `var-title`, NEW.`body` = `var-body`; 146 | END IF; 147 | END IF; 148 | 149 | IF (NEW.`id` != OLD.`id` OR NEW.`id` IS NULL != OLD.`id` IS NULL) THEN 150 | -- Workaround for missing SIGNAL command 151 | DO `Can't change the value of the primary key of table 'mytable' because of revisioning`; 152 | END IF; 153 | 154 | IF NEW.`_revision` IS NULL THEN 155 | INSERT INTO `_revision_mytable` (`_revision_previous`, `_revision_comment`, `_revision_user_id`, `_revision_timestamp`) VALUES (OLD.`_revision`, NEW.`_revision_comment`, @auth_uid, NOW()); 156 | SET NEW.`_revision` = LAST_INSERT_ID(); 157 | END IF; 158 | 159 | SET NEW.`_revision_comment` = NULL; 160 | END 161 | 162 | CREATE TRIGGER `mytable-afterupdate` AFTER UPDATE ON `mytable` 163 | FOR EACH ROW BEGIN 164 | UPDATE `_revision_mytable` SET `id` = NEW.`id`, `title` = NEW.`title`, `body` = NEW.`body`, `_revision_action`='UPDATE' WHERE `_revision`=NEW.`_revision` AND `_revision_action` IS NULL; 165 | INSERT INTO `_revhistory_mytable` VALUES (NEW.`id`, NEW.`_revision`, @auth_uid, NOW()); 166 | END 167 | ``` 168 | 169 | If `_revision` is not set, it has the old value. In that case a new revision should be created. Setting `_revision` to NULL will have the same behaviour of not setting `_revision`. Next to the comment, user id and timestamp, we add also set the previous revision. 170 | 171 | As said before, it’s very important that the value of primary key doesn’t change. We need to check this and trigger an error, if it would be changed. 172 | 173 | ### On Delete 174 | Deleting won’t create a new revisiong. However we do want to log that the record has been deleted. Therefore we add an entry to the history table with `_revision` set to NULL. 175 | 176 | ``` 177 | CREATE TRIGGER `mytable-afterdelete` AFTER DELETE ON `mytable` 178 | FOR EACH ROW BEGIN 179 | INSERT INTO `_revhistory_mytable` VALUES (OLD.`id`, NULL, @auth_uid, NOW()); 180 | END 181 | ``` 182 | 183 | ## Multi-table records 184 | often the data of a record is spread across multiple tables, like an invoice with multiple invoice lines. Having each invoice line versioned individually isn’t really useful. Instead we want a new revision of the whole invoice on each change. 185 | 186 | Ideally a change of one or more parts of the invoice would be changed, a new revision would be created. There are several issues in actually creating this those. Detecting the change of multiple parts of the invoice at once, generating a single revision, would mean we need to know if the actions are done within the same transaction. Unfortunately there is a connection\_id(), but no transaction\_id() function in MySQL. Also, the query would fail when a query inserts or updates a record in the child table, using the parent table. We need to come up with something else. 187 | 188 | One solution is to version the rows in the parent as well in the child tables. For each version of the parent row, we register which versions of the child rows ware set. This however has really complicated the trigger code and tends to need a lot of checking an querying slowing the write process down. Since nobody ever looks at the versions of the child rows, the application forces a new version of the parent row. The benefits of versioning both are therefor minimal. 189 | 190 | ### Only versioning the parent 191 | For this new (simplified) implementation, we will only have one revision number across all tables of the record. Changing data from the parent table, will trigger a new version. This will not only copy the parent row to the revisioning table, but also the rows of the children. 192 | 193 | Writing to the child will not trigger a new version, instead it will update the data in the revisioning table. This means that when changing the record, you need to write to the parent table, before writing to the child tables. To force a new version without changing values use 194 | 195 | ``` 196 | UPDATE mytable SET _revision=NULL where id=$id 197 | ``` 198 | 199 | The parent and child tables are defined as 200 | 201 | ``` 202 | CREATE TABLE `mytable` ( 203 | `id` int(10) unsigned NOT NULL AUTO_INCREMENT, 204 | `name` varchar(255) NOT NULL DEFAULT '', 205 | `description` text, 206 | PRIMARY KEY (`id`), 207 | UNIQUE KEY `name` (`name`) 208 | ) ENGINE=InnoDB 209 | 210 | CREATE TABLE `mychild` ( 211 | `id` int(10) unsigned NOT NULL AUTO_INCREMENT, 212 | `mytable_id` int(10) unsigned NOT NULL DEFAULT '0', 213 | `title` varchar(255) NOT NULL DEFAULT '', 214 | PRIMARY KEY (`id`), 215 | KEY `mytable_id` (`mytable_id`), 216 | CONSTRAINT `mychild_ibfk_1` FOREIGN KEY (`mytable_id`) REFERENCES `mytable` (`id`) ON DELETE CASCADE 217 | ) ENGINE=InnoDB 218 | ``` 219 | 220 | Note that we are using InnoDB tables here. MyISAM doesn’t have foreign key constraints, therefor it’s not possible to define a parent-child relationship. 221 | 222 | ### Insert, update and delete 223 | 224 | In the parent trigger, two different things happen concerning the child rows. When a new version is created, the data of `mychild` is copied to the revisioning table. On a revision switch, data will be copied from the revisioning table into `mychild`. The “`_revision_action` IS NULL” condition, means that `_revision_mytable` is only updated when a new revision is created. 225 | 226 | ``` 227 | CREATE TRIGGER `mytable-afterupdate` AFTER update ON `mytable` 228 | FOR EACH ROW BEGIN 229 | DECLARE `newrev` BOOLEAN; 230 | 231 | UPDATE `_revision_mytable` SET `id` = NEW.`id`, `name` = NEW.`name`, `description` = NEW.`description`, `_revision_action`='update' WHERE `_revision`=NEW.`_revision` AND `_revision_action` IS NULL; 232 | SET newrev = (ROW_COUNT() > 0); 233 | INSERT INTO `_revhistory_mytable` VALUES (NEW.`id`, NEW.`_revision`, @auth_uid, NOW()); 234 | 235 | IF newrev THEN 236 | INSERT INTO `_revision_mychild` SELECT *, NEW.`_revision` FROM `mychild` WHERE `mytable_id` = NEW.`id`; 237 | ELSE 238 | DELETE `t`.* FROM `mychild` AS `t` LEFT JOIN `_revision_mychild` AS `r` ON 0=1 WHERE `t`.`mytable_id` = NEW.`id`; 239 | INSERT INTO `mychild` SELECT `id`, `mytable_id`, `title` FROM `_revision_mychild` WHERE `_revision` = NEW.`_revision`; 240 | END IF; 241 | END 242 | 243 | CREATE TRIGGER `mychild-afterinsert` AFTER INSERT ON `mychild` 244 | FOR EACH ROW BEGIN 245 | DECLARE CONTINUE HANDLER FOR 1442 BEGIN END; 246 | INSERT IGNORE INTO `_revision_mychild` (`id`, `mytable_id`, `title`, `_revision`) SELECT NEW.`id`, NEW.`mytable_id`, NEW.`title`, `_revision` FROM `mytable` AS `p` WHERE `p`.`id`=NEW.`mytable_id`; 247 | END 248 | 249 | CREATE TRIGGER `mychild-afterupdate` AFTER UPDATE ON `mychild` 250 | FOR EACH ROW BEGIN 251 | REPLACE INTO `_revision_mychild` (`id`, `mytable_id`, `title`, `_revision`) SELECT NEW.`id`, NEW.`mytable_id`, NEW.`title`, `_revision` FROM `mytable` AS `p` WHERE `p`.`id`=NEW.`mytable_id`; 252 | END 253 | 254 | CREATE TRIGGER `mychild-afterdelete` AFTER DELETE ON `mychild` 255 | FOR EACH ROW BEGIN 256 | DECLARE CONTINUE HANDLER FOR 1442 BEGIN END; 257 | DELETE `r`.* FROM `_revision_mychild` AS `r` INNER JOIN `mytable` AS `p` ON `r`.`_revision` = `p`.`_revision` WHERE `r`.`id` = OLD.`id`; 258 | END 259 | ``` 260 | 261 | Changing data in table `mychild` simply updates the data in the revisioning table. The revision number is grabbed from the field in the parent table. 262 | 263 | Switching the revision can only be done through the parent table. This will also automatically change the data in the child tables. We simply delete all rows of the record and replace them with data from the revisioning table. This would however trigger the deletion of the data in `_revision_child` on which the insert has nothing to do. To prevent this, we can abuse that fact that a trigger can’t update data of a table using in the insert/update/delete query. This causes error 1442. With a continue handler we can ignore this silently. 264 | 265 | The InnoDB constraints will handle the cascading delete. Deleting child data won’t activate the deletion trigger, which is all the better in this case. 266 | 267 | ### Without a primary key 268 | A primary key is not required for the child table, since versioning is done purely based on the id of `mytable`. 269 | 270 | ``` 271 | CREATE TABLE `mypart` ( 272 | `mytable_id` int(10) unsigned NOT NULL, 273 | `reference` varchar(255) NOT NULL, 274 | KEY `mytable_id` (`mytable_id`), 275 | CONSTRAINT `mypart_ibfk_1` FOREIGN KEY (`mytable_id`) REFERENCES `mytable` (`id`) ON DELETE CASCADE 276 | ) ENGINE=InnoDB 277 | ``` 278 | 279 | This does cause an issue for the update and delete triggers of the child table. It can’t use the primary to id to locate the current version of the modified/removed row. This can be solved by a trick I got from PhpMyAdmin. We can simply locate the record by comparing the old values of all fields. There is no constraint for the table enforcing the uniqueness of a row, so we could be targeting multiple identical rows. Since they are identical, it doesn’t matter which one we target, as long as we limit to 1 row. 280 | 281 | ``` 282 | CREATE TRIGGER `mypart-afterupdate` AFTER UPDATE ON `mypart` 283 | FOR EACH ROW BEGIN 284 | DELETE FROM `_revision_mypart` WHERE `_revision` IN (SELECT `_revision` FROM `mytable` WHERE `id` = OLD.`mytable_id`) AND `mytable_id` = OLD.`mytable_id` AND `reference` = OLD.`reference` LIMIT 1; 285 | INSERT INTO `_revision_mypart` (`mytable_id`, `reference`, `_revision`) SELECT NEW.`mytable_id`, NEW.`reference`, `_revision` FROM `mytable` AS `p` WHERE `p`.`id`=NEW.`mytable_id`; 286 | END 287 | 288 | CREATE TRIGGER `mypart-afterdelete` AFTER DELETE ON `mypart` 289 | FOR EACH ROW BEGIN 290 | DECLARE CONTINUE HANDLER FOR 1442 BEGIN END; 291 | DELETE FROM `_revision_mypart` WHERE `_revision` IN (SELECT `_revision` FROM `mytable` WHERE `id` = OLD.`mytable_id`) AND `mytable_id` = OLD.`mytable_id` AND `reference` = OLD.`reference` LIMIT 1; 292 | END 293 | ``` 294 | 295 | ### Unique keys 296 | The revisioning table has multiple versions of a record. Unique indexes from the original table should be converted to non-unique indexes in the revisioning table. This information can be fetched using INFORMATION_SCHEMA. 297 | 298 | ``` 299 | SELECT c.CONSTRAINT_NAME, GROUP_CONCAT(CONCAT('`', k.COLUMN_NAME, '`')) AS cols FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS AS `c` INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS `k` ON c.TABLE_SCHEMA=k.TABLE_SCHEMA AND c.TABLE_NAME=k.TABLE_NAME AND c.CONSTRAINT_NAME=k.CONSTRAINT_NAME WHERE c.TABLE_SCHEMA=DATABASE() AND c.TABLE_NAME='mytable' AND c.CONSTRAINT_TYPE='UNIQUE' AND c.CONSTRAINT_NAME != '_revision' GROUP BY c.CONSTRAINT_NAME 300 | ``` 301 | 302 | ## Revisioning and replication 303 | 304 | Revisioning using triggers, will only work with [row-based replication](https://dev.mysql.com/doc/refman/5.1/en/replication-sbr-rbr.html). On systems with statement-based replication, there is be a race condition when relying on auto-increment keys in triggers. 305 | -------------------------------------------------------------------------------- /mysql-revisioning.php: -------------------------------------------------------------------------------- 1 | conn = $conn instanceof mysqli ? $conn : new mysqli($conn['host'], $conn['user'], $conn['password'], $conn['db']); 35 | if (!isset($this->signal)) $this->signal = $this->conn->server_version >= 60000 ? 'SIGNAL SQLSTATE \'%errno\' SET MESSAGE_TEXT="%errmsg"' : 'DO `%errmsg`'; 36 | } 37 | 38 | /** 39 | * Performs a query on the database 40 | * 41 | * @param string $statement 42 | * @return mysqli_result 43 | */ 44 | protected function query($statement) 45 | { 46 | if ($this->verbose) echo "\n", $statement, "\n"; 47 | 48 | $result = $this->conn->query($statement); 49 | if (!$result) throw new Exception("Query failed ({$this->conn->errno}): {$this->conn->error} "); 50 | 51 | return $result; 52 | } 53 | 54 | /** 55 | * Create a revision table based to original table. 56 | * 57 | * @param string $table 58 | * @param array $info Table information 59 | */ 60 | protected function createRevisionTable($table, $info) 61 | { 62 | $pk = '`' . join('`, `', $info['primarykey']) . '`'; 63 | $change_autoinc = !empty($info['autoinc']) ? "CHANGE `{$info['autoinc']}` `{$info['autoinc']}` {$info['fieldtypes'][$info['autoinc']]}," : null; 64 | 65 | $unique_index = ""; 66 | foreach ($info['unique'] as $key=>$rows) $unique_index .= ", DROP INDEX `$key`, ADD INDEX `$key` ($rows)"; 67 | 68 | $sql = <<query("CREATE TABLE `_revision_$table` LIKE `$table`"); 85 | $this->query($sql); 86 | $this->query("INSERT INTO `_revision_$table` SELECT *, NULL, NULL, 'INSERT', NULL, NOW(), 'Revisioning initialisation' FROM `$table`"); 87 | } 88 | 89 | /** 90 | * Create a revision table based to original table. 91 | * 92 | * @param string $table 93 | * @param array $info Table information 94 | */ 95 | protected function createRevisionChildTable($table, $info) 96 | { 97 | if (!empty($info['primarykey'])) $pk = '`' . join('`, `', $info['primarykey']) . '`'; 98 | $change_autoinc = !empty($info['autoinc']) ? "CHANGE `{$info['autoinc']}` `{$info['autoinc']}` {$info['fieldtypes'][$info['autoinc']]}," : null; 99 | 100 | $unique_index = ""; 101 | foreach ($info['unique'] as $key=>$rows) $unique_index .= "DROP INDEX `$key`, ADD INDEX `$key` ($rows),"; 102 | 103 | if (isset($pk)) $sql = <<query("CREATE TABLE `_revision_$table` LIKE `$table`"); 122 | $this->query($sql); 123 | $this->query("INSERT INTO `_revision_$table` SELECT `t`.*, `p`.`_revision` FROM `$table` AS `t` INNER JOIN `{$info['parent']}` AS `p` ON `t`.`{$info['foreign_key']}`=`p`.`{$info['parent_key']}`"); 124 | } 125 | 126 | /** 127 | * Alter the existing table. 128 | * 129 | * @param string $table 130 | * @param array $info Table information 131 | */ 132 | protected function alterTable($table, $info) 133 | { 134 | foreach ($info['primarykey'] as $field) $pk_join[] = "`t`.`$field` = `r`.`$field`"; 135 | $pk_join = join(' AND ', $pk_join); 136 | 137 | $sql = <<query($sql); 145 | $this->query("UPDATE `$table` AS `t` INNER JOIN `_revision_$table` AS `r` ON $pk_join SET `t`.`_revision` = `r`.`_revision`"); 146 | } 147 | 148 | /** 149 | * Alter the existing table. 150 | * 151 | * @param string $table 152 | * @param array $info Table information 153 | */ 154 | function createHistoryTable($table, $info) 155 | { 156 | $pk = '`' . join('`, `', $info['primarykey']) . '`'; 157 | foreach ($info['primarykey'] as $field) $pk_type[] = "`$field` {$info['fieldtypes'][$field]}"; 158 | $pk_type = join(',', $pk_type); 159 | 160 | $sql = <<query($sql); 174 | $this->query("INSERT INTO `_revhistory_$table` SELECT $pk, `_revision`, NULL, `_revision_timestamp` FROM `_revision_$table`"); 175 | } 176 | 177 | 178 | /** 179 | * Create before insert trigger 180 | * 181 | * @param string $table 182 | * @param array $info Table information 183 | */ 184 | protected function beforeInsert($table, $info) 185 | { 186 | $fields = '`' . join('`, `', $info['fieldnames']) . '`'; 187 | $var_fields = '`var-' . join('`, `var-', $info['fieldnames']) . '`'; 188 | 189 | foreach ($info['fieldnames'] as $field) { 190 | $declare_var_fields[] = "DECLARE `var-$field` {$info['fieldtypes'][$field]}"; 191 | $new_to_var[] = "NEW.`$field` = `var-$field`"; 192 | } 193 | $declare_var_fields = join(";\n", $declare_var_fields); 194 | $new_to_var = join(', ', $new_to_var); 195 | 196 | $sql = <<query("DROP TRIGGER IF EXISTS `$table-beforeinsert`"); 220 | $this->query($sql); 221 | } 222 | 223 | /** 224 | * Create before insert trigger 225 | * 226 | * @param string $table 227 | * @param array $info Table information 228 | */ 229 | protected function beforeUpdate($table, $info) 230 | { 231 | $fields = '`' . join('`, `', $info['fieldnames']) . '`'; 232 | $var_fields = '`var-' . join('`, `var-', $info['fieldnames']) . '`'; 233 | 234 | foreach ($info['fieldnames'] as $field) { 235 | $declare_var_fields[] = "DECLARE `var-$field` {$info['fieldtypes'][$field]}"; 236 | $new_to_var[] = "NEW.`$field` = `var-$field`"; 237 | } 238 | $declare_var_fields = join(";\n", $declare_var_fields); 239 | $new_to_var = join(', ', $new_to_var); 240 | 241 | foreach ($info['primarykey'] as $field) $pk_new_ne_old[] = "(NEW.`$field` != OLD.`$field` OR NEW.`$field` IS NULL != OLD.`$field` IS NULL)"; 242 | $pk_new_ne_old = join(' OR ', $pk_new_ne_old); 243 | $signal_pk_new_ne_old = str_replace(array('%errno', '%errmsg'), array('23000', "Can't change the value of the primary key of table '$table' because of revisioning"), $this->signal); 244 | 245 | $sql = <<query("DROP TRIGGER IF EXISTS `$table-beforeupdate`"); 282 | $this->query($sql); 283 | } 284 | 285 | 286 | /** 287 | * Create after insert trigger. 288 | * 289 | * @param string $table 290 | * @param array $info Table information 291 | * @param array $children Information of child tables 292 | */ 293 | protected function afterInsert($table, $info, $children) 294 | { 295 | $aftertrigger = empty($children) ? 'afterTriggerSingle' : 'afterTriggerParent'; 296 | $this->$aftertrigger('insert', $table, $info, $children); 297 | } 298 | 299 | /** 300 | * Create after update trigger. 301 | * 302 | * @param string $table 303 | * @param array $info Table information 304 | * @param array $children Information of child tables 305 | */ 306 | protected function afterUpdate($table, $info, $children) 307 | { 308 | $aftertrigger = empty($children) ? 'afterTriggerSingle' : 'afterTriggerParent'; 309 | $this->$aftertrigger('update', $table, $info, $children); 310 | } 311 | 312 | /** 313 | * Create after insert/update trigger for table without children. 314 | * 315 | * @param string $action INSERT or UPDATE 316 | * @param string $table 317 | * @param array $info Table information 318 | */ 319 | protected function afterTriggerSingle($action, $table, $info) 320 | { 321 | $pk = 'NEW.`' . join('`, NEW.`', $info['primarykey']) . '`'; 322 | foreach ($info['fieldnames'] as $field) $fields_is_new[] = "`$field` = NEW.`$field`"; 323 | $fields_is_new = join(', ', $fields_is_new); 324 | 325 | $sql = <<query("DROP TRIGGER IF EXISTS `$table-after$action`"); 334 | $this->query($sql); 335 | } 336 | 337 | /** 338 | * Create after insert/update trigger for table with children. 339 | * 340 | * @param string $action INSERT or UPDATE 341 | * @param string $table 342 | * @param array $info Table information 343 | * @param array $children Information of child tables 344 | */ 345 | protected function afterTriggerParent($action, $table, $info, $children=array()) 346 | { 347 | $pk = 'NEW.`' . join('`, NEW.`', $info['primarykey']) . '`'; 348 | foreach ($info['fieldnames'] as $field) $fields_is_new[] = "`$field` = NEW.`$field`"; 349 | $fields_is_new = join(', ', $fields_is_new); 350 | 351 | $child_newrev = ""; 352 | $child_switch = ""; 353 | foreach ($children as $child=>&$chinfo) { 354 | $child_fields = '`' . join('`, `', $chinfo['fieldnames']) . '`'; 355 | 356 | $child_newrev .= " INSERT INTO `_revision_$child` SELECT *, NEW.`_revision` FROM `$child` WHERE `{$chinfo['foreign_key']}` = NEW.`{$chinfo['parent_key']}`;"; 357 | if ($action == 'update') $child_switch .= " DELETE `t`.* FROM `$child` AS `t` LEFT JOIN `_revision_{$child}` AS `r` ON 0=1 WHERE `t`.`{$chinfo['foreign_key']}` = NEW.`{$chinfo['parent_key']}`;"; 358 | $child_switch .= " INSERT INTO `$child` SELECT $child_fields FROM `_revision_{$child}` WHERE `_revision` = NEW.`_revision`;"; 359 | } 360 | 361 | $sql = << 0); 368 | INSERT INTO `_revhistory_$table` VALUES ($pk, NEW.`_revision`, @auth_uid, NOW()); 369 | 370 | IF newrev THEN 371 | $child_newrev 372 | ELSE 373 | $child_switch 374 | END IF; 375 | END 376 | SQL; 377 | 378 | $this->query("DROP TRIGGER IF EXISTS `$table-after$action`"); 379 | $this->query($sql); 380 | } 381 | 382 | /** 383 | * Create after update trigger. 384 | * 385 | * @param string $table 386 | * @param array $info Table information 387 | */ 388 | protected function afterDelete($table, $info) 389 | { 390 | $pk = 'OLD.`' . join('`, OLD.`', $info['primarykey']) . '`'; 391 | 392 | $sql = <<query("DROP TRIGGER IF EXISTS `$table-afterdelete`"); 400 | $this->query($sql); 401 | } 402 | 403 | 404 | /** 405 | * Create after insert/update trigger. 406 | * 407 | * @param string $table 408 | * @param array $info Table information 409 | */ 410 | protected function afterInsertChild($table, $info) 411 | { 412 | $new = 'NEW.`' . join('`, NEW.`', $info['fieldnames']) . '`'; 413 | $fields = '`' . join('`, `', $info['fieldnames']) . '`'; 414 | 415 | $sql = <<query("DROP TRIGGER IF EXISTS `$table-afterinsert`"); 424 | $this->query($sql); 425 | } 426 | 427 | /** 428 | * Create after insert/update trigger. 429 | * 430 | * @param string $table 431 | * @param array $info Table information 432 | */ 433 | protected function afterUpdateChild($table, $info) 434 | { 435 | $new = 'NEW.`' . join('`, NEW.`', $info['fieldnames']) . '`'; 436 | $fields = '`' . join('`, `', $info['fieldnames']) . '`'; 437 | $delete = null; 438 | 439 | if (empty($info['primarykey'])) { 440 | foreach ($info['fieldnames'] as $field) $fields_is_old[] = "`$field` = OLD.`$field`"; 441 | $delete = "DELETE FROM `_revision_$table` WHERE `_revision` IN (SELECT `_revision` FROM `{$info['parent']}` WHERE `{$info['parent_key']}` = OLD.`{$info['foreign_key']}`) AND " . join(' AND ', $fields_is_old) . " LIMIT 1;"; 442 | } 443 | 444 | $sql = <<query("DROP TRIGGER IF EXISTS `$table-afterupdate`"); 453 | $this->query($sql); 454 | } 455 | 456 | /** 457 | * Create after update trigger. 458 | * 459 | * @param string $table 460 | * @param array $info Table information 461 | */ 462 | protected function afterDeleteChild($table, $info) 463 | { 464 | if (!empty($info['primarykey'])) { 465 | foreach ($info['primarykey'] as $field) $fields_is_old[] = "`r`.`$field` = OLD.`$field`"; 466 | $delete = "DELETE `r`.* FROM `_revision_$table` AS `r` INNER JOIN `{$info['parent']}` AS `p` ON `r`.`_revision` = `p`.`_revision` WHERE " . join(' AND ', $fields_is_old) . ";"; 467 | 468 | } else { 469 | foreach ($info['fieldnames'] as $field) $fields_is_old[] = "`$field` = OLD.`$field`"; 470 | $delete = "DELETE FROM `_revision_$table` WHERE `_revision` IN (SELECT `_revision` FROM `{$info['parent']}` WHERE `{$info['parent_key']}` = OLD.`{$info['foreign_key']}`) AND " . join(' AND ', $fields_is_old) . " LIMIT 1;"; 471 | } 472 | 473 | $sql = <<query("DROP TRIGGER IF EXISTS `$table-afterdelete`"); 482 | $this->query($sql); 483 | } 484 | 485 | 486 | /** 487 | * Add revisioning 488 | * 489 | * @param array $args 490 | */ 491 | public function install($args) 492 | { 493 | foreach ($args as $arg) { 494 | if (is_string($arg)) { 495 | $matches = null; 496 | if (!preg_match_all('/[^,()\s]++/', $arg, $matches, PREG_PATTERN_ORDER)) continue; 497 | } else { 498 | $matches[0] = $arg; 499 | } 500 | 501 | $exists = false; 502 | $tables = array(); 503 | 504 | // Prepare 505 | foreach ($matches[0] as $i=>$table) { 506 | $info = array('parent'=>$i > 0 ? $matches[0][0] : null, 'unique'=>array()); 507 | $result = $this->query("DESCRIBE `$table`;"); 508 | 509 | while ($field = $result->fetch_assoc()) { 510 | if (preg_match('/^_revision/', $field['Field'])) { 511 | $exists = true; 512 | continue; 513 | } 514 | 515 | $info['fieldnames'][] = $field['Field']; 516 | if ($field['Key'] == 'PRI') $info['primarykey'][] = $field['Field']; 517 | if (preg_match('/\bauto_increment\b/i', $field['Extra'])) $info['autoinc'] = $field['Field']; 518 | $info['fieldtypes'][$field['Field']] = $field['Type']; 519 | } 520 | 521 | $result = $this->query("SELECT c.CONSTRAINT_NAME, GROUP_CONCAT(CONCAT('`', k.COLUMN_NAME, '`')) AS cols FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS AS `c` INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS `k` ON c.TABLE_SCHEMA=k.TABLE_SCHEMA AND c.TABLE_NAME=k.TABLE_NAME AND c.CONSTRAINT_NAME=k.CONSTRAINT_NAME WHERE c.TABLE_SCHEMA=DATABASE() AND c.TABLE_NAME='$table' AND c.CONSTRAINT_TYPE='UNIQUE' AND c.CONSTRAINT_NAME != '_revision' GROUP BY c.CONSTRAINT_NAME"); 522 | while ($key = $result->fetch_row()) $info['unique'][$key[0]] = $key[1]; 523 | 524 | if (empty($info['parent'])) { 525 | if (empty($info['primarykey'])) { 526 | trigger_error("Unable to add revisioning table '$table': Table does not have a primary key", E_USER_WARNING); 527 | continue 2; 528 | } 529 | } else { 530 | $result = $this->query("SELECT `COLUMN_NAME`, `REFERENCED_COLUMN_NAME` FROM `INFORMATION_SCHEMA`.`KEY_COLUMN_USAGE` WHERE `TABLE_SCHEMA` = DATABASE() AND `TABLE_NAME` = '$table' AND REFERENCED_TABLE_SCHEMA = DATABASE() AND REFERENCED_TABLE_NAME = '{$info['parent']}' AND `REFERENCED_COLUMN_NAME` IS NOT NULL"); 531 | if ($result->num_rows == 0) { 532 | trigger_error("Unable to add revisioning table '$table' as child of '{$info['parent']}': Table does not have a foreign key reference to parent table", E_USER_WARNING); 533 | continue; 534 | } 535 | list($info['foreign_key'], $info['parent_key']) = $result->fetch_row(); 536 | } 537 | 538 | $tables[$table] = $info; 539 | } 540 | 541 | // Process 542 | reset($tables); 543 | $table = key($tables); 544 | $info = array_shift($tables); 545 | 546 | echo "Installing revisioning for `$table`"; 547 | 548 | // Parent 549 | if (!$exists) { 550 | echo " - tables"; 551 | $this->createRevisionTable($table, $info); 552 | $this->alterTable($table, $info); 553 | $this->createHistoryTable($table, $info); 554 | } 555 | 556 | echo " - triggers"; 557 | $this->beforeInsert($table, $info, $tables); 558 | $this->afterUpdate($table, $info, $tables); 559 | 560 | $this->beforeUpdate($table, $info, $tables); 561 | $this->afterInsert($table, $info, $tables); 562 | 563 | $this->afterDelete($table, $info, $tables); 564 | 565 | // Children 566 | foreach ($tables as $table=>&$info) { 567 | echo "\n - child `$table`"; 568 | 569 | if (!$exists) { 570 | echo " - tables"; 571 | $this->createRevisionChildTable($table, $info); 572 | } 573 | 574 | echo " - triggers"; 575 | $this->afterInsertChild($table, $info); 576 | $this->afterUpdateChild($table, $info); 577 | $this->afterDeleteChild($table, $info); 578 | } 579 | 580 | echo "\n"; 581 | } 582 | } 583 | 584 | /** 585 | * Remove revisioning for tables 586 | * 587 | * @param $args 588 | */ 589 | public function remove($args) 590 | { 591 | foreach ($args as $arg) { 592 | $matches = null; 593 | if (!preg_match_all('/[^,()\s]++/', $arg, $matches, PREG_PATTERN_ORDER)) return; 594 | 595 | // Prepare 596 | foreach ($matches[0] as $i=>$table) { 597 | echo "Removing revisioning for `$table`\n"; 598 | 599 | $this->query("DROP TRIGGER IF EXISTS `$table-afterdelete`;"); 600 | $this->query("DROP TRIGGER IF EXISTS `$table-afterupdate`;"); 601 | $this->query("DROP TRIGGER IF EXISTS `$table-beforeupdate`;"); 602 | $this->query("DROP TRIGGER IF EXISTS `$table-afterinsert`;"); 603 | $this->query("DROP TRIGGER IF EXISTS `$table-beforeinsert`;"); 604 | 605 | if ($i == 0) $this->query("DROP TABLE IF EXISTS `_revhistory_$table`;"); 606 | $this->query("DROP TABLE IF EXISTS `_revision_$table`;"); 607 | if ($i == 0) $this->query("ALTER TABLE `$table` DROP `_revision`, DROP `_revision_comment`"); 608 | } 609 | } 610 | } 611 | 612 | public function help() 613 | { 614 | echo <<'localhost', 'user'=>null, 'password'=>null, 'db'=>null); 636 | 637 | for ($i=1; $i < $_SERVER['argc']; $i++) { 638 | if (strncmp($_SERVER['argv'][$i], '--', 2) == 0) { 639 | list($key, $value) = explode("=", substr($_SERVER['argv'][$i], 2), 2) + array(1=>null); 640 | 641 | if (property_exists($this, $key)) $this->$key = isset($value) ? $value : true; 642 | elseif (!isset($value)) $cmd = $key; 643 | else $settings[$key] = $value; 644 | } else { 645 | $args[] = $_SERVER['argv'][$i]; 646 | } 647 | } 648 | 649 | if (!isset($cmd)) $cmd = empty($args) ? 'help' : 'install'; 650 | 651 | $this->connect($settings); 652 | $this->$cmd($args); 653 | } 654 | } 655 | 656 | // Execute controller command 657 | if (isset($_SERVER['argv']) && realpath($_SERVER['argv'][0]) == realpath(__FILE__)) { 658 | $ctl = new MySQL_Revisioning(); 659 | $ctl->execCmd(); 660 | } 661 | --------------------------------------------------------------------------------