Make user_ip in user_newtalk a TEXT, as it is not an IP field.
[lhc/web/wiklou.git] / maintenance / postgres / tables.sql
1 -- SQL to create the initial tables for the MediaWiki database.
2 -- This is read and executed by the install script; you should
3 -- not have to run it by itself unless doing a manual install.
4 -- This is the PostgreSQL version.
5 -- For information about each table, please see the notes in maintenance/tables.sql
6 -- Please make sure all dollar-quoting uses $mw$ at the start of the line
7 -- We can't use SERIAL everywhere: the sequence names are hard-coded into the PHP
8 -- TODO: Change CHAR to BOOL
9
10 BEGIN;
11 SET client_min_messages = 'ERROR';
12
13 CREATE SEQUENCE user_user_id_seq MINVALUE 0 START WITH 0;
14 CREATE TABLE mwuser ( -- replace reserved word 'user'
15 user_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('user_user_id_seq'),
16 user_name TEXT NOT NULL UNIQUE,
17 user_real_name TEXT,
18 user_password TEXT,
19 user_newpassword TEXT,
20 user_newpass_time TIMESTAMPTZ,
21 user_token CHAR(32),
22 user_email TEXT,
23 user_email_token CHAR(32),
24 user_email_token_expires TIMESTAMPTZ,
25 user_email_authenticated TIMESTAMPTZ,
26 user_options TEXT,
27 user_touched TIMESTAMPTZ,
28 user_registration TIMESTAMPTZ,
29 user_editcount INTEGER
30 );
31 CREATE INDEX user_email_token_idx ON mwuser (user_email_token);
32
33 -- Create a dummy user to satisfy fk contraints especially with revisions
34 INSERT INTO mwuser
35 VALUES (DEFAULT,'Anonymous','',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,now(),now());
36
37 CREATE TABLE user_groups (
38 ug_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
39 ug_group TEXT NOT NULL
40 );
41 CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
42
43 CREATE TABLE user_newtalk (
44 user_id INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
45 user_ip TEXT NULL
46 );
47 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
48 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
49
50
51 CREATE SEQUENCE page_page_id_seq;
52 CREATE TABLE page (
53 page_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('page_page_id_seq'),
54 page_namespace SMALLINT NOT NULL,
55 page_title TEXT NOT NULL,
56 page_restrictions TEXT,
57 page_counter BIGINT NOT NULL DEFAULT 0,
58 page_is_redirect CHAR NOT NULL DEFAULT 0,
59 page_is_new CHAR NOT NULL DEFAULT 0,
60 page_random NUMERIC(15,14) NOT NULL DEFAULT RANDOM(),
61 page_touched TIMESTAMPTZ,
62 page_latest INTEGER NOT NULL, -- FK?
63 page_len INTEGER NOT NULL
64 );
65 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
66 CREATE INDEX page_main_title ON page (page_title) WHERE page_namespace = 0;
67 CREATE INDEX page_talk_title ON page (page_title) WHERE page_namespace = 1;
68 CREATE INDEX page_user_title ON page (page_title) WHERE page_namespace = 2;
69 CREATE INDEX page_utalk_title ON page (page_title) WHERE page_namespace = 3;
70 CREATE INDEX page_project_title ON page (page_title) WHERE page_namespace = 4;
71 CREATE INDEX page_random_idx ON page (page_random);
72 CREATE INDEX page_len_idx ON page (page_len);
73
74 CREATE FUNCTION page_deleted() RETURNS TRIGGER LANGUAGE plpgsql AS
75 $mw$
76 BEGIN
77 DELETE FROM recentchanges WHERE rc_namespace = OLD.page_namespace AND rc_title = OLD.page_title;
78 RETURN NULL;
79 END;
80 $mw$;
81
82 CREATE TRIGGER page_deleted AFTER DELETE ON page
83 FOR EACH ROW EXECUTE PROCEDURE page_deleted();
84
85 CREATE SEQUENCE rev_rev_id_val;
86 CREATE TABLE revision (
87 rev_id INTEGER NOT NULL UNIQUE DEFAULT nextval('rev_rev_id_val'),
88 rev_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE,
89 rev_text_id INTEGER NULL, -- FK
90 rev_comment TEXT,
91 rev_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE RESTRICT,
92 rev_user_text TEXT NOT NULL,
93 rev_timestamp TIMESTAMPTZ NOT NULL,
94 rev_minor_edit CHAR NOT NULL DEFAULT '0',
95 rev_deleted CHAR NOT NULL DEFAULT '0'
96 );
97 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
98 CREATE INDEX rev_text_id_idx ON revision (rev_text_id);
99 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
100 CREATE INDEX rev_user_idx ON revision (rev_user);
101 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
102
103
104 CREATE SEQUENCE text_old_id_val;
105 CREATE TABLE pagecontent ( -- replaces reserved word 'text'
106 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_val'),
107 old_text TEXT,
108 old_flags TEXT
109 );
110
111
112 CREATE TABLE page_restrictions (
113 pr_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE,
114 pr_type TEXT NOT NULL,
115 pr_level TEXT NOT NULL,
116 pr_cascade SMALLINT NOT NULL,
117 pr_user INTEGER NULL,
118 pr_expiry TIMESTAMPTZ NULL
119 );
120 ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type);
121
122
123 CREATE TABLE archive2 (
124 ar_namespace SMALLINT NOT NULL,
125 ar_title TEXT NOT NULL,
126 ar_text TEXT,
127 ar_comment TEXT,
128 ar_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
129 ar_user_text TEXT NOT NULL,
130 ar_timestamp TIMESTAMPTZ NOT NULL,
131 ar_minor_edit CHAR NOT NULL DEFAULT '0',
132 ar_flags TEXT,
133 ar_rev_id INTEGER,
134 ar_text_id INTEGER
135 );
136 CREATE INDEX archive_name_title_timestamp ON archive2 (ar_namespace,ar_title,ar_timestamp);
137
138 -- This is the easiest way to work around the char(15) timestamp hack without modifying PHP code
139 CREATE VIEW archive AS
140 SELECT
141 ar_namespace, ar_title, ar_text, ar_comment, ar_user, ar_user_text,
142 ar_minor_edit, ar_flags, ar_rev_id, ar_text_id,
143 TO_CHAR(ar_timestamp, 'YYYYMMDDHH24MISS') AS ar_timestamp
144 FROM archive2;
145
146 CREATE RULE archive_insert AS ON INSERT TO archive
147 DO INSTEAD INSERT INTO archive2 VALUES (
148 NEW.ar_namespace, NEW.ar_title, NEW.ar_text, NEW.ar_comment, NEW.ar_user, NEW.ar_user_text,
149 TO_TIMESTAMP(NEW.ar_timestamp, 'YYYYMMDDHH24MISS'),
150 NEW.ar_minor_edit, NEW.ar_flags, NEW.ar_rev_id, NEW.ar_text_id
151 );
152
153 CREATE RULE archive_delete AS ON DELETE TO archive
154 DO INSTEAD DELETE FROM archive2 a2 WHERE
155 a2.ar_title = OLD.ar_title AND
156 a2.ar_namespace = OLD.ar_namespace AND
157 a2.ar_rev_id = OLD.ar_rev_id;
158
159
160 CREATE TABLE redirect (
161 rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
162 rd_namespace SMALLINT NOT NULL,
163 rd_title TEXT NOT NULL
164 );
165 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
166
167
168 CREATE TABLE pagelinks (
169 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
170 pl_namespace SMALLINT NOT NULL,
171 pl_title TEXT NOT NULL
172 );
173 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
174
175 CREATE TABLE templatelinks (
176 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
177 tl_namespace TEXT NOT NULL,
178 tl_title TEXT NOT NULL
179 );
180 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
181
182 CREATE TABLE imagelinks (
183 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
184 il_to TEXT NOT NULL
185 );
186 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
187
188 CREATE TABLE categorylinks (
189 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
190 cl_to TEXT NOT NULL,
191 cl_sortkey TEXT,
192 cl_timestamp TIMESTAMPTZ NOT NULL
193 );
194 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
195 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey);
196
197 CREATE TABLE externallinks (
198 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
199 el_to TEXT NOT NULL,
200 el_index TEXT NOT NULL
201 );
202 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
203 CREATE INDEX externallinks_index ON externallinks (el_index);
204
205 CREATE TABLE langlinks (
206 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
207 ll_lang TEXT,
208 ll_title TEXT
209 );
210 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
211 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
212
213
214 CREATE TABLE site_stats (
215 ss_row_id INTEGER NOT NULL UNIQUE,
216 ss_total_views INTEGER DEFAULT 0,
217 ss_total_edits INTEGER DEFAULT 0,
218 ss_good_articles INTEGER DEFAULT 0,
219 ss_total_pages INTEGER DEFAULT -1,
220 ss_users INTEGER DEFAULT -1,
221 ss_admins INTEGER DEFAULT -1,
222 ss_images INTEGER DEFAULT 0
223 );
224
225 CREATE TABLE hitcounter (
226 hc_id BIGINT NOT NULL
227 );
228
229
230 CREATE SEQUENCE ipblocks_ipb_id_val;
231 CREATE TABLE ipblocks (
232 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_val'),
233 ipb_address TEXT NULL,
234 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
235 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
236 ipb_reason TEXT NOT NULL,
237 ipb_timestamp TIMESTAMPTZ NOT NULL,
238 ipb_auto CHAR NOT NULL DEFAULT '0',
239 ipb_anon_only CHAR NOT NULL DEFAULT '0',
240 ipb_create_account CHAR NOT NULL DEFAULT '1',
241 ipb_enable_autoblock CHAR NOT NULL DEFAULT '1',
242 ipb_expiry TIMESTAMPTZ NOT NULL,
243 ipb_range_start TEXT,
244 ipb_range_end TEXT
245 );
246 CREATE INDEX ipb_address ON ipblocks (ipb_address);
247 CREATE INDEX ipb_user ON ipblocks (ipb_user);
248 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
249
250
251 CREATE TABLE image (
252 img_name TEXT NOT NULL PRIMARY KEY,
253 img_size INTEGER NOT NULL,
254 img_width INTEGER NOT NULL,
255 img_height INTEGER NOT NULL,
256 img_metadata TEXT,
257 img_bits SMALLINT,
258 img_media_type TEXT,
259 img_major_mime TEXT DEFAULT 'unknown',
260 img_minor_mime TEXT DEFAULT 'unknown',
261 img_description TEXT NOT NULL,
262 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
263 img_user_text TEXT NOT NULL,
264 img_timestamp TIMESTAMPTZ
265 );
266 CREATE INDEX img_size_idx ON image (img_size);
267 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
268
269 CREATE TABLE oldimage (
270 oi_name TEXT NOT NULL REFERENCES image(img_name),
271 oi_archive_name TEXT NOT NULL,
272 oi_size INTEGER NOT NULL,
273 oi_width INTEGER NOT NULL,
274 oi_height INTEGER NOT NULL,
275 oi_bits SMALLINT NOT NULL,
276 oi_description TEXT,
277 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
278 oi_user_text TEXT NOT NULL,
279 oi_timestamp TIMESTAMPTZ NOT NULL
280 );
281 CREATE INDEX oi_name ON oldimage (oi_name);
282
283
284 CREATE TABLE filearchive (
285 fa_id SERIAL NOT NULL PRIMARY KEY,
286 fa_name TEXT NOT NULL,
287 fa_archive_name TEXT,
288 fa_storage_group VARCHAR(16),
289 fa_storage_key CHAR(64),
290 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
291 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
292 fa_deleted_reason TEXT,
293 fa_size SMALLINT NOT NULL,
294 fa_width SMALLINT NOT NULL,
295 fa_height SMALLINT NOT NULL,
296 fa_metadata TEXT,
297 fa_bits SMALLINT,
298 fa_media_type TEXT,
299 fa_major_mime TEXT DEFAULT 'unknown',
300 fa_minor_mime TEXT DEFAULT 'unknown',
301 fa_description TEXT NOT NULL,
302 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
303 fa_user_text TEXT NOT NULL,
304 fa_timestamp TIMESTAMPTZ
305 );
306 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
307 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
308 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
309 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
310
311
312 CREATE SEQUENCE rc_rc_id_seq;
313 CREATE TABLE recentchanges (
314 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
315 rc_timestamp TIMESTAMPTZ NOT NULL,
316 rc_cur_time TIMESTAMPTZ NOT NULL,
317 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
318 rc_user_text TEXT NOT NULL,
319 rc_namespace SMALLINT NOT NULL,
320 rc_title TEXT NOT NULL,
321 rc_comment TEXT,
322 rc_minor CHAR NOT NULL DEFAULT '0',
323 rc_bot CHAR NOT NULL DEFAULT '0',
324 rc_new CHAR NOT NULL DEFAULT '0',
325 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL,
326 rc_this_oldid INTEGER NOT NULL,
327 rc_last_oldid INTEGER NOT NULL,
328 rc_type CHAR NOT NULL DEFAULT '0',
329 rc_moved_to_ns SMALLINT,
330 rc_moved_to_title TEXT,
331 rc_patrolled CHAR NOT NULL DEFAULT '0',
332 rc_ip CIDR,
333 rc_old_len INTEGER,
334 rc_new_len INTEGER
335 );
336 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
337 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
338 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
339 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
340 CREATE INDEX rc_ip ON recentchanges (rc_ip);
341
342
343 CREATE TABLE watchlist (
344 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
345 wl_namespace SMALLINT NOT NULL DEFAULT 0,
346 wl_title TEXT NOT NULL,
347 wl_notificationtimestamp TIMESTAMPTZ
348 );
349 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
350
351
352 CREATE TABLE math (
353 math_inputhash TEXT NOT NULL UNIQUE,
354 math_outputhash TEXT NOT NULL,
355 math_html_conservativeness SMALLINT NOT NULL,
356 math_html TEXT,
357 math_mathml TEXT
358 );
359
360
361 CREATE TABLE interwiki (
362 iw_prefix TEXT NOT NULL UNIQUE,
363 iw_url TEXT NOT NULL,
364 iw_local CHAR NOT NULL,
365 iw_trans CHAR NOT NULL DEFAULT '0'
366 );
367
368
369 CREATE TABLE querycache (
370 qc_type TEXT NOT NULL,
371 qc_value SMALLINT NOT NULL,
372 qc_namespace SMALLINT NOT NULL,
373 qc_title TEXT NOT NULL
374 );
375 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
376
377 CREATE TABLE querycache_info (
378 qci_type TEXT UNIQUE,
379 qci_timestamp TIMESTAMPTZ NULL
380 );
381
382 CREATE TABLE querycachetwo (
383 qcc_type TEXT NOT NULL,
384 qcc_value SMALLINT NOT NULL DEFAULT 0,
385 qcc_namespace INTEGER NOT NULL DEFAULT 0,
386 qcc_title TEXT NOT NULL DEFAULT '',
387 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
388 qcc_titletwo TEXT NOT NULL DEFAULT ''
389 );
390 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
391 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
392 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
393
394
395 CREATE TABLE objectcache (
396 keyname CHAR(255) UNIQUE,
397 value BYTEA NOT NULL DEFAULT '',
398 exptime TIMESTAMPTZ NOT NULL
399 );
400 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
401
402 CREATE TABLE transcache (
403 tc_url TEXT NOT NULL UNIQUE,
404 tc_contents TEXT NOT NULL,
405 tc_time TIMESTAMPTZ NOT NULL
406 );
407
408
409 CREATE TABLE logging (
410 log_type TEXT NOT NULL,
411 log_action TEXT NOT NULL,
412 log_timestamp TIMESTAMPTZ NOT NULL,
413 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL,
414 log_namespace SMALLINT NOT NULL,
415 log_title TEXT NOT NULL,
416 log_comment TEXT,
417 log_params TEXT
418 );
419 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
420 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
421 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
422
423
424 CREATE TABLE trackbacks (
425 tb_id SERIAL NOT NULL PRIMARY KEY,
426 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
427 tb_title TEXT NOT NULL,
428 tb_url TEXT NOT NULL,
429 tb_ex TEXT,
430 tb_name TEXT
431 );
432 CREATE INDEX trackback_page ON trackbacks (tb_page);
433
434
435 CREATE SEQUENCE job_job_id_seq;
436 CREATE TABLE job (
437 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
438 job_cmd TEXT NOT NULL,
439 job_namespace SMALLINT NOT NULL,
440 job_title TEXT NOT NULL,
441 job_params TEXT NOT NULL
442 );
443 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
444
445 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
446
447 ALTER TABLE page ADD titlevector tsvector;
448 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
449 $mw$
450 BEGIN
451 IF TG_OP = 'INSERT' THEN
452 NEW.titlevector = to_tsvector('default',NEW.page_title);
453 ELSIF NEW.page_title != OLD.page_title THEN
454 NEW.titlevector := to_tsvector('default',NEW.page_title);
455 END IF;
456 RETURN NEW;
457 END;
458 $mw$;
459
460 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
461 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
462
463
464 ALTER TABLE pagecontent ADD textvector tsvector;
465 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
466 $mw$
467 BEGIN
468 IF TG_OP = 'INSERT' THEN
469 NEW.textvector = to_tsvector('default',NEW.old_text);
470 ELSIF NEW.old_text != OLD.old_text THEN
471 NEW.textvector := to_tsvector('default',NEW.old_text);
472 END IF;
473 RETURN NEW;
474 END;
475 $mw$;
476
477 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
478 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
479
480 -- These are added by the setup script due to version compatibility issues
481 -- If using 8.1, switch from "gin" to "gist"
482 -- CREATE INDEX ts2_page_title ON page USING gin(titlevector);
483 -- CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
484
485 CREATE FUNCTION add_interwiki (TEXT,INT,CHAR) RETURNS INT LANGUAGE SQL AS
486 $mw$
487 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
488 SELECT 1;
489 $mw$;
490
491 -- This table is not used unless profiling is turned on
492 CREATE TABLE profiling (
493 pf_count INTEGER NOT NULL DEFAULT 0,
494 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
495 pf_name TEXT NOT NULL,
496 pf_server TEXT NULL
497 );
498 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
499
500
501 CREATE TABLE mediawiki_version (
502 type TEXT NOT NULL,
503 mw_version TEXT NOT NULL,
504 notes TEXT NULL,
505
506 pg_version TEXT NULL,
507 pg_dbname TEXT NULL,
508 pg_user TEXT NULL,
509 pg_port TEXT NULL,
510 mw_schema TEXT NULL,
511 ts2_schema TEXT NULL,
512 ctype TEXT NULL,
513
514 sql_version TEXT NULL,
515 sql_date TEXT NULL,
516 cdate TIMESTAMPTZ NOT NULL DEFAULT now()
517 );
518
519 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
520 VALUES ('Creation','??','$LastChangedRevision$','$LastChangedDate$');
521
522
523 COMMIT;