tables.sql 31 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750
  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. -- TODO: Change CHAR/SMALLINT to BOOL (still used in a non-bool fashion in PHP code)
  8. BEGIN;
  9. SET client_min_messages = 'ERROR';
  10. DROP SEQUENCE IF EXISTS user_user_id_seq CASCADE;
  11. DROP SEQUENCE IF EXISTS page_page_id_seq CASCADE;
  12. DROP SEQUENCE IF EXISTS revision_rev_id_seq CASCADE;
  13. DROP SEQUENCE IF EXISTS text_old_id_seq CASCADE;
  14. DROP SEQUENCE IF EXISTS page_restrictions_pr_id_seq CASCADE;
  15. DROP SEQUENCE IF EXISTS ipblocks_ipb_id_seq CASCADE;
  16. DROP SEQUENCE IF EXISTS filearchive_fa_id_seq CASCADE;
  17. DROP SEQUENCE IF EXISTS uploadstash_us_id_seq CASCADE;
  18. DROP SEQUENCE IF EXISTS recentchanges_rc_id_seq CASCADE;
  19. DROP SEQUENCE IF EXISTS watchlist_wl_id_seq CASCADE;
  20. DROP SEQUENCE IF EXISTS logging_log_id_seq CASCADE;
  21. DROP SEQUENCE IF EXISTS job_job_id_seq CASCADE;
  22. DROP SEQUENCE IF EXISTS category_cat_id_seq CASCADE;
  23. DROP SEQUENCE IF EXISTS archive_ar_id_seq CASCADE;
  24. DROP SEQUENCE IF EXISTS externallinks_el_id_seq CASCADE;
  25. DROP SEQUENCE IF EXISTS sites_site_id_seq CASCADE;
  26. DROP SEQUENCE IF EXISTS change_tag_ct_id_seq CASCADE;
  27. DROP SEQUENCE IF EXISTS tag_summary_ts_id_seq CASCADE;
  28. DROP FUNCTION IF EXISTS page_deleted() CASCADE;
  29. DROP FUNCTION IF EXISTS ts2_page_title() CASCADE;
  30. DROP FUNCTION IF EXISTS ts2_page_text() CASCADE;
  31. DROP FUNCTION IF EXISTS add_interwiki(TEXT,INT,SMALLINT) CASCADE;
  32. DROP TYPE IF EXISTS media_type CASCADE;
  33. CREATE SEQUENCE user_user_id_seq MINVALUE 0 START WITH 0;
  34. CREATE TABLE mwuser ( -- replace reserved word 'user'
  35. user_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('user_user_id_seq'),
  36. user_name TEXT NOT NULL UNIQUE,
  37. user_real_name TEXT,
  38. user_password TEXT,
  39. user_newpassword TEXT,
  40. user_newpass_time TIMESTAMPTZ,
  41. user_token TEXT,
  42. user_email TEXT,
  43. user_email_token TEXT,
  44. user_email_token_expires TIMESTAMPTZ,
  45. user_email_authenticated TIMESTAMPTZ,
  46. user_touched TIMESTAMPTZ,
  47. user_registration TIMESTAMPTZ,
  48. user_editcount INTEGER,
  49. user_password_expires TIMESTAMPTZ NULL
  50. );
  51. CREATE INDEX user_email_token_idx ON mwuser (user_email_token);
  52. -- Create a dummy user to satisfy fk contraints especially with revisions
  53. INSERT INTO mwuser
  54. VALUES (DEFAULT,'Anonymous','',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,now(),now());
  55. CREATE TABLE user_groups (
  56. ug_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  57. ug_group TEXT NOT NULL
  58. );
  59. CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
  60. CREATE TABLE user_former_groups (
  61. ufg_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  62. ufg_group TEXT NOT NULL
  63. );
  64. CREATE UNIQUE INDEX ufg_user_group ON user_former_groups (ufg_user, ufg_group);
  65. CREATE TABLE user_newtalk (
  66. user_id INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  67. user_ip TEXT NULL,
  68. user_last_timestamp TIMESTAMPTZ
  69. );
  70. CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
  71. CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
  72. CREATE TABLE bot_passwords (
  73. bp_user INTEGER NOT NULL,
  74. bp_app_id TEXT NOT NULL,
  75. bp_password TEXT NOT NULL,
  76. bp_token TEXT NOT NULL,
  77. bp_restrictions TEXT NOT NULL,
  78. bp_grants TEXT NOT NULL,
  79. PRIMARY KEY ( bp_user, bp_app_id )
  80. );
  81. CREATE SEQUENCE page_page_id_seq;
  82. CREATE TABLE page (
  83. page_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('page_page_id_seq'),
  84. page_namespace SMALLINT NOT NULL,
  85. page_title TEXT NOT NULL,
  86. page_restrictions TEXT,
  87. page_is_redirect SMALLINT NOT NULL DEFAULT 0,
  88. page_is_new SMALLINT NOT NULL DEFAULT 0,
  89. page_random NUMERIC(15,14) NOT NULL DEFAULT RANDOM(),
  90. page_touched TIMESTAMPTZ,
  91. page_links_updated TIMESTAMPTZ NULL,
  92. page_latest INTEGER NOT NULL, -- FK?
  93. page_len INTEGER NOT NULL,
  94. page_content_model TEXT,
  95. page_lang TEXT DEFAULT NULL
  96. );
  97. CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
  98. CREATE INDEX page_main_title ON page (page_title text_pattern_ops) WHERE page_namespace = 0;
  99. CREATE INDEX page_talk_title ON page (page_title text_pattern_ops) WHERE page_namespace = 1;
  100. CREATE INDEX page_user_title ON page (page_title text_pattern_ops) WHERE page_namespace = 2;
  101. CREATE INDEX page_utalk_title ON page (page_title text_pattern_ops) WHERE page_namespace = 3;
  102. CREATE INDEX page_project_title ON page (page_title text_pattern_ops) WHERE page_namespace = 4;
  103. CREATE INDEX page_mediawiki_title ON page (page_title text_pattern_ops) WHERE page_namespace = 8;
  104. CREATE INDEX page_random_idx ON page (page_random);
  105. CREATE INDEX page_len_idx ON page (page_len);
  106. CREATE FUNCTION page_deleted() RETURNS TRIGGER LANGUAGE plpgsql AS
  107. $mw$
  108. BEGIN
  109. DELETE FROM recentchanges WHERE rc_namespace = OLD.page_namespace AND rc_title = OLD.page_title;
  110. RETURN NULL;
  111. END;
  112. $mw$;
  113. CREATE TRIGGER page_deleted AFTER DELETE ON page
  114. FOR EACH ROW EXECUTE PROCEDURE page_deleted();
  115. CREATE SEQUENCE revision_rev_id_seq;
  116. CREATE TABLE revision (
  117. rev_id INTEGER NOT NULL UNIQUE DEFAULT nextval('revision_rev_id_seq'),
  118. rev_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  119. rev_text_id INTEGER NULL, -- FK
  120. rev_comment TEXT,
  121. rev_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE RESTRICT DEFERRABLE INITIALLY DEFERRED,
  122. rev_user_text TEXT NOT NULL,
  123. rev_timestamp TIMESTAMPTZ NOT NULL,
  124. rev_minor_edit SMALLINT NOT NULL DEFAULT 0,
  125. rev_deleted SMALLINT NOT NULL DEFAULT 0,
  126. rev_len INTEGER NULL,
  127. rev_parent_id INTEGER NULL,
  128. rev_sha1 TEXT NOT NULL DEFAULT '',
  129. rev_content_model TEXT,
  130. rev_content_format TEXT
  131. );
  132. CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
  133. CREATE INDEX rev_text_id_idx ON revision (rev_text_id);
  134. CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
  135. CREATE INDEX rev_user_idx ON revision (rev_user);
  136. CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
  137. CREATE SEQUENCE text_old_id_seq;
  138. CREATE TABLE pagecontent ( -- replaces reserved word 'text'
  139. old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_seq'),
  140. old_text TEXT,
  141. old_flags TEXT
  142. );
  143. CREATE SEQUENCE page_restrictions_pr_id_seq;
  144. CREATE TABLE page_restrictions (
  145. pr_id INTEGER NOT NULL UNIQUE DEFAULT nextval('page_restrictions_pr_id_seq'),
  146. pr_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  147. pr_type TEXT NOT NULL,
  148. pr_level TEXT NOT NULL,
  149. pr_cascade SMALLINT NOT NULL,
  150. pr_user INTEGER NULL,
  151. pr_expiry TIMESTAMPTZ NULL
  152. );
  153. ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type);
  154. CREATE TABLE page_props (
  155. pp_page INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  156. pp_propname TEXT NOT NULL,
  157. pp_value TEXT NOT NULL,
  158. pp_sortkey FLOAT
  159. );
  160. ALTER TABLE page_props ADD CONSTRAINT page_props_pk PRIMARY KEY (pp_page,pp_propname);
  161. CREATE INDEX page_props_propname ON page_props (pp_propname);
  162. CREATE UNIQUE INDEX pp_propname_page ON page_props (pp_propname,pp_page);
  163. CREATE INDEX pp_propname_sortkey_page ON page_props (pp_propname, pp_sortkey, pp_page) WHERE (pp_sortkey IS NOT NULL);
  164. CREATE SEQUENCE archive_ar_id_seq;
  165. CREATE TABLE archive (
  166. ar_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('archive_ar_id_seq'),
  167. ar_namespace SMALLINT NOT NULL,
  168. ar_title TEXT NOT NULL,
  169. ar_text TEXT, -- technically should be bytea, but not used anymore
  170. ar_page_id INTEGER NULL,
  171. ar_parent_id INTEGER NULL,
  172. ar_sha1 TEXT NOT NULL DEFAULT '',
  173. ar_comment TEXT,
  174. ar_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
  175. ar_user_text TEXT NOT NULL,
  176. ar_timestamp TIMESTAMPTZ NOT NULL,
  177. ar_minor_edit SMALLINT NOT NULL DEFAULT 0,
  178. ar_flags TEXT,
  179. ar_rev_id INTEGER,
  180. ar_text_id INTEGER,
  181. ar_deleted SMALLINT NOT NULL DEFAULT 0,
  182. ar_len INTEGER NULL,
  183. ar_content_model TEXT,
  184. ar_content_format TEXT
  185. );
  186. CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp);
  187. CREATE INDEX archive_user_text ON archive (ar_user_text);
  188. CREATE TABLE redirect (
  189. rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  190. rd_namespace SMALLINT NOT NULL,
  191. rd_title TEXT NOT NULL,
  192. rd_interwiki TEXT NULL,
  193. rd_fragment TEXT NULL
  194. );
  195. CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
  196. CREATE TABLE pagelinks (
  197. pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  198. pl_from_namespace INTEGER NOT NULL DEFAULT 0,
  199. pl_namespace SMALLINT NOT NULL,
  200. pl_title TEXT NOT NULL
  201. );
  202. CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
  203. CREATE INDEX pagelinks_title ON pagelinks (pl_title);
  204. CREATE TABLE templatelinks (
  205. tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  206. tl_from_namespace INTEGER NOT NULL DEFAULT 0,
  207. tl_namespace SMALLINT NOT NULL,
  208. tl_title TEXT NOT NULL
  209. );
  210. CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
  211. CREATE INDEX templatelinks_from ON templatelinks (tl_from);
  212. CREATE TABLE imagelinks (
  213. il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  214. il_from_namespace INTEGER NOT NULL DEFAULT 0,
  215. il_to TEXT NOT NULL
  216. );
  217. CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
  218. CREATE TABLE categorylinks (
  219. cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  220. cl_to TEXT NOT NULL,
  221. cl_sortkey TEXT NULL,
  222. cl_timestamp TIMESTAMPTZ NOT NULL,
  223. cl_sortkey_prefix TEXT NOT NULL DEFAULT '',
  224. cl_collation TEXT NOT NULL DEFAULT 0,
  225. cl_type TEXT NOT NULL DEFAULT 'page'
  226. );
  227. CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
  228. CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from);
  229. CREATE SEQUENCE externallinks_el_id_seq;
  230. CREATE TABLE externallinks (
  231. el_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('externallinks_el_id_seq'),
  232. el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  233. el_to TEXT NOT NULL,
  234. el_index TEXT NOT NULL
  235. );
  236. CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
  237. CREATE INDEX externallinks_index ON externallinks (el_index);
  238. CREATE TABLE langlinks (
  239. ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  240. ll_lang TEXT,
  241. ll_title TEXT
  242. );
  243. CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
  244. CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
  245. CREATE TABLE site_stats (
  246. ss_row_id INTEGER NOT NULL UNIQUE,
  247. ss_total_edits INTEGER DEFAULT 0,
  248. ss_good_articles INTEGER DEFAULT 0,
  249. ss_total_pages INTEGER DEFAULT -1,
  250. ss_users INTEGER DEFAULT -1,
  251. ss_active_users INTEGER DEFAULT -1,
  252. ss_admins INTEGER DEFAULT -1,
  253. ss_images INTEGER DEFAULT 0
  254. );
  255. CREATE SEQUENCE ipblocks_ipb_id_seq;
  256. CREATE TABLE ipblocks (
  257. ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_seq'),
  258. ipb_address TEXT NULL,
  259. ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
  260. ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  261. ipb_by_text TEXT NOT NULL DEFAULT '',
  262. ipb_reason TEXT NOT NULL,
  263. ipb_timestamp TIMESTAMPTZ NOT NULL,
  264. ipb_auto SMALLINT NOT NULL DEFAULT 0,
  265. ipb_anon_only SMALLINT NOT NULL DEFAULT 0,
  266. ipb_create_account SMALLINT NOT NULL DEFAULT 1,
  267. ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1,
  268. ipb_expiry TIMESTAMPTZ NOT NULL,
  269. ipb_range_start TEXT,
  270. ipb_range_end TEXT,
  271. ipb_deleted SMALLINT NOT NULL DEFAULT 0,
  272. ipb_block_email SMALLINT NOT NULL DEFAULT 0,
  273. ipb_allow_usertalk SMALLINT NOT NULL DEFAULT 0,
  274. ipb_parent_block_id INTEGER NULL REFERENCES ipblocks(ipb_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED
  275. );
  276. CREATE UNIQUE INDEX ipb_address_unique ON ipblocks (ipb_address,ipb_user,ipb_auto,ipb_anon_only);
  277. CREATE INDEX ipb_user ON ipblocks (ipb_user);
  278. CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
  279. CREATE INDEX ipb_parent_block_id ON ipblocks (ipb_parent_block_id);
  280. CREATE TABLE image (
  281. img_name TEXT NOT NULL PRIMARY KEY,
  282. img_size INTEGER NOT NULL,
  283. img_width INTEGER NOT NULL,
  284. img_height INTEGER NOT NULL,
  285. img_metadata BYTEA NOT NULL DEFAULT '',
  286. img_bits SMALLINT,
  287. img_media_type TEXT,
  288. img_major_mime TEXT DEFAULT 'unknown',
  289. img_minor_mime TEXT DEFAULT 'unknown',
  290. img_description TEXT NOT NULL,
  291. img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
  292. img_user_text TEXT NOT NULL,
  293. img_timestamp TIMESTAMPTZ,
  294. img_sha1 TEXT NOT NULL DEFAULT ''
  295. );
  296. CREATE INDEX img_size_idx ON image (img_size);
  297. CREATE INDEX img_timestamp_idx ON image (img_timestamp);
  298. CREATE INDEX img_sha1 ON image (img_sha1);
  299. CREATE TABLE oldimage (
  300. oi_name TEXT NOT NULL,
  301. oi_archive_name TEXT NOT NULL,
  302. oi_size INTEGER NOT NULL,
  303. oi_width INTEGER NOT NULL,
  304. oi_height INTEGER NOT NULL,
  305. oi_bits SMALLINT NULL,
  306. oi_description TEXT,
  307. oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
  308. oi_user_text TEXT NOT NULL,
  309. oi_timestamp TIMESTAMPTZ NULL,
  310. oi_metadata BYTEA NOT NULL DEFAULT '',
  311. oi_media_type TEXT NULL,
  312. oi_major_mime TEXT NULL DEFAULT 'unknown',
  313. oi_minor_mime TEXT NULL DEFAULT 'unknown',
  314. oi_deleted SMALLINT NOT NULL DEFAULT 0,
  315. oi_sha1 TEXT NOT NULL DEFAULT ''
  316. );
  317. ALTER TABLE oldimage ADD CONSTRAINT oldimage_oi_name_fkey_cascaded FOREIGN KEY (oi_name) REFERENCES image(img_name) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
  318. CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp);
  319. CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name);
  320. CREATE INDEX oi_sha1 ON oldimage (oi_sha1);
  321. CREATE SEQUENCE filearchive_fa_id_seq;
  322. CREATE TABLE filearchive (
  323. fa_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('filearchive_fa_id_seq'),
  324. fa_name TEXT NOT NULL,
  325. fa_archive_name TEXT,
  326. fa_storage_group TEXT,
  327. fa_storage_key TEXT,
  328. fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
  329. fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
  330. fa_deleted_reason TEXT,
  331. fa_size INTEGER NOT NULL,
  332. fa_width INTEGER NOT NULL,
  333. fa_height INTEGER NOT NULL,
  334. fa_metadata BYTEA NOT NULL DEFAULT '',
  335. fa_bits SMALLINT,
  336. fa_media_type TEXT,
  337. fa_major_mime TEXT DEFAULT 'unknown',
  338. fa_minor_mime TEXT DEFAULT 'unknown',
  339. fa_description TEXT NOT NULL,
  340. fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
  341. fa_user_text TEXT NOT NULL,
  342. fa_timestamp TIMESTAMPTZ,
  343. fa_deleted SMALLINT NOT NULL DEFAULT 0,
  344. fa_sha1 TEXT NOT NULL DEFAULT ''
  345. );
  346. CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
  347. CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
  348. CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
  349. CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
  350. CREATE INDEX fa_sha1 ON filearchive (fa_sha1);
  351. CREATE SEQUENCE uploadstash_us_id_seq;
  352. CREATE TYPE media_type AS ENUM ('UNKNOWN','BITMAP','DRAWING','AUDIO','VIDEO','MULTIMEDIA','OFFICE','TEXT','EXECUTABLE','ARCHIVE');
  353. CREATE TABLE uploadstash (
  354. us_id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval('uploadstash_us_id_seq'),
  355. us_user INTEGER,
  356. us_key TEXT,
  357. us_orig_path TEXT,
  358. us_path TEXT,
  359. us_props BYTEA,
  360. us_source_type TEXT,
  361. us_timestamp TIMESTAMPTZ,
  362. us_status TEXT,
  363. us_chunk_inx INTEGER NULL,
  364. us_size INTEGER,
  365. us_sha1 TEXT,
  366. us_mime TEXT,
  367. us_media_type media_type DEFAULT NULL,
  368. us_image_width INTEGER,
  369. us_image_height INTEGER,
  370. us_image_bits SMALLINT
  371. );
  372. CREATE INDEX us_user_idx ON uploadstash (us_user);
  373. CREATE UNIQUE INDEX us_key_idx ON uploadstash (us_key);
  374. CREATE INDEX us_timestamp_idx ON uploadstash (us_timestamp);
  375. CREATE SEQUENCE recentchanges_rc_id_seq;
  376. CREATE TABLE recentchanges (
  377. rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('recentchanges_rc_id_seq'),
  378. rc_timestamp TIMESTAMPTZ NOT NULL,
  379. rc_cur_time TIMESTAMPTZ NULL,
  380. rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
  381. rc_user_text TEXT NOT NULL,
  382. rc_namespace SMALLINT NOT NULL,
  383. rc_title TEXT NOT NULL,
  384. rc_comment TEXT,
  385. rc_minor SMALLINT NOT NULL DEFAULT 0,
  386. rc_bot SMALLINT NOT NULL DEFAULT 0,
  387. rc_new SMALLINT NOT NULL DEFAULT 0,
  388. rc_cur_id INTEGER NULL,
  389. rc_this_oldid INTEGER NOT NULL,
  390. rc_last_oldid INTEGER NOT NULL,
  391. rc_type SMALLINT NOT NULL DEFAULT 0,
  392. rc_source TEXT NOT NULL,
  393. rc_patrolled SMALLINT NOT NULL DEFAULT 0,
  394. rc_ip CIDR,
  395. rc_old_len INTEGER,
  396. rc_new_len INTEGER,
  397. rc_deleted SMALLINT NOT NULL DEFAULT 0,
  398. rc_logid INTEGER NOT NULL DEFAULT 0,
  399. rc_log_type TEXT,
  400. rc_log_action TEXT,
  401. rc_params TEXT
  402. );
  403. CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
  404. CREATE INDEX rc_timestamp_bot ON recentchanges (rc_timestamp) WHERE rc_bot = 0;
  405. CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
  406. CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
  407. CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
  408. CREATE INDEX rc_ip ON recentchanges (rc_ip);
  409. CREATE INDEX rc_name_type_patrolled_timestamp ON recentchanges (rc_namespace, rc_type, rc_patrolled, rc_timestamp);
  410. CREATE SEQUENCE watchlist_wl_id_seq;
  411. CREATE TABLE watchlist (
  412. wl_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('watchlist_wl_id_seq'),
  413. wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  414. wl_namespace SMALLINT NOT NULL DEFAULT 0,
  415. wl_title TEXT NOT NULL,
  416. wl_notificationtimestamp TIMESTAMPTZ
  417. );
  418. CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
  419. CREATE INDEX wl_user ON watchlist (wl_user);
  420. CREATE INDEX wl_user_notificationtimestamp ON watchlist (wl_user, wl_notificationtimestamp);
  421. CREATE TABLE interwiki (
  422. iw_prefix TEXT NOT NULL UNIQUE,
  423. iw_url TEXT NOT NULL,
  424. iw_local SMALLINT NOT NULL,
  425. iw_trans SMALLINT NOT NULL DEFAULT 0,
  426. iw_api TEXT NOT NULL DEFAULT '',
  427. iw_wikiid TEXT NOT NULL DEFAULT ''
  428. );
  429. CREATE TABLE querycache (
  430. qc_type TEXT NOT NULL,
  431. qc_value INTEGER NOT NULL,
  432. qc_namespace SMALLINT NOT NULL,
  433. qc_title TEXT NOT NULL
  434. );
  435. CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
  436. CREATE TABLE querycache_info (
  437. qci_type TEXT UNIQUE,
  438. qci_timestamp TIMESTAMPTZ NULL
  439. );
  440. CREATE TABLE querycachetwo (
  441. qcc_type TEXT NOT NULL,
  442. qcc_value INTEGER NOT NULL DEFAULT 0,
  443. qcc_namespace INTEGER NOT NULL DEFAULT 0,
  444. qcc_title TEXT NOT NULL DEFAULT '',
  445. qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
  446. qcc_titletwo TEXT NOT NULL DEFAULT ''
  447. );
  448. CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
  449. CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
  450. CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
  451. CREATE TABLE objectcache (
  452. keyname TEXT UNIQUE,
  453. value BYTEA NOT NULL DEFAULT '',
  454. exptime TIMESTAMPTZ NOT NULL
  455. );
  456. CREATE INDEX objectcacache_exptime ON objectcache (exptime);
  457. CREATE TABLE transcache (
  458. tc_url TEXT NOT NULL UNIQUE,
  459. tc_contents TEXT NOT NULL,
  460. tc_time TIMESTAMPTZ NOT NULL
  461. );
  462. CREATE SEQUENCE logging_log_id_seq;
  463. CREATE TABLE logging (
  464. log_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('logging_log_id_seq'),
  465. log_type TEXT NOT NULL,
  466. log_action TEXT NOT NULL,
  467. log_timestamp TIMESTAMPTZ NOT NULL,
  468. log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
  469. log_namespace SMALLINT NOT NULL,
  470. log_title TEXT NOT NULL,
  471. log_comment TEXT,
  472. log_params TEXT,
  473. log_deleted SMALLINT NOT NULL DEFAULT 0,
  474. log_user_text TEXT NOT NULL DEFAULT '',
  475. log_page INTEGER
  476. );
  477. CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
  478. CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
  479. CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
  480. CREATE INDEX logging_times ON logging (log_timestamp);
  481. CREATE INDEX logging_user_type_time ON logging (log_user, log_type, log_timestamp);
  482. CREATE INDEX logging_page_id_time ON logging (log_page, log_timestamp);
  483. CREATE INDEX logging_user_text_type_time ON logging (log_user_text, log_type, log_timestamp);
  484. CREATE INDEX logging_user_text_time ON logging (log_user_text, log_timestamp);
  485. CREATE TABLE log_search (
  486. ls_field TEXT NOT NULL,
  487. ls_value TEXT NOT NULL,
  488. ls_log_id INTEGER NOT NULL DEFAULT 0,
  489. PRIMARY KEY (ls_field,ls_value,ls_log_id)
  490. );
  491. CREATE INDEX ls_log_id ON log_search (ls_log_id);
  492. CREATE SEQUENCE job_job_id_seq;
  493. CREATE TABLE job (
  494. job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
  495. job_cmd TEXT NOT NULL,
  496. job_namespace SMALLINT NOT NULL,
  497. job_title TEXT NOT NULL,
  498. job_timestamp TIMESTAMPTZ,
  499. job_params TEXT NOT NULL,
  500. job_random INTEGER NOT NULL DEFAULT 0,
  501. job_attempts INTEGER NOT NULL DEFAULT 0,
  502. job_token TEXT NOT NULL DEFAULT '',
  503. job_token_timestamp TIMESTAMPTZ,
  504. job_sha1 TEXT NOT NULL DEFAULT ''
  505. );
  506. CREATE INDEX job_sha1 ON job (job_sha1);
  507. CREATE INDEX job_cmd_token ON job (job_cmd, job_token, job_random);
  508. CREATE INDEX job_cmd_token_id ON job (job_cmd, job_token, job_id);
  509. CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
  510. CREATE INDEX job_timestamp_idx ON job (job_timestamp);
  511. -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
  512. -- Version 8.3 or higher only. Previous versions would need another parmeter for to_tsvector.
  513. -- Make sure you also change patch-tsearch2funcs.sql if the funcs below change.
  514. ALTER TABLE page ADD titlevector tsvector;
  515. CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
  516. $mw$
  517. BEGIN
  518. IF TG_OP = 'INSERT' THEN
  519. NEW.titlevector = to_tsvector(REPLACE(NEW.page_title,'/',' '));
  520. ELSIF NEW.page_title != OLD.page_title THEN
  521. NEW.titlevector := to_tsvector(REPLACE(NEW.page_title,'/',' '));
  522. END IF;
  523. RETURN NEW;
  524. END;
  525. $mw$;
  526. CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
  527. FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
  528. ALTER TABLE pagecontent ADD textvector tsvector;
  529. CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
  530. $mw$
  531. BEGIN
  532. IF TG_OP = 'INSERT' THEN
  533. NEW.textvector = to_tsvector(NEW.old_text);
  534. ELSIF NEW.old_text != OLD.old_text THEN
  535. NEW.textvector := to_tsvector(NEW.old_text);
  536. END IF;
  537. RETURN NEW;
  538. END;
  539. $mw$;
  540. CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
  541. FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
  542. -- These are added by the setup script due to version compatibility issues
  543. -- If using 8.1, we switch from "gin" to "gist"
  544. CREATE INDEX ts2_page_title ON page USING gin(titlevector);
  545. CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
  546. CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
  547. $mw$
  548. INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
  549. SELECT 1;
  550. $mw$;
  551. -- This table is not used unless profiling is turned on
  552. CREATE TABLE profiling (
  553. pf_count INTEGER NOT NULL DEFAULT 0,
  554. pf_time FLOAT NOT NULL DEFAULT 0,
  555. pf_memory FLOAT NOT NULL DEFAULT 0,
  556. pf_name TEXT NOT NULL,
  557. pf_server TEXT NULL
  558. );
  559. CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
  560. CREATE TABLE protected_titles (
  561. pt_namespace SMALLINT NOT NULL,
  562. pt_title TEXT NOT NULL,
  563. pt_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
  564. pt_reason TEXT NULL,
  565. pt_timestamp TIMESTAMPTZ NOT NULL,
  566. pt_expiry TIMESTAMPTZ NULL,
  567. pt_create_perm TEXT NOT NULL DEFAULT ''
  568. );
  569. CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
  570. CREATE TABLE updatelog (
  571. ul_key TEXT NOT NULL PRIMARY KEY,
  572. ul_value TEXT
  573. );
  574. CREATE SEQUENCE category_cat_id_seq;
  575. CREATE TABLE category (
  576. cat_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('category_cat_id_seq'),
  577. cat_title TEXT NOT NULL,
  578. cat_pages INTEGER NOT NULL DEFAULT 0,
  579. cat_subcats INTEGER NOT NULL DEFAULT 0,
  580. cat_files INTEGER NOT NULL DEFAULT 0,
  581. cat_hidden SMALLINT NOT NULL DEFAULT 0
  582. );
  583. CREATE UNIQUE INDEX category_title ON category(cat_title);
  584. CREATE INDEX category_pages ON category(cat_pages);
  585. CREATE SEQUENCE change_tag_ct_id_seq;
  586. CREATE TABLE change_tag (
  587. ct_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('change_tag_ct_id_seq'),
  588. ct_rc_id INTEGER NULL,
  589. ct_log_id INTEGER NULL,
  590. ct_rev_id INTEGER NULL,
  591. ct_tag TEXT NOT NULL,
  592. ct_params TEXT NULL
  593. );
  594. CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag(ct_rc_id,ct_tag);
  595. CREATE UNIQUE INDEX change_tag_log_tag ON change_tag(ct_log_id,ct_tag);
  596. CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag(ct_rev_id,ct_tag);
  597. CREATE INDEX change_tag_tag_id ON change_tag(ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
  598. CREATE SEQUENCE tag_summary_ts_id_seq;
  599. CREATE TABLE tag_summary (
  600. ts_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('tag_summary_ts_id_seq'),
  601. ts_rc_id INTEGER NULL,
  602. ts_log_id INTEGER NULL,
  603. ts_rev_id INTEGER NULL,
  604. ts_tags TEXT NOT NULL
  605. );
  606. CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary(ts_rc_id);
  607. CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary(ts_log_id);
  608. CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary(ts_rev_id);
  609. CREATE TABLE valid_tag (
  610. vt_tag TEXT NOT NULL PRIMARY KEY
  611. );
  612. CREATE TABLE user_properties (
  613. up_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
  614. up_property TEXT NOT NULL,
  615. up_value TEXT
  616. );
  617. CREATE UNIQUE INDEX user_properties_user_property ON user_properties (up_user,up_property);
  618. CREATE INDEX user_properties_property ON user_properties (up_property);
  619. CREATE TABLE l10n_cache (
  620. lc_lang TEXT NOT NULL,
  621. lc_key TEXT NOT NULL,
  622. lc_value BYTEA NOT NULL
  623. );
  624. CREATE INDEX l10n_cache_lc_lang_key ON l10n_cache (lc_lang, lc_key);
  625. CREATE TABLE iwlinks (
  626. iwl_from INTEGER NOT NULL DEFAULT 0,
  627. iwl_prefix TEXT NOT NULL DEFAULT '',
  628. iwl_title TEXT NOT NULL DEFAULT ''
  629. );
  630. CREATE UNIQUE INDEX iwl_from ON iwlinks (iwl_from, iwl_prefix, iwl_title);
  631. CREATE UNIQUE INDEX iwl_prefix_title_from ON iwlinks (iwl_prefix, iwl_title, iwl_from);
  632. CREATE UNIQUE INDEX iwl_prefix_from_title ON iwlinks (iwl_prefix, iwl_from, iwl_title);
  633. CREATE TABLE module_deps (
  634. md_module TEXT NOT NULL,
  635. md_skin TEXT NOT NULL,
  636. md_deps TEXT NOT NULL
  637. );
  638. CREATE UNIQUE INDEX md_module_skin ON module_deps (md_module, md_skin);
  639. CREATE SEQUENCE sites_site_id_seq;
  640. CREATE TABLE sites (
  641. site_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('sites_site_id_seq'),
  642. site_global_key TEXT NOT NULL,
  643. site_type TEXT NOT NULL,
  644. site_group TEXT NOT NULL,
  645. site_source TEXT NOT NULL,
  646. site_language TEXT NOT NULL,
  647. site_protocol TEXT NOT NULL,
  648. site_domain TEXT NOT NULL,
  649. site_data TEXT NOT NULL,
  650. site_forward SMALLINT NOT NULL,
  651. site_config TEXT NOT NULL
  652. );
  653. CREATE UNIQUE INDEX site_global_key ON sites (site_global_key);
  654. CREATE INDEX site_type ON sites (site_type);
  655. CREATE INDEX site_group ON sites (site_group);
  656. CREATE INDEX site_source ON sites (site_source);
  657. CREATE INDEX site_language ON sites (site_language);
  658. CREATE INDEX site_protocol ON sites (site_protocol);
  659. CREATE INDEX site_domain ON sites (site_domain);
  660. CREATE INDEX site_forward ON sites (site_forward);
  661. CREATE TABLE site_identifiers (
  662. si_site INTEGER NOT NULL,
  663. si_type TEXT NOT NULL,
  664. si_key TEXT NOT NULL
  665. );
  666. CREATE UNIQUE INDEX si_type_key ON site_identifiers (si_type, si_key);
  667. CREATE INDEX si_site ON site_identifiers (si_site);
  668. CREATE INDEX si_key ON site_identifiers (si_key);