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