This adds the rev_id column to the end of the rev_actor_timestamp index to make it unambiguous. With the id field added, the index matches the pagination criterion for user contributions (filter by actor, sort by timestamp, then disambiguate based on revision id). The index is not marked UNIQUE since this would potentially degrade write performance. Uniqueness is already guaranteed by the rev_id field being the primary key. Note that no provisions are made to change the definition of the rev_actor_timestamp index for existing instances. This index was only recently added in I18071a2fe45907a0cf1b0fefebd96a97a2dacb7b and has not been part of any release. It has also not yet been created on the wikimedia servers. For this reason, any existing instances are assumed to be for testing only. Instances would also continue to function normally with the previous index definition. With this patch, the new index will be created correctly when updating from 1.34 or earlier. It will however not be modified for installations of some development version of 1.35. Bug: T200259 Bug: T238966 Change-Id: I511bb21b1ca820d950818cc831f8e3fef43a1559
36 lines
1.5 KiB
PL/PgSQL
36 lines
1.5 KiB
PL/PgSQL
-- T161671, T184615, T215466: Drop old revision user, comment, and content fields, and
|
|
-- add the replacement actor and comment_id fields.
|
|
|
|
BEGIN;
|
|
|
|
DROP TABLE IF EXISTS /*_*/revision_tmp;
|
|
CREATE TABLE /*_*/revision_tmp (
|
|
rev_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
|
|
rev_page int unsigned NOT NULL,
|
|
rev_comment_id bigint unsigned NOT NULL default 0,
|
|
rev_actor bigint unsigned NOT NULL default 0,
|
|
rev_timestamp binary(14) NOT NULL default '',
|
|
rev_minor_edit tinyint unsigned NOT NULL default 0,
|
|
rev_deleted tinyint unsigned NOT NULL default 0,
|
|
rev_len int unsigned,
|
|
rev_parent_id int unsigned default NULL,
|
|
rev_sha1 varbinary(32) NOT NULL default ''
|
|
) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=1024;
|
|
|
|
INSERT OR IGNORE INTO revision_tmp (
|
|
rev_id, rev_page, rev_timestamp, rev_minor_edit, rev_deleted, rev_len,
|
|
rev_parent_id, rev_sha1)
|
|
SELECT
|
|
rev_id, rev_page, rev_timestamp, rev_minor_edit, rev_deleted, rev_len,
|
|
rev_parent_id, rev_sha1
|
|
FROM /*_*/revision;
|
|
|
|
DROP TABLE /*_*/revision;
|
|
ALTER TABLE /*_*/revision_tmp RENAME TO /*_*/revision;
|
|
CREATE INDEX /*i*/rev_page_id ON /*_*/revision (rev_page, rev_id);
|
|
CREATE INDEX /*i*/rev_timestamp ON /*_*/revision (rev_timestamp);
|
|
CREATE INDEX /*i*/page_timestamp ON /*_*/revision (rev_page,rev_timestamp);
|
|
CREATE INDEX /*i*/rev_actor_timestamp ON /*_*/revision (rev_actor,rev_timestamp,rev_id);
|
|
CREATE INDEX /*i*/rev_page_actor_timestamp ON /*_*/revision (rev_page,rev_actor,rev_timestamp);
|
|
|
|
COMMIT;
|