wiki.techinc.nl/maintenance/sqlite/archives/patch-revision-actor-comment-MCR.sql
Brad Jorsch c04732b987 Alter revision for actor, comment, and MCR
We're finally to the point of making the massive alter to the `revision`
table that we've been building up to for 2.5 years now.

Changes here are:
* Drop `rev_text_id`, `rev_content_model`, and `rev_content_format` that
  MCR obsoleted.
* Drop `ar_text_id`, `ar_content_model`, and `ar_content_format` that
  MCR obsoleted.
* Replace `rev_comment` with `rev_comment_id`.
* Replace `rev_user` and `rev_user_text` with `rev_actor`, plus
  associated index changes.

Future patches will make the code changes to migrate data from
`revision_actor_temp` and `revision_comment_temp` into the new
`revision` columns.

Bug: T251343
Bug: T184615
Bug: T215466
Change-Id: I18071a2fe45907a0cf1b0fefebd96a97a2dacb7b
2020-05-08 15:26:56 +00:00

36 lines
1.4 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);
CREATE INDEX /*i*/rev_page_actor_timestamp ON /*_*/revision (rev_page,rev_actor,rev_timestamp);
COMMIT;