0bea5f86ffd9b4b8b71332affbeb8086a293b937
[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 CIDR 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
154 CREATE TABLE redirect (
155 rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
156 rd_namespace SMALLINT NOT NULL,
157 rd_title TEXT NOT NULL
158 );
159 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
160
161
162 CREATE TABLE pagelinks (
163 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
164 pl_namespace SMALLINT NOT NULL,
165 pl_title TEXT NOT NULL
166 );
167 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
168
169 CREATE TABLE templatelinks (
170 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
171 tl_namespace TEXT NOT NULL,
172 tl_title TEXT NOT NULL
173 );
174 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
175
176 CREATE TABLE imagelinks (
177 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
178 il_to TEXT NOT NULL
179 );
180 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
181
182 CREATE TABLE categorylinks (
183 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
184 cl_to TEXT NOT NULL,
185 cl_sortkey TEXT,
186 cl_timestamp TIMESTAMPTZ NOT NULL
187 );
188 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
189 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey);
190
191 CREATE TABLE externallinks (
192 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
193 el_to TEXT NOT NULL,
194 el_index TEXT NOT NULL
195 );
196 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
197 CREATE INDEX externallinks_index ON externallinks (el_index);
198
199 CREATE TABLE langlinks (
200 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
201 ll_lang TEXT,
202 ll_title TEXT
203 );
204 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
205 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
206
207
208 CREATE TABLE site_stats (
209 ss_row_id INTEGER NOT NULL UNIQUE,
210 ss_total_views INTEGER DEFAULT 0,
211 ss_total_edits INTEGER DEFAULT 0,
212 ss_good_articles INTEGER DEFAULT 0,
213 ss_total_pages INTEGER DEFAULT -1,
214 ss_users INTEGER DEFAULT -1,
215 ss_admins INTEGER DEFAULT -1,
216 ss_images INTEGER DEFAULT 0
217 );
218
219 CREATE TABLE hitcounter (
220 hc_id BIGINT NOT NULL
221 );
222
223
224 CREATE SEQUENCE ipblocks_ipb_id_val;
225 CREATE TABLE ipblocks (
226 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_val'),
227 ipb_address TEXT NULL,
228 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
229 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
230 ipb_reason TEXT NOT NULL,
231 ipb_timestamp TIMESTAMPTZ NOT NULL,
232 ipb_auto CHAR NOT NULL DEFAULT '0',
233 ipb_anon_only CHAR NOT NULL DEFAULT '0',
234 ipb_create_account CHAR NOT NULL DEFAULT '1',
235 ipb_enable_autoblock CHAR NOT NULL DEFAULT '1',
236 ipb_expiry TIMESTAMPTZ NOT NULL,
237 ipb_range_start TEXT,
238 ipb_range_end TEXT
239 );
240 CREATE INDEX ipb_address ON ipblocks (ipb_address);
241 CREATE INDEX ipb_user ON ipblocks (ipb_user);
242 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
243
244
245 CREATE TABLE image (
246 img_name TEXT NOT NULL PRIMARY KEY,
247 img_size INTEGER NOT NULL,
248 img_width INTEGER NOT NULL,
249 img_height INTEGER NOT NULL,
250 img_metadata TEXT,
251 img_bits SMALLINT,
252 img_media_type TEXT,
253 img_major_mime TEXT DEFAULT 'unknown',
254 img_minor_mime TEXT DEFAULT 'unknown',
255 img_description TEXT NOT NULL,
256 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
257 img_user_text TEXT NOT NULL,
258 img_timestamp TIMESTAMPTZ
259 );
260 CREATE INDEX img_size_idx ON image (img_size);
261 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
262
263 CREATE TABLE oldimage (
264 oi_name TEXT NOT NULL REFERENCES image(img_name),
265 oi_archive_name TEXT NOT NULL,
266 oi_size INTEGER NOT NULL,
267 oi_width INTEGER NOT NULL,
268 oi_height INTEGER NOT NULL,
269 oi_bits SMALLINT NOT NULL,
270 oi_description TEXT,
271 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
272 oi_user_text TEXT NOT NULL,
273 oi_timestamp TIMESTAMPTZ NOT NULL
274 );
275 CREATE INDEX oi_name ON oldimage (oi_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 );
300 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
301 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
302 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
303 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
304
305
306 CREATE SEQUENCE rc_rc_id_seq;
307 CREATE TABLE recentchanges (
308 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
309 rc_timestamp TIMESTAMPTZ NOT NULL,
310 rc_cur_time TIMESTAMPTZ NOT NULL,
311 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
312 rc_user_text TEXT NOT NULL,
313 rc_namespace SMALLINT NOT NULL,
314 rc_title TEXT NOT NULL,
315 rc_comment TEXT,
316 rc_minor CHAR NOT NULL DEFAULT '0',
317 rc_bot CHAR NOT NULL DEFAULT '0',
318 rc_new CHAR NOT NULL DEFAULT '0',
319 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL,
320 rc_this_oldid INTEGER NOT NULL,
321 rc_last_oldid INTEGER NOT NULL,
322 rc_type CHAR NOT NULL DEFAULT '0',
323 rc_moved_to_ns SMALLINT,
324 rc_moved_to_title TEXT,
325 rc_patrolled CHAR NOT NULL DEFAULT '0',
326 rc_ip CIDR,
327 rc_old_len INTEGER,
328 rc_new_len INTEGER
329 );
330 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
331 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
332 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
333 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
334 CREATE INDEX rc_ip ON recentchanges (rc_ip);
335
336
337 CREATE TABLE watchlist (
338 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
339 wl_namespace SMALLINT NOT NULL DEFAULT 0,
340 wl_title TEXT NOT NULL,
341 wl_notificationtimestamp TIMESTAMPTZ
342 );
343 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
344
345
346 CREATE TABLE math (
347 math_inputhash TEXT NOT NULL UNIQUE,
348 math_outputhash TEXT NOT NULL,
349 math_html_conservativeness SMALLINT NOT NULL,
350 math_html TEXT,
351 math_mathml TEXT
352 );
353
354
355 CREATE TABLE interwiki (
356 iw_prefix TEXT NOT NULL UNIQUE,
357 iw_url TEXT NOT NULL,
358 iw_local CHAR NOT NULL,
359 iw_trans CHAR NOT NULL DEFAULT '0'
360 );
361
362
363 CREATE TABLE querycache (
364 qc_type TEXT NOT NULL,
365 qc_value SMALLINT NOT NULL,
366 qc_namespace SMALLINT NOT NULL,
367 qc_title TEXT NOT NULL
368 );
369 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
370
371 CREATE TABLE querycache_info (
372 qci_type TEXT UNIQUE,
373 qci_timestamp TIMESTAMPTZ NULL
374 );
375
376 CREATE TABLE querycachetwo (
377 qcc_type TEXT NOT NULL,
378 qcc_value SMALLINT NOT NULL DEFAULT 0,
379 qcc_namespace INTEGER NOT NULL DEFAULT 0,
380 qcc_title TEXT NOT NULL DEFAULT '',
381 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
382 qcc_titletwo TEXT NOT NULL DEFAULT ''
383 );
384 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
385 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
386 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
387
388
389 CREATE TABLE objectcache (
390 keyname CHAR(255) UNIQUE,
391 value BYTEA NOT NULL DEFAULT '',
392 exptime TIMESTAMPTZ NOT NULL
393 );
394 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
395
396 CREATE TABLE transcache (
397 tc_url TEXT NOT NULL UNIQUE,
398 tc_contents TEXT NOT NULL,
399 tc_time TIMESTAMPTZ NOT NULL
400 );
401
402
403 CREATE TABLE logging (
404 log_type TEXT NOT NULL,
405 log_action TEXT NOT NULL,
406 log_timestamp TIMESTAMPTZ NOT NULL,
407 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL,
408 log_namespace SMALLINT NOT NULL,
409 log_title TEXT NOT NULL,
410 log_comment TEXT,
411 log_params TEXT
412 );
413 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
414 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
415 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
416
417
418 CREATE TABLE trackbacks (
419 tb_id SERIAL NOT NULL PRIMARY KEY,
420 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
421 tb_title TEXT NOT NULL,
422 tb_url TEXT NOT NULL,
423 tb_ex TEXT,
424 tb_name TEXT
425 );
426 CREATE INDEX trackback_page ON trackbacks (tb_page);
427
428
429 CREATE SEQUENCE job_job_id_seq;
430 CREATE TABLE job (
431 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
432 job_cmd TEXT NOT NULL,
433 job_namespace SMALLINT NOT NULL,
434 job_title TEXT NOT NULL,
435 job_params TEXT NOT NULL
436 );
437 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
438
439 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
440
441 ALTER TABLE page ADD titlevector tsvector;
442 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
443 $mw$
444 BEGIN
445 IF TG_OP = 'INSERT' THEN
446 NEW.titlevector = to_tsvector('default',NEW.page_title);
447 ELSIF NEW.page_title != OLD.page_title THEN
448 NEW.titlevector := to_tsvector('default',NEW.page_title);
449 END IF;
450 RETURN NEW;
451 END;
452 $mw$;
453
454 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
455 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
456
457
458 ALTER TABLE pagecontent ADD textvector tsvector;
459 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
460 $mw$
461 BEGIN
462 IF TG_OP = 'INSERT' THEN
463 NEW.textvector = to_tsvector('default',NEW.old_text);
464 ELSIF NEW.old_text != OLD.old_text THEN
465 NEW.textvector := to_tsvector('default',NEW.old_text);
466 END IF;
467 RETURN NEW;
468 END;
469 $mw$;
470
471 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
472 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
473
474 -- These are added by the setup script due to version compatibility issues
475 -- If using 8.1, switch from "gin" to "gist"
476 -- CREATE INDEX ts2_page_title ON page USING gin(titlevector);
477 -- CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
478
479 CREATE FUNCTION add_interwiki (TEXT,INT,CHAR) RETURNS INT LANGUAGE SQL AS
480 $mw$
481 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
482 SELECT 1;
483 $mw$;
484
485 -- This table is not used unless profiling is turned on
486 CREATE TABLE profiling (
487 pf_count INTEGER NOT NULL DEFAULT 0,
488 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
489 pf_name TEXT NOT NULL,
490 pf_server TEXT NULL
491 );
492 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
493
494
495 CREATE TABLE mediawiki_version (
496 type TEXT NOT NULL,
497 mw_version TEXT NOT NULL,
498 notes TEXT NULL,
499
500 pg_version TEXT NULL,
501 pg_dbname TEXT NULL,
502 pg_user TEXT NULL,
503 pg_port TEXT NULL,
504 mw_schema TEXT NULL,
505 ts2_schema TEXT NULL,
506 ctype TEXT NULL,
507
508 sql_version TEXT NULL,
509 sql_date TEXT NULL,
510 cdate TIMESTAMPTZ NOT NULL DEFAULT now()
511 );
512
513 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
514 VALUES ('Creation','??','$LastChangedRevision$','$LastChangedDate$');
515
516
517 COMMIT;