Migrate ip_changes to abstract schema
In order to make Postgres work: - Dropped the autoincrement sequence, this is the PK without autoincrement - Change ipc_hex from BYTEA to TEXT - Set default for ipc_rev_id MySQL/SQLite: -Drop default for ipc_rev_timestamp Bug: T230428 Bug: T164898 Change-Id: I7f85d65f6ee3ac8b1d28e33095f37dce81e1727e
This commit is contained in:
parent
c823e03ec9
commit
b14f9ead33
11 changed files with 86 additions and 35 deletions
|
|
@ -458,6 +458,7 @@ class MysqlUpdater extends DatabaseUpdater {
|
|||
],
|
||||
[ 'modifyField', 'protected_titles', 'pt_title', 'patch-protected_titles-pt_title-varbinary.sql' ],
|
||||
[ 'modifyField', 'protected_titles', 'pt_expiry', 'patch-protected_titles-pt_expiry-drop-default.sql' ],
|
||||
[ 'modifyField', 'ip_changes', 'ipc_rev_timestamp', 'patch-ip_changes-pc_rev_timestamp-drop-default.sql' ],
|
||||
];
|
||||
}
|
||||
|
||||
|
|
|
|||
|
|
@ -808,6 +808,9 @@ class PostgresUpdater extends DatabaseUpdater {
|
|||
[ 'renameIndex', 'externallinks', 'externallinks_from_to', 'el_from' ],
|
||||
[ 'renameIndex', 'externallinks', 'externallinks_index', 'el_index' ],
|
||||
[ 'addPgIndex', 'externallinks', 'el_to', '(el_to, el_from)' ],
|
||||
[ 'dropSequence', 'ip_changes', 'ip_changes_ipc_rev_id_seq' ],
|
||||
[ 'changeField', 'ip_changes', 'ipc_hex', 'TEXT', "ipc_hex::TEXT DEFAULT ''" ],
|
||||
[ 'setDefault', 'ip_changes', 'ipc_rev_id', 0 ],
|
||||
];
|
||||
}
|
||||
|
||||
|
|
|
|||
|
|
@ -311,6 +311,7 @@ class SqliteUpdater extends DatabaseUpdater {
|
|||
[ 'modifyField', 'watchlist', 'wl_title', 'patch-watchlist-wl_title-varbinary.sql' ],
|
||||
[ 'modifyField', 'protected_titles', 'pt_title', 'patch-protected_titles-pt_title-varbinary.sql' ],
|
||||
[ 'modifyField', 'protected_titles', 'pt_expiry', 'patch-protected_titles-pt_expiry-drop-default.sql' ],
|
||||
[ 'modifyField', 'ip_changes', 'ipc_rev_timestamp', 'patch-ip_changes-pc_rev_timestamp-drop-default.sql' ]
|
||||
];
|
||||
}
|
||||
|
||||
|
|
|
|||
|
|
@ -0,0 +1 @@
|
|||
ALTER TABLE /*_*/ip_changes ALTER COLUMN ipc_rev_timestamp DROP DEFAULT;
|
||||
|
|
@ -452,3 +452,15 @@ CREATE INDEX el_index ON externallinks (el_index);
|
|||
CREATE INDEX el_index_60 ON externallinks (el_index_60, el_id);
|
||||
|
||||
CREATE INDEX el_from_index_60 ON externallinks (el_from, el_index_60, el_id);
|
||||
|
||||
|
||||
CREATE TABLE ip_changes (
|
||||
ipc_rev_id INT DEFAULT 0 NOT NULL,
|
||||
ipc_rev_timestamp TIMESTAMPTZ NOT NULL,
|
||||
ipc_hex TEXT DEFAULT '' NOT NULL,
|
||||
PRIMARY KEY(ipc_rev_id)
|
||||
);
|
||||
|
||||
CREATE INDEX ipc_rev_timestamp ON ip_changes (ipc_rev_timestamp);
|
||||
|
||||
CREATE INDEX ipc_hex_time ON ip_changes (ipc_hex, ipc_rev_timestamp);
|
||||
|
|
|
|||
|
|
@ -110,16 +110,6 @@ CREATE UNIQUE INDEX revactor_rev ON revision_actor_temp (revactor_rev);
|
|||
CREATE INDEX revactor_actor_timestamp ON revision_actor_temp (revactor_actor,revactor_timestamp);
|
||||
CREATE INDEX revactor_page_actor_timestamp ON revision_actor_temp (revactor_page,revactor_actor,revactor_timestamp);
|
||||
|
||||
CREATE SEQUENCE ip_changes_ipc_rev_id_seq;
|
||||
CREATE TABLE ip_changes (
|
||||
ipc_rev_id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval('ip_changes_ipc_rev_id_seq'),
|
||||
ipc_rev_timestamp TIMESTAMPTZ NOT NULL,
|
||||
ipc_hex BYTEA NOT NULL DEFAULT ''
|
||||
);
|
||||
ALTER SEQUENCE ip_changes_ipc_rev_id_seq OWNED BY ip_changes.ipc_rev_id;
|
||||
CREATE INDEX ipc_rev_timestamp ON ip_changes (ipc_rev_timestamp);
|
||||
CREATE INDEX ipc_hex_time ON ip_changes (ipc_hex,ipc_rev_timestamp);
|
||||
|
||||
CREATE SEQUENCE text_old_id_seq;
|
||||
CREATE TABLE pagecontent ( -- replaces reserved word 'text'
|
||||
old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_seq'),
|
||||
|
|
|
|||
|
|
@ -0,0 +1,17 @@
|
|||
CREATE TABLE /*_*/ip_changes_tmp (
|
||||
ipc_rev_id INTEGER UNSIGNED DEFAULT 0 NOT NULL,
|
||||
ipc_rev_timestamp BLOB NOT NULL,
|
||||
ipc_hex BLOB DEFAULT '' NOT NULL,
|
||||
PRIMARY KEY(ipc_rev_id)
|
||||
);
|
||||
|
||||
INSERT INTO /*_*/ip_changes_tmp
|
||||
SELECT ipc_rev_id, ipc_rev_timestamp, ipc_hex
|
||||
FROM /*_*/ip_changes;
|
||||
DROP TABLE /*_*/ip_changes;
|
||||
ALTER TABLE /*_*/ip_changes_tmp RENAME TO /*_*/ip_changes;
|
||||
|
||||
|
||||
CREATE INDEX ipc_rev_timestamp ON /*_*/ip_changes (ipc_rev_timestamp);
|
||||
|
||||
CREATE INDEX ipc_hex_time ON /*_*/ip_changes (ipc_hex, ipc_rev_timestamp);
|
||||
|
|
@ -433,3 +433,15 @@ CREATE INDEX el_index ON /*_*/externallinks (el_index);
|
|||
CREATE INDEX el_index_60 ON /*_*/externallinks (el_index_60, el_id);
|
||||
|
||||
CREATE INDEX el_from_index_60 ON /*_*/externallinks (el_from, el_index_60, el_id);
|
||||
|
||||
|
||||
CREATE TABLE /*_*/ip_changes (
|
||||
ipc_rev_id INTEGER UNSIGNED DEFAULT 0 NOT NULL,
|
||||
ipc_rev_timestamp BLOB NOT NULL,
|
||||
ipc_hex BLOB DEFAULT '' NOT NULL,
|
||||
PRIMARY KEY(ipc_rev_id)
|
||||
);
|
||||
|
||||
CREATE INDEX ipc_rev_timestamp ON /*_*/ip_changes (ipc_rev_timestamp);
|
||||
|
||||
CREATE INDEX ipc_hex_time ON /*_*/ip_changes (ipc_hex, ipc_rev_timestamp);
|
||||
|
|
|
|||
|
|
@ -405,3 +405,13 @@ CREATE TABLE /*_*/externallinks (
|
|||
INDEX el_from_index_60 (el_from, el_index_60, el_id),
|
||||
PRIMARY KEY(el_id)
|
||||
) /*$wgDBTableOptions*/;
|
||||
|
||||
|
||||
CREATE TABLE /*_*/ip_changes (
|
||||
ipc_rev_id INT UNSIGNED DEFAULT 0 NOT NULL,
|
||||
ipc_rev_timestamp BINARY(14) NOT NULL,
|
||||
ipc_hex VARBINARY(35) DEFAULT '' NOT NULL,
|
||||
INDEX ipc_rev_timestamp (ipc_rev_timestamp),
|
||||
INDEX ipc_hex_time (ipc_hex, ipc_rev_timestamp),
|
||||
PRIMARY KEY(ipc_rev_id)
|
||||
) /*$wgDBTableOptions*/;
|
||||
|
|
|
|||
|
|
@ -1321,5 +1321,34 @@
|
|||
{ "name": "el_from_index_60", "columns": [ "el_from", "el_index_60", "el_id" ], "unique": false }
|
||||
],
|
||||
"pk": [ "el_id" ]
|
||||
},
|
||||
{
|
||||
"name": "ip_changes",
|
||||
"comment": "Every time an edit by a logged out user is saved, a row is created in ip_changes. This stores the IP as a hex representation so that we can more easily find edits within an IP range.",
|
||||
"columns": [
|
||||
{
|
||||
"name": "ipc_rev_id",
|
||||
"comment": "Foreign key to the revision table, also serves as the unique primary key",
|
||||
"type": "integer",
|
||||
"options": { "unsigned": true, "notnull": true, "default": 0 }
|
||||
},
|
||||
{
|
||||
"name": "ipc_rev_timestamp",
|
||||
"comment": "The timestamp of the revision",
|
||||
"type": "mwtimestamp",
|
||||
"options": { "notnull": true }
|
||||
},
|
||||
{
|
||||
"name": "ipc_hex",
|
||||
"comment": "Hex representation of the IP address, as returned by Wikimedia\\IPUtils::toHex() For IPv4 it will resemble: ABCD1234 For IPv6: v6-ABCD1234000000000000000000000000 BETWEEN is then used to identify revisions within a given range",
|
||||
"type": "binary",
|
||||
"options": { "length": 35, "notnull": true, "default": "" }
|
||||
}
|
||||
],
|
||||
"indexes": [
|
||||
{ "name": "ipc_rev_timestamp", "columns": [ "ipc_rev_timestamp" ], "unique": false },
|
||||
{ "name": "ipc_hex_time", "columns": [ "ipc_hex", "ipc_rev_timestamp" ], "unique": false }
|
||||
],
|
||||
"pk": [ "ipc_rev_id" ]
|
||||
}
|
||||
]
|
||||
|
|
|
|||
|
|
@ -314,31 +314,6 @@ CREATE UNIQUE INDEX /*i*/revactor_rev ON /*_*/revision_actor_temp (revactor_rev)
|
|||
CREATE INDEX /*i*/actor_timestamp ON /*_*/revision_actor_temp (revactor_actor,revactor_timestamp);
|
||||
CREATE INDEX /*i*/page_actor_timestamp ON /*_*/revision_actor_temp (revactor_page,revactor_actor,revactor_timestamp);
|
||||
|
||||
--
|
||||
-- Every time an edit by a logged out user is saved,
|
||||
-- a row is created in ip_changes. This stores
|
||||
-- the IP as a hex representation so that we can more
|
||||
-- easily find edits within an IP range.
|
||||
--
|
||||
CREATE TABLE /*_*/ip_changes (
|
||||
-- Foreign key to the revision table, also serves as the unique primary key
|
||||
ipc_rev_id int unsigned NOT NULL PRIMARY KEY DEFAULT 0,
|
||||
|
||||
-- The timestamp of the revision
|
||||
ipc_rev_timestamp binary(14) NOT NULL DEFAULT '',
|
||||
|
||||
-- Hex representation of the IP address, as returned by Wikimedia\IPUtils::toHex()
|
||||
-- For IPv4 it will resemble: ABCD1234
|
||||
-- For IPv6: v6-ABCD1234000000000000000000000000
|
||||
-- BETWEEN is then used to identify revisions within a given range
|
||||
ipc_hex varbinary(35) NOT NULL DEFAULT ''
|
||||
|
||||
) /*$wgDBTableOptions*/;
|
||||
|
||||
CREATE INDEX /*i*/ipc_rev_timestamp ON /*_*/ip_changes (ipc_rev_timestamp);
|
||||
CREATE INDEX /*i*/ipc_hex_time ON /*_*/ip_changes (ipc_hex,ipc_rev_timestamp);
|
||||
|
||||
--
|
||||
-- Holds text of individual page revisions.
|
||||
--
|
||||
-- Field names are a holdover from the 'old' revisions table in
|
||||
|
|
|
|||
Loading…
Reference in a new issue