bdbf2e180a3d8315654cad79ca457edfea6bfc03
[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 rev_len INTEGER NULL
97 );
98 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
99 CREATE INDEX rev_text_id_idx ON revision (rev_text_id);
100 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
101 CREATE INDEX rev_user_idx ON revision (rev_user);
102 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
103
104
105 CREATE SEQUENCE text_old_id_val;
106 CREATE TABLE pagecontent ( -- replaces reserved word 'text'
107 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_val'),
108 old_text TEXT,
109 old_flags TEXT
110 );
111
112
113 CREATE SEQUENCE pr_id_val;
114 CREATE TABLE page_restrictions (
115 pr_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('pr_id_val'),
116 pr_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE,
117 pr_type TEXT NOT NULL,
118 pr_level TEXT NOT NULL,
119 pr_cascade SMALLINT NOT NULL,
120 pr_user INTEGER NULL,
121 pr_expiry TIMESTAMPTZ NULL
122 );
123 CREATE UNIQUE INDEX pr_pagetype ON page_restrictions (pr_page,pr_type);
124
125
126 CREATE TABLE archive2 (
127 ar_namespace SMALLINT NOT NULL,
128 ar_title TEXT NOT NULL,
129 ar_text TEXT,
130 ar_comment TEXT,
131 ar_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
132 ar_user_text TEXT NOT NULL,
133 ar_timestamp TIMESTAMPTZ NOT NULL,
134 ar_minor_edit CHAR NOT NULL DEFAULT '0',
135 ar_flags TEXT,
136 ar_rev_id INTEGER,
137 ar_text_id INTEGER
138 );
139 CREATE INDEX archive_name_title_timestamp ON archive2 (ar_namespace,ar_title,ar_timestamp);
140
141 -- This is the easiest way to work around the char(15) timestamp hack without modifying PHP code
142 CREATE VIEW archive AS
143 SELECT
144 ar_namespace, ar_title, ar_text, ar_comment, ar_user, ar_user_text,
145 ar_minor_edit, ar_flags, ar_rev_id, ar_text_id,
146 TO_CHAR(ar_timestamp, 'YYYYMMDDHH24MISS') AS ar_timestamp
147 FROM archive2;
148
149 CREATE RULE archive_insert AS ON INSERT TO archive
150 DO INSTEAD INSERT INTO archive2 VALUES (
151 NEW.ar_namespace, NEW.ar_title, NEW.ar_text, NEW.ar_comment, NEW.ar_user, NEW.ar_user_text,
152 TO_TIMESTAMP(NEW.ar_timestamp, 'YYYYMMDDHH24MISS'),
153 NEW.ar_minor_edit, NEW.ar_flags, NEW.ar_rev_id, NEW.ar_text_id
154 );
155
156 CREATE RULE archive_delete AS ON DELETE TO archive
157 DO INSTEAD DELETE FROM archive2 WHERE
158 archive2.ar_title = OLD.ar_title AND
159 archive2.ar_namespace = OLD.ar_namespace AND
160 archive2.ar_rev_id = OLD.ar_rev_id;
161
162
163 CREATE TABLE redirect (
164 rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
165 rd_namespace SMALLINT NOT NULL,
166 rd_title TEXT NOT NULL
167 );
168 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
169
170
171 CREATE TABLE pagelinks (
172 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
173 pl_namespace SMALLINT NOT NULL,
174 pl_title TEXT NOT NULL
175 );
176 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
177
178 CREATE TABLE templatelinks (
179 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
180 tl_namespace TEXT NOT NULL,
181 tl_title TEXT NOT NULL
182 );
183 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
184
185 CREATE TABLE imagelinks (
186 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
187 il_to TEXT NOT NULL
188 );
189 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
190
191 CREATE TABLE categorylinks (
192 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
193 cl_to TEXT NOT NULL,
194 cl_sortkey TEXT,
195 cl_timestamp TIMESTAMPTZ NOT NULL
196 );
197 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
198 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey);
199
200 CREATE TABLE externallinks (
201 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
202 el_to TEXT NOT NULL,
203 el_index TEXT NOT NULL
204 );
205 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
206 CREATE INDEX externallinks_index ON externallinks (el_index);
207
208 CREATE TABLE langlinks (
209 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
210 ll_lang TEXT,
211 ll_title TEXT
212 );
213 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
214 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
215
216
217 CREATE TABLE site_stats (
218 ss_row_id INTEGER NOT NULL UNIQUE,
219 ss_total_views INTEGER DEFAULT 0,
220 ss_total_edits INTEGER DEFAULT 0,
221 ss_good_articles INTEGER DEFAULT 0,
222 ss_total_pages INTEGER DEFAULT -1,
223 ss_users INTEGER DEFAULT -1,
224 ss_admins INTEGER DEFAULT -1,
225 ss_images INTEGER DEFAULT 0
226 );
227
228 CREATE TABLE hitcounter (
229 hc_id BIGINT NOT NULL
230 );
231
232
233 CREATE SEQUENCE ipblocks_ipb_id_val;
234 CREATE TABLE ipblocks (
235 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_val'),
236 ipb_address TEXT NULL,
237 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
238 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
239 ipb_reason TEXT NOT NULL,
240 ipb_timestamp TIMESTAMPTZ NOT NULL,
241 ipb_auto CHAR NOT NULL DEFAULT '0',
242 ipb_anon_only CHAR NOT NULL DEFAULT '0',
243 ipb_create_account CHAR NOT NULL DEFAULT '1',
244 ipb_enable_autoblock CHAR NOT NULL DEFAULT '1',
245 ipb_expiry TIMESTAMPTZ NOT NULL,
246 ipb_range_start TEXT,
247 ipb_range_end TEXT
248 );
249 CREATE INDEX ipb_address ON ipblocks (ipb_address);
250 CREATE INDEX ipb_user ON ipblocks (ipb_user);
251 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
252
253
254 CREATE TABLE image (
255 img_name TEXT NOT NULL PRIMARY KEY,
256 img_size INTEGER NOT NULL,
257 img_width INTEGER NOT NULL,
258 img_height INTEGER NOT NULL,
259 img_metadata TEXT,
260 img_bits SMALLINT,
261 img_media_type TEXT,
262 img_major_mime TEXT DEFAULT 'unknown',
263 img_minor_mime TEXT DEFAULT 'unknown',
264 img_description TEXT NOT NULL,
265 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
266 img_user_text TEXT NOT NULL,
267 img_timestamp TIMESTAMPTZ
268 );
269 CREATE INDEX img_size_idx ON image (img_size);
270 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
271
272 CREATE TABLE oldimage (
273 oi_name TEXT NOT NULL REFERENCES image(img_name),
274 oi_archive_name TEXT NOT NULL,
275 oi_size INTEGER NOT NULL,
276 oi_width INTEGER NOT NULL,
277 oi_height INTEGER NOT NULL,
278 oi_bits SMALLINT NOT NULL,
279 oi_description TEXT,
280 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
281 oi_user_text TEXT NOT NULL,
282 oi_timestamp TIMESTAMPTZ NOT NULL
283 );
284 CREATE INDEX oi_name ON oldimage (oi_name);
285
286
287 CREATE TABLE filearchive (
288 fa_id SERIAL NOT NULL PRIMARY KEY,
289 fa_name TEXT NOT NULL,
290 fa_archive_name TEXT,
291 fa_storage_group VARCHAR(16),
292 fa_storage_key CHAR(64),
293 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
294 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
295 fa_deleted_reason TEXT,
296 fa_size SMALLINT NOT NULL,
297 fa_width SMALLINT NOT NULL,
298 fa_height SMALLINT NOT NULL,
299 fa_metadata TEXT,
300 fa_bits SMALLINT,
301 fa_media_type TEXT,
302 fa_major_mime TEXT DEFAULT 'unknown',
303 fa_minor_mime TEXT DEFAULT 'unknown',
304 fa_description TEXT NOT NULL,
305 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
306 fa_user_text TEXT NOT NULL,
307 fa_timestamp TIMESTAMPTZ
308 );
309 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
310 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
311 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
312 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
313
314
315 CREATE SEQUENCE rc_rc_id_seq;
316 CREATE TABLE recentchanges (
317 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
318 rc_timestamp TIMESTAMPTZ NOT NULL,
319 rc_cur_time TIMESTAMPTZ NOT NULL,
320 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
321 rc_user_text TEXT NOT NULL,
322 rc_namespace SMALLINT NOT NULL,
323 rc_title TEXT NOT NULL,
324 rc_comment TEXT,
325 rc_minor CHAR NOT NULL DEFAULT '0',
326 rc_bot CHAR NOT NULL DEFAULT '0',
327 rc_new CHAR NOT NULL DEFAULT '0',
328 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL,
329 rc_this_oldid INTEGER NOT NULL,
330 rc_last_oldid INTEGER NOT NULL,
331 rc_type CHAR NOT NULL DEFAULT '0',
332 rc_moved_to_ns SMALLINT,
333 rc_moved_to_title TEXT,
334 rc_patrolled CHAR NOT NULL DEFAULT '0',
335 rc_ip CIDR,
336 rc_old_len INTEGER,
337 rc_new_len INTEGER
338 );
339 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
340 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
341 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
342 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
343 CREATE INDEX rc_ip ON recentchanges (rc_ip);
344
345
346 CREATE TABLE watchlist (
347 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
348 wl_namespace SMALLINT NOT NULL DEFAULT 0,
349 wl_title TEXT NOT NULL,
350 wl_notificationtimestamp TIMESTAMPTZ
351 );
352 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
353
354
355 CREATE TABLE math (
356 math_inputhash TEXT NOT NULL UNIQUE,
357 math_outputhash TEXT NOT NULL,
358 math_html_conservativeness SMALLINT NOT NULL,
359 math_html TEXT,
360 math_mathml TEXT
361 );
362
363
364 CREATE TABLE interwiki (
365 iw_prefix TEXT NOT NULL UNIQUE,
366 iw_url TEXT NOT NULL,
367 iw_local CHAR NOT NULL,
368 iw_trans CHAR NOT NULL DEFAULT '0'
369 );
370
371
372 CREATE TABLE querycache (
373 qc_type TEXT NOT NULL,
374 qc_value SMALLINT NOT NULL,
375 qc_namespace SMALLINT NOT NULL,
376 qc_title TEXT NOT NULL
377 );
378 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
379
380 CREATE TABLE querycache_info (
381 qci_type TEXT UNIQUE,
382 qci_timestamp TIMESTAMPTZ NULL
383 );
384
385 CREATE TABLE querycachetwo (
386 qcc_type TEXT NOT NULL,
387 qcc_value SMALLINT NOT NULL DEFAULT 0,
388 qcc_namespace INTEGER NOT NULL DEFAULT 0,
389 qcc_title TEXT NOT NULL DEFAULT '',
390 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
391 qcc_titletwo TEXT NOT NULL DEFAULT ''
392 );
393 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
394 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
395 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
396
397
398 CREATE TABLE objectcache (
399 keyname CHAR(255) UNIQUE,
400 value BYTEA NOT NULL DEFAULT '',
401 exptime TIMESTAMPTZ NOT NULL
402 );
403 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
404
405 CREATE TABLE transcache (
406 tc_url TEXT NOT NULL UNIQUE,
407 tc_contents TEXT NOT NULL,
408 tc_time TIMESTAMPTZ NOT NULL
409 );
410
411
412 CREATE TABLE logging (
413 log_type TEXT NOT NULL,
414 log_action TEXT NOT NULL,
415 log_timestamp TIMESTAMPTZ NOT NULL,
416 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL,
417 log_namespace SMALLINT NOT NULL,
418 log_title TEXT NOT NULL,
419 log_comment TEXT,
420 log_params TEXT
421 );
422 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
423 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
424 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
425
426
427 CREATE TABLE trackbacks (
428 tb_id SERIAL NOT NULL PRIMARY KEY,
429 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
430 tb_title TEXT NOT NULL,
431 tb_url TEXT NOT NULL,
432 tb_ex TEXT,
433 tb_name TEXT
434 );
435 CREATE INDEX trackback_page ON trackbacks (tb_page);
436
437
438 CREATE SEQUENCE job_job_id_seq;
439 CREATE TABLE job (
440 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
441 job_cmd TEXT NOT NULL,
442 job_namespace SMALLINT NOT NULL,
443 job_title TEXT NOT NULL,
444 job_params TEXT NOT NULL
445 );
446 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
447
448 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
449
450 ALTER TABLE page ADD titlevector tsvector;
451 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
452 $mw$
453 BEGIN
454 IF TG_OP = 'INSERT' THEN
455 NEW.titlevector = to_tsvector('default',NEW.page_title);
456 ELSIF NEW.page_title != OLD.page_title THEN
457 NEW.titlevector := to_tsvector('default',NEW.page_title);
458 END IF;
459 RETURN NEW;
460 END;
461 $mw$;
462
463 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
464 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
465
466
467 ALTER TABLE pagecontent ADD textvector tsvector;
468 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
469 $mw$
470 BEGIN
471 IF TG_OP = 'INSERT' THEN
472 NEW.textvector = to_tsvector('default',NEW.old_text);
473 ELSIF NEW.old_text != OLD.old_text THEN
474 NEW.textvector := to_tsvector('default',NEW.old_text);
475 END IF;
476 RETURN NEW;
477 END;
478 $mw$;
479
480 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
481 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
482
483 -- These are added by the setup script due to version compatibility issues
484 -- If using 8.1, switch from "gin" to "gist"
485 -- CREATE INDEX ts2_page_title ON page USING gin(titlevector);
486 -- CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
487
488 CREATE FUNCTION add_interwiki (TEXT,INT,CHAR) RETURNS INT LANGUAGE SQL AS
489 $mw$
490 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
491 SELECT 1;
492 $mw$;
493
494 -- This table is not used unless profiling is turned on
495 CREATE TABLE profiling (
496 pf_count INTEGER NOT NULL DEFAULT 0,
497 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
498 pf_name TEXT NOT NULL,
499 pf_server TEXT NULL
500 );
501 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
502
503
504 CREATE TABLE mediawiki_version (
505 type TEXT NOT NULL,
506 mw_version TEXT NOT NULL,
507 notes TEXT NULL,
508
509 pg_version TEXT NULL,
510 pg_dbname TEXT NULL,
511 pg_user TEXT NULL,
512 pg_port TEXT NULL,
513 mw_schema TEXT NULL,
514 ts2_schema TEXT NULL,
515 ctype TEXT NULL,
516
517 sql_version TEXT NULL,
518 sql_date TEXT NULL,
519 cdate TIMESTAMPTZ NOT NULL DEFAULT now()
520 );
521
522 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
523 VALUES ('Creation','??','$LastChangedRevision$','$LastChangedDate$');
524
525
526 COMMIT;