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