tables.sql 59 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966967968969970971972973974975976977978979980981982983984985986987988989990991992993994995996997998999100010011002100310041005100610071008100910101011101210131014101510161017101810191020102110221023102410251026102710281029103010311032103310341035103610371038103910401041104210431044104510461047104810491050105110521053105410551056105710581059106010611062106310641065106610671068106910701071107210731074107510761077107810791080108110821083108410851086108710881089109010911092109310941095109610971098109911001101110211031104110511061107110811091110111111121113111411151116111711181119112011211122112311241125112611271128112911301131113211331134113511361137113811391140114111421143114411451146114711481149115011511152115311541155115611571158115911601161116211631164116511661167116811691170117111721173117411751176117711781179118011811182118311841185118611871188118911901191119211931194119511961197119811991200120112021203120412051206120712081209121012111212121312141215121612171218121912201221122212231224122512261227122812291230123112321233123412351236123712381239124012411242124312441245124612471248124912501251125212531254125512561257125812591260126112621263126412651266126712681269127012711272127312741275127612771278127912801281128212831284128512861287128812891290129112921293129412951296129712981299130013011302130313041305130613071308130913101311131213131314131513161317131813191320132113221323132413251326132713281329133013311332133313341335133613371338133913401341134213431344134513461347134813491350135113521353135413551356135713581359136013611362136313641365136613671368136913701371137213731374137513761377137813791380138113821383138413851386138713881389139013911392139313941395139613971398139914001401140214031404140514061407140814091410141114121413141414151416141714181419142014211422142314241425142614271428142914301431143214331434143514361437143814391440144114421443144414451446144714481449145014511452145314541455145614571458145914601461146214631464146514661467146814691470147114721473147414751476147714781479148014811482148314841485148614871488148914901491149214931494149514961497149814991500150115021503150415051506150715081509151015111512151315141515151615171518151915201521152215231524152515261527152815291530153115321533153415351536153715381539154015411542154315441545154615471548154915501551155215531554155515561557155815591560156115621563156415651566156715681569157015711572157315741575157615771578157915801581158215831584158515861587158815891590159115921593159415951596159715981599160016011602160316041605160616071608
  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 a shared schema file used for both MySQL and SQLite installs.
  5. --
  6. -- For more documentation on the database schema, see
  7. -- https://www.mediawiki.org/wiki/Manual:Database_layout
  8. --
  9. -- General notes:
  10. --
  11. -- If possible, create tables as InnoDB to benefit from the
  12. -- superior resiliency against crashes and ability to read
  13. -- during writes (and write during reads!)
  14. --
  15. -- Only the 'searchindex' table requires MyISAM due to the
  16. -- requirement for fulltext index support, which is missing
  17. -- from InnoDB.
  18. --
  19. --
  20. -- The MySQL table backend for MediaWiki currently uses
  21. -- 14-character BINARY or VARBINARY fields to store timestamps.
  22. -- The format is YYYYMMDDHHMMSS, which is derived from the
  23. -- text format of MySQL's TIMESTAMP fields.
  24. --
  25. -- Historically TIMESTAMP fields were used, but abandoned
  26. -- in early 2002 after a lot of trouble with the fields
  27. -- auto-updating.
  28. --
  29. -- The Postgres backend uses TIMESTAMPTZ fields for timestamps,
  30. -- and we will migrate the MySQL definitions at some point as
  31. -- well.
  32. --
  33. --
  34. -- The /*_*/ comments in this and other files are
  35. -- replaced with the defined table prefix by the installer
  36. -- and updater scripts. If you are installing or running
  37. -- updates manually, you will need to manually insert the
  38. -- table prefix if any when running these scripts.
  39. --
  40. --
  41. -- The user table contains basic account information,
  42. -- authentication keys, etc.
  43. --
  44. -- Some multi-wiki sites may share a single central user table
  45. -- between separate wikis using the $wgSharedDB setting.
  46. --
  47. -- Note that when a external authentication plugin is used,
  48. -- user table entries still need to be created to store
  49. -- preferences and to key tracking information in the other
  50. -- tables.
  51. --
  52. CREATE TABLE /*_*/user (
  53. user_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  54. -- Usernames must be unique, must not be in the form of
  55. -- an IP address. _Shouldn't_ allow slashes or case
  56. -- conflicts. Spaces are allowed, and are _not_ converted
  57. -- to underscores like titles. See the User::newFromName() for
  58. -- the specific tests that usernames have to pass.
  59. user_name varchar(255) binary NOT NULL default '',
  60. -- Optional 'real name' to be displayed in credit listings
  61. user_real_name varchar(255) binary NOT NULL default '',
  62. -- Password hashes, see User::crypt() and User::comparePasswords()
  63. -- in User.php for the algorithm
  64. user_password tinyblob NOT NULL,
  65. -- When using 'mail me a new password', a random
  66. -- password is generated and the hash stored here.
  67. -- The previous password is left in place until
  68. -- someone actually logs in with the new password,
  69. -- at which point the hash is moved to user_password
  70. -- and the old password is invalidated.
  71. user_newpassword tinyblob NOT NULL,
  72. -- Timestamp of the last time when a new password was
  73. -- sent, for throttling and expiring purposes
  74. -- Emailed passwords will expire $wgNewPasswordExpiry
  75. -- (a week) after being set. If user_newpass_time is NULL
  76. -- (eg. created by mail) it doesn't expire.
  77. user_newpass_time binary(14),
  78. -- Note: email should be restricted, not public info.
  79. -- Same with passwords.
  80. user_email tinytext NOT NULL,
  81. -- If the browser sends an If-Modified-Since header, a 304 response is
  82. -- suppressed if the value in this field for the current user is later than
  83. -- the value in the IMS header. That is, this field is an invalidation timestamp
  84. -- for the browser cache of logged-in users. Among other things, it is used
  85. -- to prevent pages generated for a previously logged in user from being
  86. -- displayed after a session expiry followed by a fresh login.
  87. user_touched binary(14) NOT NULL default '',
  88. -- A pseudorandomly generated value that is stored in
  89. -- a cookie when the "remember password" feature is
  90. -- used (previously, a hash of the password was used, but
  91. -- this was vulnerable to cookie-stealing attacks)
  92. user_token binary(32) NOT NULL default '',
  93. -- Initially NULL; when a user's e-mail address has been
  94. -- validated by returning with a mailed token, this is
  95. -- set to the current timestamp.
  96. user_email_authenticated binary(14),
  97. -- Randomly generated token created when the e-mail address
  98. -- is set and a confirmation test mail sent.
  99. user_email_token binary(32),
  100. -- Expiration date for the user_email_token
  101. user_email_token_expires binary(14),
  102. -- Timestamp of account registration.
  103. -- Accounts predating this schema addition may contain NULL.
  104. user_registration binary(14),
  105. -- Count of edits and edit-like actions.
  106. --
  107. -- *NOT* intended to be an accurate copy of COUNT(*) WHERE rev_user=user_id
  108. -- May contain NULL for old accounts if batch-update scripts haven't been
  109. -- run, as well as listing deleted edits and other myriad ways it could be
  110. -- out of sync.
  111. --
  112. -- Meant primarily for heuristic checks to give an impression of whether
  113. -- the account has been used much.
  114. --
  115. user_editcount int,
  116. -- Expiration date for user password.
  117. user_password_expires varbinary(14) DEFAULT NULL
  118. ) /*$wgDBTableOptions*/;
  119. CREATE UNIQUE INDEX /*i*/user_name ON /*_*/user (user_name);
  120. CREATE INDEX /*i*/user_email_token ON /*_*/user (user_email_token);
  121. CREATE INDEX /*i*/user_email ON /*_*/user (user_email(50));
  122. --
  123. -- User permissions have been broken out to a separate table;
  124. -- this allows sites with a shared user table to have different
  125. -- permissions assigned to a user in each project.
  126. --
  127. -- This table replaces the old user_rights field which used a
  128. -- comma-separated blob.
  129. --
  130. CREATE TABLE /*_*/user_groups (
  131. -- Key to user_id
  132. ug_user int unsigned NOT NULL default 0,
  133. -- Group names are short symbolic string keys.
  134. -- The set of group names is open-ended, though in practice
  135. -- only some predefined ones are likely to be used.
  136. --
  137. -- At runtime $wgGroupPermissions will associate group keys
  138. -- with particular permissions. A user will have the combined
  139. -- permissions of any group they're explicitly in, plus
  140. -- the implicit '*' and 'user' groups.
  141. ug_group varbinary(255) NOT NULL default ''
  142. ) /*$wgDBTableOptions*/;
  143. CREATE UNIQUE INDEX /*i*/ug_user_group ON /*_*/user_groups (ug_user,ug_group);
  144. CREATE INDEX /*i*/ug_group ON /*_*/user_groups (ug_group);
  145. -- Stores the groups the user has once belonged to.
  146. -- The user may still belong to these groups (check user_groups).
  147. -- Users are not autopromoted to groups from which they were removed.
  148. CREATE TABLE /*_*/user_former_groups (
  149. -- Key to user_id
  150. ufg_user int unsigned NOT NULL default 0,
  151. ufg_group varbinary(255) NOT NULL default ''
  152. ) /*$wgDBTableOptions*/;
  153. CREATE UNIQUE INDEX /*i*/ufg_user_group ON /*_*/user_former_groups (ufg_user,ufg_group);
  154. --
  155. -- Stores notifications of user talk page changes, for the display
  156. -- of the "you have new messages" box
  157. --
  158. CREATE TABLE /*_*/user_newtalk (
  159. -- Key to user.user_id
  160. user_id int unsigned NOT NULL default 0,
  161. -- If the user is an anonymous user their IP address is stored here
  162. -- since the user_id of 0 is ambiguous
  163. user_ip varbinary(40) NOT NULL default '',
  164. -- The highest timestamp of revisions of the talk page viewed
  165. -- by this user
  166. user_last_timestamp varbinary(14) NULL default NULL
  167. ) /*$wgDBTableOptions*/;
  168. -- Indexes renamed for SQLite in 1.14
  169. CREATE INDEX /*i*/un_user_id ON /*_*/user_newtalk (user_id);
  170. CREATE INDEX /*i*/un_user_ip ON /*_*/user_newtalk (user_ip);
  171. --
  172. -- User preferences and perhaps other fun stuff. :)
  173. -- Replaces the old user.user_options blob, with a couple nice properties:
  174. --
  175. -- 1) We only store non-default settings, so changes to the defauls
  176. -- are now reflected for everybody, not just new accounts.
  177. -- 2) We can more easily do bulk lookups, statistics, or modifications of
  178. -- saved options since it's a sane table structure.
  179. --
  180. CREATE TABLE /*_*/user_properties (
  181. -- Foreign key to user.user_id
  182. up_user int NOT NULL,
  183. -- Name of the option being saved. This is indexed for bulk lookup.
  184. up_property varbinary(255) NOT NULL,
  185. -- Property value as a string.
  186. up_value blob
  187. ) /*$wgDBTableOptions*/;
  188. CREATE UNIQUE INDEX /*i*/user_properties_user_property ON /*_*/user_properties (up_user,up_property);
  189. CREATE INDEX /*i*/user_properties_property ON /*_*/user_properties (up_property);
  190. --
  191. -- This table contains a user's bot passwords: passwords that allow access to
  192. -- the account via the API with limited rights.
  193. --
  194. CREATE TABLE /*_*/bot_passwords (
  195. -- User ID obtained from CentralIdLookup.
  196. bp_user int NOT NULL,
  197. -- Application identifier
  198. bp_app_id varbinary(32) NOT NULL,
  199. -- Password hashes, like user.user_password
  200. bp_password tinyblob NOT NULL,
  201. -- Like user.user_token
  202. bp_token binary(32) NOT NULL default '',
  203. -- JSON blob for MWRestrictions
  204. bp_restrictions blob NOT NULL,
  205. -- Grants allowed to the account when authenticated with this bot-password
  206. bp_grants blob NOT NULL,
  207. PRIMARY KEY ( bp_user, bp_app_id )
  208. ) /*$wgDBTableOptions*/;
  209. --
  210. -- Core of the wiki: each page has an entry here which identifies
  211. -- it by title and contains some essential metadata.
  212. --
  213. CREATE TABLE /*_*/page (
  214. -- Unique identifier number. The page_id will be preserved across
  215. -- edits and rename operations, but not deletions and recreations.
  216. page_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  217. -- A page name is broken into a namespace and a title.
  218. -- The namespace keys are UI-language-independent constants,
  219. -- defined in includes/Defines.php
  220. page_namespace int NOT NULL,
  221. -- The rest of the title, as text.
  222. -- Spaces are transformed into underscores in title storage.
  223. page_title varchar(255) binary NOT NULL,
  224. -- Comma-separated set of permission keys indicating who
  225. -- can move or edit the page.
  226. page_restrictions tinyblob NOT NULL,
  227. -- 1 indicates the article is a redirect.
  228. page_is_redirect tinyint unsigned NOT NULL default 0,
  229. -- 1 indicates this is a new entry, with only one edit.
  230. -- Not all pages with one edit are new pages.
  231. page_is_new tinyint unsigned NOT NULL default 0,
  232. -- Random value between 0 and 1, used for Special:Randompage
  233. page_random real unsigned NOT NULL,
  234. -- This timestamp is updated whenever the page changes in
  235. -- a way requiring it to be re-rendered, invalidating caches.
  236. -- Aside from editing this includes permission changes,
  237. -- creation or deletion of linked pages, and alteration
  238. -- of contained templates.
  239. page_touched binary(14) NOT NULL default '',
  240. -- This timestamp is updated whenever a page is re-parsed and
  241. -- it has all the link tracking tables updated for it. This is
  242. -- useful for de-duplicating expensive backlink update jobs.
  243. page_links_updated varbinary(14) NULL default NULL,
  244. -- Handy key to revision.rev_id of the current revision.
  245. -- This may be 0 during page creation, but that shouldn't
  246. -- happen outside of a transaction... hopefully.
  247. page_latest int unsigned NOT NULL,
  248. -- Uncompressed length in bytes of the page's current source text.
  249. page_len int unsigned NOT NULL,
  250. -- content model, see CONTENT_MODEL_XXX constants
  251. page_content_model varbinary(32) DEFAULT NULL,
  252. -- Page content language
  253. page_lang varbinary(35) DEFAULT NULL
  254. ) /*$wgDBTableOptions*/;
  255. CREATE UNIQUE INDEX /*i*/name_title ON /*_*/page (page_namespace,page_title);
  256. CREATE INDEX /*i*/page_random ON /*_*/page (page_random);
  257. CREATE INDEX /*i*/page_len ON /*_*/page (page_len);
  258. CREATE INDEX /*i*/page_redirect_namespace_len ON /*_*/page (page_is_redirect, page_namespace, page_len);
  259. --
  260. -- Every edit of a page creates also a revision row.
  261. -- This stores metadata about the revision, and a reference
  262. -- to the text storage backend.
  263. --
  264. CREATE TABLE /*_*/revision (
  265. -- Unique ID to identify each revision
  266. rev_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  267. -- Key to page_id. This should _never_ be invalid.
  268. rev_page int unsigned NOT NULL,
  269. -- Key to text.old_id, where the actual bulk text is stored.
  270. -- It's possible for multiple revisions to use the same text,
  271. -- for instance revisions where only metadata is altered
  272. -- or a rollback to a previous version.
  273. rev_text_id int unsigned NOT NULL,
  274. -- Text comment summarizing the change.
  275. -- This text is shown in the history and other changes lists,
  276. -- rendered in a subset of wiki markup by Linker::formatComment()
  277. rev_comment varbinary(767) NOT NULL,
  278. -- Key to user.user_id of the user who made this edit.
  279. -- Stores 0 for anonymous edits and for some mass imports.
  280. rev_user int unsigned NOT NULL default 0,
  281. -- Text username or IP address of the editor.
  282. rev_user_text varchar(255) binary NOT NULL default '',
  283. -- Timestamp of when revision was created
  284. rev_timestamp binary(14) NOT NULL default '',
  285. -- Records whether the user marked the 'minor edit' checkbox.
  286. -- Many automated edits are marked as minor.
  287. rev_minor_edit tinyint unsigned NOT NULL default 0,
  288. -- Restrictions on who can access this revision
  289. rev_deleted tinyint unsigned NOT NULL default 0,
  290. -- Length of this revision in bytes
  291. rev_len int unsigned,
  292. -- Key to revision.rev_id
  293. -- This field is used to add support for a tree structure (The Adjacency List Model)
  294. rev_parent_id int unsigned default NULL,
  295. -- SHA-1 text content hash in base-36
  296. rev_sha1 varbinary(32) NOT NULL default '',
  297. -- content model, see CONTENT_MODEL_XXX constants
  298. rev_content_model varbinary(32) DEFAULT NULL,
  299. -- content format, see CONTENT_FORMAT_XXX constants
  300. rev_content_format varbinary(64) DEFAULT NULL
  301. ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=1024;
  302. -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
  303. CREATE INDEX /*i*/rev_page_id ON /*_*/revision (rev_page, rev_id);
  304. CREATE INDEX /*i*/rev_timestamp ON /*_*/revision (rev_timestamp);
  305. CREATE INDEX /*i*/page_timestamp ON /*_*/revision (rev_page,rev_timestamp);
  306. CREATE INDEX /*i*/user_timestamp ON /*_*/revision (rev_user,rev_timestamp);
  307. CREATE INDEX /*i*/usertext_timestamp ON /*_*/revision (rev_user_text,rev_timestamp);
  308. CREATE INDEX /*i*/page_user_timestamp ON /*_*/revision (rev_page,rev_user,rev_timestamp);
  309. --
  310. -- Holds text of individual page revisions.
  311. --
  312. -- Field names are a holdover from the 'old' revisions table in
  313. -- MediaWiki 1.4 and earlier: an upgrade will transform that
  314. -- table into the 'text' table to minimize unnecessary churning
  315. -- and downtime. If upgrading, the other fields will be left unused.
  316. --
  317. CREATE TABLE /*_*/text (
  318. -- Unique text storage key number.
  319. -- Note that the 'oldid' parameter used in URLs does *not*
  320. -- refer to this number anymore, but to rev_id.
  321. --
  322. -- revision.rev_text_id is a key to this column
  323. old_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  324. -- Depending on the contents of the old_flags field, the text
  325. -- may be convenient plain text, or it may be funkily encoded.
  326. old_text mediumblob NOT NULL,
  327. -- Comma-separated list of flags:
  328. -- gzip: text is compressed with PHP's gzdeflate() function.
  329. -- utf-8: text was stored as UTF-8.
  330. -- If $wgLegacyEncoding option is on, rows *without* this flag
  331. -- will be converted to UTF-8 transparently at load time. Note
  332. -- that due to a bug in a maintenance script, this flag may
  333. -- have been stored as 'utf8' in some cases (T18841).
  334. -- object: text field contained a serialized PHP object.
  335. -- The object either contains multiple versions compressed
  336. -- together to achieve a better compression ratio, or it refers
  337. -- to another row where the text can be found.
  338. -- external: text was stored in an external location specified by old_text.
  339. -- Any additional flags apply to the data stored at that URL, not
  340. -- the URL itself. The 'object' flag is *not* set for URLs of the
  341. -- form 'DB://cluster/id/itemid', because the external storage
  342. -- system itself decompresses these.
  343. old_flags tinyblob NOT NULL
  344. ) /*$wgDBTableOptions*/ MAX_ROWS=10000000 AVG_ROW_LENGTH=10240;
  345. -- In case tables are created as MyISAM, use row hints for MySQL <5.0 to avoid 4GB limit
  346. --
  347. -- Holding area for deleted articles, which may be viewed
  348. -- or restored by admins through the Special:Undelete interface.
  349. -- The fields generally correspond to the page, revision, and text
  350. -- fields, with several caveats.
  351. --
  352. CREATE TABLE /*_*/archive (
  353. -- Primary key
  354. ar_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  355. ar_namespace int NOT NULL default 0,
  356. ar_title varchar(255) binary NOT NULL default '',
  357. -- Newly deleted pages will not store text in this table,
  358. -- but will reference the separately existing text rows.
  359. -- This field is retained for backwards compatibility,
  360. -- so old archived pages will remain accessible after
  361. -- upgrading from 1.4 to 1.5.
  362. -- Text may be gzipped or otherwise funky.
  363. ar_text mediumblob NOT NULL,
  364. -- Basic revision stuff...
  365. ar_comment varbinary(767) NOT NULL,
  366. ar_user int unsigned NOT NULL default 0,
  367. ar_user_text varchar(255) binary NOT NULL,
  368. ar_timestamp binary(14) NOT NULL default '',
  369. ar_minor_edit tinyint NOT NULL default 0,
  370. -- See ar_text note.
  371. ar_flags tinyblob NOT NULL,
  372. -- When revisions are deleted, their unique rev_id is stored
  373. -- here so it can be retained after undeletion. This is necessary
  374. -- to retain permalinks to given revisions after accidental delete
  375. -- cycles or messy operations like history merges.
  376. --
  377. -- Old entries from 1.4 will be NULL here, and a new rev_id will
  378. -- be created on undeletion for those revisions.
  379. ar_rev_id int unsigned,
  380. -- For newly deleted revisions, this is the text.old_id key to the
  381. -- actual stored text. To avoid breaking the block-compression scheme
  382. -- and otherwise making storage changes harder, the actual text is
  383. -- *not* deleted from the text table, merely hidden by removal of the
  384. -- page and revision entries.
  385. --
  386. -- Old entries deleted under 1.2-1.4 will have NULL here, and their
  387. -- ar_text and ar_flags fields will be used to create a new text
  388. -- row upon undeletion.
  389. ar_text_id int unsigned,
  390. -- rev_deleted for archives
  391. ar_deleted tinyint unsigned NOT NULL default 0,
  392. -- Length of this revision in bytes
  393. ar_len int unsigned,
  394. -- Reference to page_id. Useful for sysadmin fixing of large pages
  395. -- merged together in the archives, or for cleanly restoring a page
  396. -- at its original ID number if possible.
  397. --
  398. -- Will be NULL for pages deleted prior to 1.11.
  399. ar_page_id int unsigned,
  400. -- Original previous revision
  401. ar_parent_id int unsigned default NULL,
  402. -- SHA-1 text content hash in base-36
  403. ar_sha1 varbinary(32) NOT NULL default '',
  404. -- content model, see CONTENT_MODEL_XXX constants
  405. ar_content_model varbinary(32) DEFAULT NULL,
  406. -- content format, see CONTENT_FORMAT_XXX constants
  407. ar_content_format varbinary(64) DEFAULT NULL
  408. ) /*$wgDBTableOptions*/;
  409. CREATE INDEX /*i*/name_title_timestamp ON /*_*/archive (ar_namespace,ar_title,ar_timestamp);
  410. CREATE INDEX /*i*/ar_usertext_timestamp ON /*_*/archive (ar_user_text,ar_timestamp);
  411. CREATE INDEX /*i*/ar_revid ON /*_*/archive (ar_rev_id);
  412. --
  413. -- Track page-to-page hyperlinks within the wiki.
  414. --
  415. CREATE TABLE /*_*/pagelinks (
  416. -- Key to the page_id of the page containing the link.
  417. pl_from int unsigned NOT NULL default 0,
  418. -- Namespace for this page
  419. pl_from_namespace int NOT NULL default 0,
  420. -- Key to page_namespace/page_title of the target page.
  421. -- The target page may or may not exist, and due to renames
  422. -- and deletions may refer to different page records as time
  423. -- goes by.
  424. pl_namespace int NOT NULL default 0,
  425. pl_title varchar(255) binary NOT NULL default ''
  426. ) /*$wgDBTableOptions*/;
  427. CREATE UNIQUE INDEX /*i*/pl_from ON /*_*/pagelinks (pl_from,pl_namespace,pl_title);
  428. CREATE INDEX /*i*/pl_namespace ON /*_*/pagelinks (pl_namespace,pl_title,pl_from);
  429. CREATE INDEX /*i*/pl_backlinks_namespace ON /*_*/pagelinks (pl_from_namespace,pl_namespace,pl_title,pl_from);
  430. --
  431. -- Track template inclusions.
  432. --
  433. CREATE TABLE /*_*/templatelinks (
  434. -- Key to the page_id of the page containing the link.
  435. tl_from int unsigned NOT NULL default 0,
  436. -- Namespace for this page
  437. tl_from_namespace int NOT NULL default 0,
  438. -- Key to page_namespace/page_title of the target page.
  439. -- The target page may or may not exist, and due to renames
  440. -- and deletions may refer to different page records as time
  441. -- goes by.
  442. tl_namespace int NOT NULL default 0,
  443. tl_title varchar(255) binary NOT NULL default ''
  444. ) /*$wgDBTableOptions*/;
  445. CREATE UNIQUE INDEX /*i*/tl_from ON /*_*/templatelinks (tl_from,tl_namespace,tl_title);
  446. CREATE INDEX /*i*/tl_namespace ON /*_*/templatelinks (tl_namespace,tl_title,tl_from);
  447. CREATE INDEX /*i*/tl_backlinks_namespace ON /*_*/templatelinks (tl_from_namespace,tl_namespace,tl_title,tl_from);
  448. --
  449. -- Track links to images *used inline*
  450. -- We don't distinguish live from broken links here, so
  451. -- they do not need to be changed on upload/removal.
  452. --
  453. CREATE TABLE /*_*/imagelinks (
  454. -- Key to page_id of the page containing the image / media link.
  455. il_from int unsigned NOT NULL default 0,
  456. -- Namespace for this page
  457. il_from_namespace int NOT NULL default 0,
  458. -- Filename of target image.
  459. -- This is also the page_title of the file's description page;
  460. -- all such pages are in namespace 6 (NS_FILE).
  461. il_to varchar(255) binary NOT NULL default ''
  462. ) /*$wgDBTableOptions*/;
  463. CREATE UNIQUE INDEX /*i*/il_from ON /*_*/imagelinks (il_from,il_to);
  464. CREATE INDEX /*i*/il_to ON /*_*/imagelinks (il_to,il_from);
  465. CREATE INDEX /*i*/il_backlinks_namespace ON /*_*/imagelinks (il_from_namespace,il_to,il_from);
  466. --
  467. -- Track category inclusions *used inline*
  468. -- This tracks a single level of category membership
  469. --
  470. CREATE TABLE /*_*/categorylinks (
  471. -- Key to page_id of the page defined as a category member.
  472. cl_from int unsigned NOT NULL default 0,
  473. -- Name of the category.
  474. -- This is also the page_title of the category's description page;
  475. -- all such pages are in namespace 14 (NS_CATEGORY).
  476. cl_to varchar(255) binary NOT NULL default '',
  477. -- A binary string obtained by applying a sortkey generation algorithm
  478. -- (Collation::getSortKey()) to page_title, or cl_sortkey_prefix . "\n"
  479. -- . page_title if cl_sortkey_prefix is nonempty.
  480. cl_sortkey varbinary(230) NOT NULL default '',
  481. -- A prefix for the raw sortkey manually specified by the user, either via
  482. -- [[Category:Foo|prefix]] or {{defaultsort:prefix}}. If nonempty, it's
  483. -- concatenated with a line break followed by the page title before the sortkey
  484. -- conversion algorithm is run. We store this so that we can update
  485. -- collations without reparsing all pages.
  486. -- Note: If you change the length of this field, you also need to change
  487. -- code in LinksUpdate.php. See bug 25254.
  488. cl_sortkey_prefix varchar(255) binary NOT NULL default '',
  489. -- This isn't really used at present. Provided for an optional
  490. -- sorting method by approximate addition time.
  491. cl_timestamp timestamp NOT NULL,
  492. -- Stores $wgCategoryCollation at the time cl_sortkey was generated. This
  493. -- can be used to install new collation versions, tracking which rows are not
  494. -- yet updated. '' means no collation, this is a legacy row that needs to be
  495. -- updated by updateCollation.php. In the future, it might be possible to
  496. -- specify different collations per category.
  497. cl_collation varbinary(32) NOT NULL default '',
  498. -- Stores whether cl_from is a category, file, or other page, so we can
  499. -- paginate the three categories separately. This never has to be updated
  500. -- after the page is created, since none of these page types can be moved to
  501. -- any other.
  502. cl_type ENUM('page', 'subcat', 'file') NOT NULL default 'page'
  503. ) /*$wgDBTableOptions*/;
  504. CREATE UNIQUE INDEX /*i*/cl_from ON /*_*/categorylinks (cl_from,cl_to);
  505. -- We always sort within a given category, and within a given type. FIXME:
  506. -- Formerly this index didn't cover cl_type (since that didn't exist), so old
  507. -- callers won't be using an index: fix this?
  508. CREATE INDEX /*i*/cl_sortkey ON /*_*/categorylinks (cl_to,cl_type,cl_sortkey,cl_from);
  509. -- Used by the API (and some extensions)
  510. CREATE INDEX /*i*/cl_timestamp ON /*_*/categorylinks (cl_to,cl_timestamp);
  511. -- Used when updating collation (e.g. updateCollation.php)
  512. CREATE INDEX /*i*/cl_collation_ext ON /*_*/categorylinks (cl_collation, cl_to, cl_type, cl_from);
  513. --
  514. -- Track all existing categories. Something is a category if 1) it has an entry
  515. -- somewhere in categorylinks, or 2) it has a description page. Categories
  516. -- might not have corresponding pages, so they need to be tracked separately.
  517. --
  518. CREATE TABLE /*_*/category (
  519. -- Primary key
  520. cat_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  521. -- Name of the category, in the same form as page_title (with underscores).
  522. -- If there is a category page corresponding to this category, by definition,
  523. -- it has this name (in the Category namespace).
  524. cat_title varchar(255) binary NOT NULL,
  525. -- The numbers of member pages (including categories and media), subcatego-
  526. -- ries, and Image: namespace members, respectively. These are signed to
  527. -- make underflow more obvious. We make the first number include the second
  528. -- two for better sorting: subtracting for display is easy, adding for order-
  529. -- ing is not.
  530. cat_pages int signed NOT NULL default 0,
  531. cat_subcats int signed NOT NULL default 0,
  532. cat_files int signed NOT NULL default 0
  533. ) /*$wgDBTableOptions*/;
  534. CREATE UNIQUE INDEX /*i*/cat_title ON /*_*/category (cat_title);
  535. -- For Special:Mostlinkedcategories
  536. CREATE INDEX /*i*/cat_pages ON /*_*/category (cat_pages);
  537. --
  538. -- Track links to external URLs
  539. --
  540. CREATE TABLE /*_*/externallinks (
  541. -- Primary key
  542. el_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  543. -- page_id of the referring page
  544. el_from int unsigned NOT NULL default 0,
  545. -- The URL
  546. el_to blob NOT NULL,
  547. -- In the case of HTTP URLs, this is the URL with any username or password
  548. -- removed, and with the labels in the hostname reversed and converted to
  549. -- lower case. An extra dot is added to allow for matching of either
  550. -- example.com or *.example.com in a single scan.
  551. -- Example:
  552. -- http://user:password@sub.example.com/page.html
  553. -- becomes
  554. -- http://com.example.sub./page.html
  555. -- which allows for fast searching for all pages under example.com with the
  556. -- clause:
  557. -- WHERE el_index LIKE 'http://com.example.%'
  558. el_index blob NOT NULL
  559. ) /*$wgDBTableOptions*/;
  560. CREATE INDEX /*i*/el_from ON /*_*/externallinks (el_from, el_to(40));
  561. CREATE INDEX /*i*/el_to ON /*_*/externallinks (el_to(60), el_from);
  562. CREATE INDEX /*i*/el_index ON /*_*/externallinks (el_index(60));
  563. --
  564. -- Track interlanguage links
  565. --
  566. CREATE TABLE /*_*/langlinks (
  567. -- page_id of the referring page
  568. ll_from int unsigned NOT NULL default 0,
  569. -- Language code of the target
  570. ll_lang varbinary(20) NOT NULL default '',
  571. -- Title of the target, including namespace
  572. ll_title varchar(255) binary NOT NULL default ''
  573. ) /*$wgDBTableOptions*/;
  574. CREATE UNIQUE INDEX /*i*/ll_from ON /*_*/langlinks (ll_from, ll_lang);
  575. CREATE INDEX /*i*/ll_lang ON /*_*/langlinks (ll_lang, ll_title);
  576. --
  577. -- Track inline interwiki links
  578. --
  579. CREATE TABLE /*_*/iwlinks (
  580. -- page_id of the referring page
  581. iwl_from int unsigned NOT NULL default 0,
  582. -- Interwiki prefix code of the target
  583. iwl_prefix varbinary(20) NOT NULL default '',
  584. -- Title of the target, including namespace
  585. iwl_title varchar(255) binary NOT NULL default ''
  586. ) /*$wgDBTableOptions*/;
  587. CREATE UNIQUE INDEX /*i*/iwl_from ON /*_*/iwlinks (iwl_from, iwl_prefix, iwl_title);
  588. CREATE INDEX /*i*/iwl_prefix_title_from ON /*_*/iwlinks (iwl_prefix, iwl_title, iwl_from);
  589. CREATE INDEX /*i*/iwl_prefix_from_title ON /*_*/iwlinks (iwl_prefix, iwl_from, iwl_title);
  590. --
  591. -- Contains a single row with some aggregate info
  592. -- on the state of the site.
  593. --
  594. CREATE TABLE /*_*/site_stats (
  595. -- The single row should contain 1 here.
  596. ss_row_id int unsigned NOT NULL,
  597. -- Total number of edits performed.
  598. ss_total_edits bigint unsigned default 0,
  599. -- An approximate count of pages matching the following criteria:
  600. -- * in namespace 0
  601. -- * not a redirect
  602. -- * contains the text '[['
  603. -- See Article::isCountable() in includes/Article.php
  604. ss_good_articles bigint unsigned default 0,
  605. -- Total pages, theoretically equal to SELECT COUNT(*) FROM page; except faster
  606. ss_total_pages bigint default '-1',
  607. -- Number of users, theoretically equal to SELECT COUNT(*) FROM user;
  608. ss_users bigint default '-1',
  609. -- Number of users that still edit
  610. ss_active_users bigint default '-1',
  611. -- Number of images, equivalent to SELECT COUNT(*) FROM image
  612. ss_images int default 0
  613. ) /*$wgDBTableOptions*/;
  614. -- Pointless index to assuage developer superstitions
  615. CREATE UNIQUE INDEX /*i*/ss_row_id ON /*_*/site_stats (ss_row_id);
  616. --
  617. -- The internet is full of jerks, alas. Sometimes it's handy
  618. -- to block a vandal or troll account.
  619. --
  620. CREATE TABLE /*_*/ipblocks (
  621. -- Primary key, introduced for privacy.
  622. ipb_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
  623. -- Blocked IP address in dotted-quad form or user name.
  624. ipb_address tinyblob NOT NULL,
  625. -- Blocked user ID or 0 for IP blocks.
  626. ipb_user int unsigned NOT NULL default 0,
  627. -- User ID who made the block.
  628. ipb_by int unsigned NOT NULL default 0,
  629. -- User name of blocker
  630. ipb_by_text varchar(255) binary NOT NULL default '',
  631. -- Text comment made by blocker.
  632. ipb_reason varbinary(767) NOT NULL,
  633. -- Creation (or refresh) date in standard YMDHMS form.
  634. -- IP blocks expire automatically.
  635. ipb_timestamp binary(14) NOT NULL default '',
  636. -- Indicates that the IP address was banned because a banned
  637. -- user accessed a page through it. If this is 1, ipb_address
  638. -- will be hidden, and the block identified by block ID number.
  639. ipb_auto bool NOT NULL default 0,
  640. -- If set to 1, block applies only to logged-out users
  641. ipb_anon_only bool NOT NULL default 0,
  642. -- Block prevents account creation from matching IP addresses
  643. ipb_create_account bool NOT NULL default 1,
  644. -- Block triggers autoblocks
  645. ipb_enable_autoblock bool NOT NULL default '1',
  646. -- Time at which the block will expire.
  647. -- May be "infinity"
  648. ipb_expiry varbinary(14) NOT NULL default '',
  649. -- Start and end of an address range, in hexadecimal
  650. -- Size chosen to allow IPv6
  651. -- FIXME: these fields were originally blank for single-IP blocks,
  652. -- but now they are populated. No migration was ever done. They
  653. -- should be fixed to be blank again for such blocks (bug 49504).
  654. ipb_range_start tinyblob NOT NULL,
  655. ipb_range_end tinyblob NOT NULL,
  656. -- Flag for entries hidden from users and Sysops
  657. ipb_deleted bool NOT NULL default 0,
  658. -- Block prevents user from accessing Special:Emailuser
  659. ipb_block_email bool NOT NULL default 0,
  660. -- Block allows user to edit their own talk page
  661. ipb_allow_usertalk bool NOT NULL default 0,
  662. -- ID of the block that caused this block to exist
  663. -- Autoblocks set this to the original block
  664. -- so that the original block being deleted also
  665. -- deletes the autoblocks
  666. ipb_parent_block_id int default NULL
  667. ) /*$wgDBTableOptions*/;
  668. -- Unique index to support "user already blocked" messages
  669. -- Any new options which prevent collisions should be included
  670. CREATE UNIQUE INDEX /*i*/ipb_address ON /*_*/ipblocks (ipb_address(255), ipb_user, ipb_auto, ipb_anon_only);
  671. CREATE INDEX /*i*/ipb_user ON /*_*/ipblocks (ipb_user);
  672. CREATE INDEX /*i*/ipb_range ON /*_*/ipblocks (ipb_range_start(8), ipb_range_end(8));
  673. CREATE INDEX /*i*/ipb_timestamp ON /*_*/ipblocks (ipb_timestamp);
  674. CREATE INDEX /*i*/ipb_expiry ON /*_*/ipblocks (ipb_expiry);
  675. CREATE INDEX /*i*/ipb_parent_block_id ON /*_*/ipblocks (ipb_parent_block_id);
  676. --
  677. -- Uploaded images and other files.
  678. --
  679. CREATE TABLE /*_*/image (
  680. -- Filename.
  681. -- This is also the title of the associated description page,
  682. -- which will be in namespace 6 (NS_FILE).
  683. img_name varchar(255) binary NOT NULL default '' PRIMARY KEY,
  684. -- File size in bytes.
  685. img_size int unsigned NOT NULL default 0,
  686. -- For images, size in pixels.
  687. img_width int NOT NULL default 0,
  688. img_height int NOT NULL default 0,
  689. -- Extracted Exif metadata stored as a serialized PHP array.
  690. img_metadata mediumblob NOT NULL,
  691. -- For images, bits per pixel if known.
  692. img_bits int NOT NULL default 0,
  693. -- Media type as defined by the MEDIATYPE_xxx constants
  694. img_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
  695. -- major part of a MIME media type as defined by IANA
  696. -- see http://www.iana.org/assignments/media-types/
  697. -- for "chemical" cf. http://dx.doi.org/10.1021/ci9803233 by the ACS
  698. img_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") NOT NULL default "unknown",
  699. -- minor part of a MIME media type as defined by IANA
  700. -- the minor parts are not required to adher to any standard
  701. -- but should be consistent throughout the database
  702. -- see http://www.iana.org/assignments/media-types/
  703. img_minor_mime varbinary(100) NOT NULL default "unknown",
  704. -- Description field as entered by the uploader.
  705. -- This is displayed in image upload history and logs.
  706. img_description varbinary(767) NOT NULL,
  707. -- user_id and user_name of uploader.
  708. img_user int unsigned NOT NULL default 0,
  709. img_user_text varchar(255) binary NOT NULL,
  710. -- Time of the upload.
  711. img_timestamp varbinary(14) NOT NULL default '',
  712. -- SHA-1 content hash in base-36
  713. img_sha1 varbinary(32) NOT NULL default ''
  714. ) /*$wgDBTableOptions*/;
  715. CREATE INDEX /*i*/img_usertext_timestamp ON /*_*/image (img_user_text,img_timestamp);
  716. -- Used by Special:ListFiles for sort-by-size
  717. CREATE INDEX /*i*/img_size ON /*_*/image (img_size);
  718. -- Used by Special:Newimages and Special:ListFiles
  719. CREATE INDEX /*i*/img_timestamp ON /*_*/image (img_timestamp);
  720. -- Used in API and duplicate search
  721. CREATE INDEX /*i*/img_sha1 ON /*_*/image (img_sha1(10));
  722. -- Used to get media of one type
  723. CREATE INDEX /*i*/img_media_mime ON /*_*/image (img_media_type,img_major_mime,img_minor_mime);
  724. --
  725. -- Previous revisions of uploaded files.
  726. -- Awkwardly, image rows have to be moved into
  727. -- this table at re-upload time.
  728. --
  729. CREATE TABLE /*_*/oldimage (
  730. -- Base filename: key to image.img_name
  731. oi_name varchar(255) binary NOT NULL default '',
  732. -- Filename of the archived file.
  733. -- This is generally a timestamp and '!' prepended to the base name.
  734. oi_archive_name varchar(255) binary NOT NULL default '',
  735. -- Other fields as in image...
  736. oi_size int unsigned NOT NULL default 0,
  737. oi_width int NOT NULL default 0,
  738. oi_height int NOT NULL default 0,
  739. oi_bits int NOT NULL default 0,
  740. oi_description varbinary(767) NOT NULL,
  741. oi_user int unsigned NOT NULL default 0,
  742. oi_user_text varchar(255) binary NOT NULL,
  743. oi_timestamp binary(14) NOT NULL default '',
  744. oi_metadata mediumblob NOT NULL,
  745. oi_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
  746. oi_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") NOT NULL default "unknown",
  747. oi_minor_mime varbinary(100) NOT NULL default "unknown",
  748. oi_deleted tinyint unsigned NOT NULL default 0,
  749. oi_sha1 varbinary(32) NOT NULL default ''
  750. ) /*$wgDBTableOptions*/;
  751. CREATE INDEX /*i*/oi_usertext_timestamp ON /*_*/oldimage (oi_user_text,oi_timestamp);
  752. CREATE INDEX /*i*/oi_name_timestamp ON /*_*/oldimage (oi_name,oi_timestamp);
  753. -- oi_archive_name truncated to 14 to avoid key length overflow
  754. CREATE INDEX /*i*/oi_name_archive_name ON /*_*/oldimage (oi_name,oi_archive_name(14));
  755. CREATE INDEX /*i*/oi_sha1 ON /*_*/oldimage (oi_sha1(10));
  756. --
  757. -- Record of deleted file data
  758. --
  759. CREATE TABLE /*_*/filearchive (
  760. -- Unique row id
  761. fa_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
  762. -- Original base filename; key to image.img_name, page.page_title, etc
  763. fa_name varchar(255) binary NOT NULL default '',
  764. -- Filename of archived file, if an old revision
  765. fa_archive_name varchar(255) binary default '',
  766. -- Which storage bin (directory tree or object store) the file data
  767. -- is stored in. Should be 'deleted' for files that have been deleted;
  768. -- any other bin is not yet in use.
  769. fa_storage_group varbinary(16),
  770. -- SHA-1 of the file contents plus extension, used as a key for storage.
  771. -- eg 8f8a562add37052a1848ff7771a2c515db94baa9.jpg
  772. --
  773. -- If NULL, the file was missing at deletion time or has been purged
  774. -- from the archival storage.
  775. fa_storage_key varbinary(64) default '',
  776. -- Deletion information, if this file is deleted.
  777. fa_deleted_user int,
  778. fa_deleted_timestamp binary(14) default '',
  779. fa_deleted_reason varbinary(767) default '',
  780. -- Duped fields from image
  781. fa_size int unsigned default 0,
  782. fa_width int default 0,
  783. fa_height int default 0,
  784. fa_metadata mediumblob,
  785. fa_bits int default 0,
  786. fa_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
  787. fa_major_mime ENUM("unknown", "application", "audio", "image", "text", "video", "message", "model", "multipart", "chemical") default "unknown",
  788. fa_minor_mime varbinary(100) default "unknown",
  789. fa_description varbinary(767),
  790. fa_user int unsigned default 0,
  791. fa_user_text varchar(255) binary,
  792. fa_timestamp binary(14) default '',
  793. -- Visibility of deleted revisions, bitfield
  794. fa_deleted tinyint unsigned NOT NULL default 0,
  795. -- sha1 hash of file content
  796. fa_sha1 varbinary(32) NOT NULL default ''
  797. ) /*$wgDBTableOptions*/;
  798. -- pick out by image name
  799. CREATE INDEX /*i*/fa_name ON /*_*/filearchive (fa_name, fa_timestamp);
  800. -- pick out dupe files
  801. CREATE INDEX /*i*/fa_storage_group ON /*_*/filearchive (fa_storage_group, fa_storage_key);
  802. -- sort by deletion time
  803. CREATE INDEX /*i*/fa_deleted_timestamp ON /*_*/filearchive (fa_deleted_timestamp);
  804. -- sort by uploader
  805. CREATE INDEX /*i*/fa_user_timestamp ON /*_*/filearchive (fa_user_text,fa_timestamp);
  806. -- find file by sha1, 10 bytes will be enough for hashes to be indexed
  807. CREATE INDEX /*i*/fa_sha1 ON /*_*/filearchive (fa_sha1(10));
  808. --
  809. -- Store information about newly uploaded files before they're
  810. -- moved into the actual filestore
  811. --
  812. CREATE TABLE /*_*/uploadstash (
  813. us_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  814. -- the user who uploaded the file.
  815. us_user int unsigned NOT NULL,
  816. -- file key. this is how applications actually search for the file.
  817. -- this might go away, or become the primary key.
  818. us_key varchar(255) NOT NULL,
  819. -- the original path
  820. us_orig_path varchar(255) NOT NULL,
  821. -- the temporary path at which the file is actually stored
  822. us_path varchar(255) NOT NULL,
  823. -- which type of upload the file came from (sometimes)
  824. us_source_type varchar(50),
  825. -- the date/time on which the file was added
  826. us_timestamp varbinary(14) NOT NULL,
  827. us_status varchar(50) NOT NULL,
  828. -- chunk counter starts at 0, current offset is stored in us_size
  829. us_chunk_inx int unsigned NULL,
  830. -- Serialized file properties from FSFile::getProps()
  831. us_props blob,
  832. -- file size in bytes
  833. us_size int unsigned NOT NULL,
  834. -- this hash comes from FSFile::getSha1Base36(), and is 31 characters
  835. us_sha1 varchar(31) NOT NULL,
  836. us_mime varchar(255),
  837. -- Media type as defined by the MEDIATYPE_xxx constants, should duplicate definition in the image table
  838. us_media_type ENUM("UNKNOWN", "BITMAP", "DRAWING", "AUDIO", "VIDEO", "MULTIMEDIA", "OFFICE", "TEXT", "EXECUTABLE", "ARCHIVE") default NULL,
  839. -- image-specific properties
  840. us_image_width int unsigned,
  841. us_image_height int unsigned,
  842. us_image_bits smallint unsigned
  843. ) /*$wgDBTableOptions*/;
  844. -- sometimes there's a delete for all of a user's stuff.
  845. CREATE INDEX /*i*/us_user ON /*_*/uploadstash (us_user);
  846. -- pick out files by key, enforce key uniqueness
  847. CREATE UNIQUE INDEX /*i*/us_key ON /*_*/uploadstash (us_key);
  848. -- the abandoned upload cleanup script needs this
  849. CREATE INDEX /*i*/us_timestamp ON /*_*/uploadstash (us_timestamp);
  850. --
  851. -- Primarily a summary table for Special:Recentchanges,
  852. -- this table contains some additional info on edits from
  853. -- the last few days, see Article::editUpdates()
  854. --
  855. CREATE TABLE /*_*/recentchanges (
  856. rc_id int NOT NULL PRIMARY KEY AUTO_INCREMENT,
  857. rc_timestamp varbinary(14) NOT NULL default '',
  858. -- As in revision
  859. rc_user int unsigned NOT NULL default 0,
  860. rc_user_text varchar(255) binary NOT NULL,
  861. -- When pages are renamed, their RC entries do _not_ change.
  862. rc_namespace int NOT NULL default 0,
  863. rc_title varchar(255) binary NOT NULL default '',
  864. -- as in revision...
  865. rc_comment varbinary(767) NOT NULL default '',
  866. rc_minor tinyint unsigned NOT NULL default 0,
  867. -- Edits by user accounts with the 'bot' rights key are
  868. -- marked with a 1 here, and will be hidden from the
  869. -- default view.
  870. rc_bot tinyint unsigned NOT NULL default 0,
  871. -- Set if this change corresponds to a page creation
  872. rc_new tinyint unsigned NOT NULL default 0,
  873. -- Key to page_id (was cur_id prior to 1.5).
  874. -- This will keep links working after moves while
  875. -- retaining the at-the-time name in the changes list.
  876. rc_cur_id int unsigned NOT NULL default 0,
  877. -- rev_id of the given revision
  878. rc_this_oldid int unsigned NOT NULL default 0,
  879. -- rev_id of the prior revision, for generating diff links.
  880. rc_last_oldid int unsigned NOT NULL default 0,
  881. -- The type of change entry (RC_EDIT,RC_NEW,RC_LOG,RC_EXTERNAL)
  882. rc_type tinyint unsigned NOT NULL default 0,
  883. -- The source of the change entry (replaces rc_type)
  884. -- default of '' is temporary, needed for initial migration
  885. rc_source varchar(16) binary not null default '',
  886. -- If the Recent Changes Patrol option is enabled,
  887. -- users may mark edits as having been reviewed to
  888. -- remove a warning flag on the RC list.
  889. -- A value of 1 indicates the page has been reviewed.
  890. rc_patrolled tinyint unsigned NOT NULL default 0,
  891. -- Recorded IP address the edit was made from, if the
  892. -- $wgPutIPinRC option is enabled.
  893. rc_ip varbinary(40) NOT NULL default '',
  894. -- Text length in characters before
  895. -- and after the edit
  896. rc_old_len int,
  897. rc_new_len int,
  898. -- Visibility of recent changes items, bitfield
  899. rc_deleted tinyint unsigned NOT NULL default 0,
  900. -- Value corresponding to log_id, specific log entries
  901. rc_logid int unsigned NOT NULL default 0,
  902. -- Store log type info here, or null
  903. rc_log_type varbinary(255) NULL default NULL,
  904. -- Store log action or null
  905. rc_log_action varbinary(255) NULL default NULL,
  906. -- Log params
  907. rc_params blob NULL
  908. ) /*$wgDBTableOptions*/;
  909. CREATE INDEX /*i*/rc_timestamp ON /*_*/recentchanges (rc_timestamp);
  910. CREATE INDEX /*i*/rc_namespace_title ON /*_*/recentchanges (rc_namespace, rc_title);
  911. CREATE INDEX /*i*/rc_cur_id ON /*_*/recentchanges (rc_cur_id);
  912. CREATE INDEX /*i*/new_name_timestamp ON /*_*/recentchanges (rc_new,rc_namespace,rc_timestamp);
  913. CREATE INDEX /*i*/rc_ip ON /*_*/recentchanges (rc_ip);
  914. CREATE INDEX /*i*/rc_ns_usertext ON /*_*/recentchanges (rc_namespace, rc_user_text);
  915. CREATE INDEX /*i*/rc_user_text ON /*_*/recentchanges (rc_user_text, rc_timestamp);
  916. CREATE INDEX /*i*/rc_name_type_patrolled_timestamp ON /*_*/recentchanges (rc_namespace, rc_type, rc_patrolled, rc_timestamp);
  917. CREATE TABLE /*_*/watchlist (
  918. wl_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  919. -- Key to user.user_id
  920. wl_user int unsigned NOT NULL,
  921. -- Key to page_namespace/page_title
  922. -- Note that users may watch pages which do not exist yet,
  923. -- or existed in the past but have been deleted.
  924. wl_namespace int NOT NULL default 0,
  925. wl_title varchar(255) binary NOT NULL default '',
  926. -- Timestamp used to send notification e-mails and show "updated since last visit" markers on
  927. -- history and recent changes / watchlist. Set to NULL when the user visits the latest revision
  928. -- of the page, which means that they should be sent an e-mail on the next change.
  929. wl_notificationtimestamp varbinary(14)
  930. ) /*$wgDBTableOptions*/;
  931. CREATE UNIQUE INDEX /*i*/wl_user ON /*_*/watchlist (wl_user, wl_namespace, wl_title);
  932. CREATE INDEX /*i*/namespace_title ON /*_*/watchlist (wl_namespace, wl_title);
  933. CREATE INDEX /*i*/wl_user_notificationtimestamp ON /*_*/watchlist (wl_user, wl_notificationtimestamp);
  934. --
  935. -- When using the default MySQL search backend, page titles
  936. -- and text are munged to strip markup, do Unicode case folding,
  937. -- and prepare the result for MySQL's fulltext index.
  938. --
  939. -- This table must be MyISAM; InnoDB does not support the needed
  940. -- fulltext index.
  941. --
  942. CREATE TABLE /*_*/searchindex (
  943. -- Key to page_id
  944. si_page int unsigned NOT NULL,
  945. -- Munged version of title
  946. si_title varchar(255) NOT NULL default '',
  947. -- Munged version of body text
  948. si_text mediumtext NOT NULL
  949. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  950. CREATE UNIQUE INDEX /*i*/si_page ON /*_*/searchindex (si_page);
  951. CREATE FULLTEXT INDEX /*i*/si_title ON /*_*/searchindex (si_title);
  952. CREATE FULLTEXT INDEX /*i*/si_text ON /*_*/searchindex (si_text);
  953. --
  954. -- Recognized interwiki link prefixes
  955. --
  956. CREATE TABLE /*_*/interwiki (
  957. -- The interwiki prefix, (e.g. "Meatball", or the language prefix "de")
  958. iw_prefix varchar(32) NOT NULL,
  959. -- The URL of the wiki, with "$1" as a placeholder for an article name.
  960. -- Any spaces in the name will be transformed to underscores before
  961. -- insertion.
  962. iw_url blob NOT NULL,
  963. -- The URL of the file api.php
  964. iw_api blob NOT NULL,
  965. -- The name of the database (for a connection to be established with wfGetLB( 'wikiid' ))
  966. iw_wikiid varchar(64) NOT NULL,
  967. -- A boolean value indicating whether the wiki is in this project
  968. -- (used, for example, to detect redirect loops)
  969. iw_local bool NOT NULL,
  970. -- Boolean value indicating whether interwiki transclusions are allowed.
  971. iw_trans tinyint NOT NULL default 0
  972. ) /*$wgDBTableOptions*/;
  973. CREATE UNIQUE INDEX /*i*/iw_prefix ON /*_*/interwiki (iw_prefix);
  974. --
  975. -- Used for caching expensive grouped queries
  976. --
  977. CREATE TABLE /*_*/querycache (
  978. -- A key name, generally the base name of of the special page.
  979. qc_type varbinary(32) NOT NULL,
  980. -- Some sort of stored value. Sizes, counts...
  981. qc_value int unsigned NOT NULL default 0,
  982. -- Target namespace+title
  983. qc_namespace int NOT NULL default 0,
  984. qc_title varchar(255) binary NOT NULL default ''
  985. ) /*$wgDBTableOptions*/;
  986. CREATE INDEX /*i*/qc_type ON /*_*/querycache (qc_type,qc_value);
  987. --
  988. -- For a few generic cache operations if not using Memcached
  989. --
  990. CREATE TABLE /*_*/objectcache (
  991. keyname varbinary(255) NOT NULL default '' PRIMARY KEY,
  992. value mediumblob,
  993. exptime datetime
  994. ) /*$wgDBTableOptions*/;
  995. CREATE INDEX /*i*/exptime ON /*_*/objectcache (exptime);
  996. --
  997. -- Cache of interwiki transclusion
  998. --
  999. CREATE TABLE /*_*/transcache (
  1000. tc_url varbinary(255) NOT NULL,
  1001. tc_contents text,
  1002. tc_time binary(14) NOT NULL
  1003. ) /*$wgDBTableOptions*/;
  1004. CREATE UNIQUE INDEX /*i*/tc_url_idx ON /*_*/transcache (tc_url);
  1005. CREATE TABLE /*_*/logging (
  1006. -- Log ID, for referring to this specific log entry, probably for deletion and such.
  1007. log_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  1008. -- Symbolic keys for the general log type and the action type
  1009. -- within the log. The output format will be controlled by the
  1010. -- action field, but only the type controls categorization.
  1011. log_type varbinary(32) NOT NULL default '',
  1012. log_action varbinary(32) NOT NULL default '',
  1013. -- Timestamp. Duh.
  1014. log_timestamp binary(14) NOT NULL default '19700101000000',
  1015. -- The user who performed this action; key to user_id
  1016. log_user int unsigned NOT NULL default 0,
  1017. -- Name of the user who performed this action
  1018. log_user_text varchar(255) binary NOT NULL default '',
  1019. -- Key to the page affected. Where a user is the target,
  1020. -- this will point to the user page.
  1021. log_namespace int NOT NULL default 0,
  1022. log_title varchar(255) binary NOT NULL default '',
  1023. log_page int unsigned NULL,
  1024. -- Freeform text. Interpreted as edit history comments.
  1025. log_comment varbinary(767) NOT NULL default '',
  1026. -- miscellaneous parameters:
  1027. -- LF separated list (old system) or serialized PHP array (new system)
  1028. log_params blob NOT NULL,
  1029. -- rev_deleted for logs
  1030. log_deleted tinyint unsigned NOT NULL default 0
  1031. ) /*$wgDBTableOptions*/;
  1032. CREATE INDEX /*i*/type_time ON /*_*/logging (log_type, log_timestamp);
  1033. CREATE INDEX /*i*/user_time ON /*_*/logging (log_user, log_timestamp);
  1034. CREATE INDEX /*i*/page_time ON /*_*/logging (log_namespace, log_title, log_timestamp);
  1035. CREATE INDEX /*i*/times ON /*_*/logging (log_timestamp);
  1036. CREATE INDEX /*i*/log_user_type_time ON /*_*/logging (log_user, log_type, log_timestamp);
  1037. CREATE INDEX /*i*/log_page_id_time ON /*_*/logging (log_page,log_timestamp);
  1038. CREATE INDEX /*i*/type_action ON /*_*/logging (log_type, log_action, log_timestamp);
  1039. CREATE INDEX /*i*/log_user_text_type_time ON /*_*/logging (log_user_text, log_type, log_timestamp);
  1040. CREATE INDEX /*i*/log_user_text_time ON /*_*/logging (log_user_text, log_timestamp);
  1041. CREATE TABLE /*_*/log_search (
  1042. -- The type of ID (rev ID, log ID, rev timestamp, username)
  1043. ls_field varbinary(32) NOT NULL,
  1044. -- The value of the ID
  1045. ls_value varchar(255) NOT NULL,
  1046. -- Key to log_id
  1047. ls_log_id int unsigned NOT NULL default 0
  1048. ) /*$wgDBTableOptions*/;
  1049. CREATE UNIQUE INDEX /*i*/ls_field_val ON /*_*/log_search (ls_field,ls_value,ls_log_id);
  1050. CREATE INDEX /*i*/ls_log_id ON /*_*/log_search (ls_log_id);
  1051. -- Jobs performed by parallel apache threads or a command-line daemon
  1052. CREATE TABLE /*_*/job (
  1053. job_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  1054. -- Command name
  1055. -- Limited to 60 to prevent key length overflow
  1056. job_cmd varbinary(60) NOT NULL default '',
  1057. -- Namespace and title to act on
  1058. -- Should be 0 and '' if the command does not operate on a title
  1059. job_namespace int NOT NULL,
  1060. job_title varchar(255) binary NOT NULL,
  1061. -- Timestamp of when the job was inserted
  1062. -- NULL for jobs added before addition of the timestamp
  1063. job_timestamp varbinary(14) NULL default NULL,
  1064. -- Any other parameters to the command
  1065. -- Stored as a PHP serialized array, or an empty string if there are no parameters
  1066. job_params blob NOT NULL,
  1067. -- Random, non-unique, number used for job acquisition (for lock concurrency)
  1068. job_random integer unsigned NOT NULL default 0,
  1069. -- The number of times this job has been locked
  1070. job_attempts integer unsigned NOT NULL default 0,
  1071. -- Field that conveys process locks on rows via process UUIDs
  1072. job_token varbinary(32) NOT NULL default '',
  1073. -- Timestamp when the job was locked
  1074. job_token_timestamp varbinary(14) NULL default NULL,
  1075. -- Base 36 SHA1 of the job parameters relevant to detecting duplicates
  1076. job_sha1 varbinary(32) NOT NULL default ''
  1077. ) /*$wgDBTableOptions*/;
  1078. CREATE INDEX /*i*/job_sha1 ON /*_*/job (job_sha1);
  1079. CREATE INDEX /*i*/job_cmd_token ON /*_*/job (job_cmd,job_token,job_random);
  1080. CREATE INDEX /*i*/job_cmd_token_id ON /*_*/job (job_cmd,job_token,job_id);
  1081. CREATE INDEX /*i*/job_cmd ON /*_*/job (job_cmd, job_namespace, job_title, job_params(128));
  1082. CREATE INDEX /*i*/job_timestamp ON /*_*/job (job_timestamp);
  1083. -- Details of updates to cached special pages
  1084. CREATE TABLE /*_*/querycache_info (
  1085. -- Special page name
  1086. -- Corresponds to a qc_type value
  1087. qci_type varbinary(32) NOT NULL default '',
  1088. -- Timestamp of last update
  1089. qci_timestamp binary(14) NOT NULL default '19700101000000'
  1090. ) /*$wgDBTableOptions*/;
  1091. CREATE UNIQUE INDEX /*i*/qci_type ON /*_*/querycache_info (qci_type);
  1092. -- For each redirect, this table contains exactly one row defining its target
  1093. CREATE TABLE /*_*/redirect (
  1094. -- Key to the page_id of the redirect page
  1095. rd_from int unsigned NOT NULL default 0 PRIMARY KEY,
  1096. -- Key to page_namespace/page_title of the target page.
  1097. -- The target page may or may not exist, and due to renames
  1098. -- and deletions may refer to different page records as time
  1099. -- goes by.
  1100. rd_namespace int NOT NULL default 0,
  1101. rd_title varchar(255) binary NOT NULL default '',
  1102. rd_interwiki varchar(32) default NULL,
  1103. rd_fragment varchar(255) binary default NULL
  1104. ) /*$wgDBTableOptions*/;
  1105. CREATE INDEX /*i*/rd_ns_title ON /*_*/redirect (rd_namespace,rd_title,rd_from);
  1106. -- Used for caching expensive grouped queries that need two links (for example double-redirects)
  1107. CREATE TABLE /*_*/querycachetwo (
  1108. -- A key name, generally the base name of of the special page.
  1109. qcc_type varbinary(32) NOT NULL,
  1110. -- Some sort of stored value. Sizes, counts...
  1111. qcc_value int unsigned NOT NULL default 0,
  1112. -- Target namespace+title
  1113. qcc_namespace int NOT NULL default 0,
  1114. qcc_title varchar(255) binary NOT NULL default '',
  1115. -- Target namespace+title2
  1116. qcc_namespacetwo int NOT NULL default 0,
  1117. qcc_titletwo varchar(255) binary NOT NULL default ''
  1118. ) /*$wgDBTableOptions*/;
  1119. CREATE INDEX /*i*/qcc_type ON /*_*/querycachetwo (qcc_type,qcc_value);
  1120. CREATE INDEX /*i*/qcc_title ON /*_*/querycachetwo (qcc_type,qcc_namespace,qcc_title);
  1121. CREATE INDEX /*i*/qcc_titletwo ON /*_*/querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
  1122. -- Used for storing page restrictions (i.e. protection levels)
  1123. CREATE TABLE /*_*/page_restrictions (
  1124. -- Field for an ID for this restrictions row (sort-key for Special:ProtectedPages)
  1125. pr_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  1126. -- Page to apply restrictions to (Foreign Key to page).
  1127. pr_page int NOT NULL,
  1128. -- The protection type (edit, move, etc)
  1129. pr_type varbinary(60) NOT NULL,
  1130. -- The protection level (Sysop, autoconfirmed, etc)
  1131. pr_level varbinary(60) NOT NULL,
  1132. -- Whether or not to cascade the protection down to pages transcluded.
  1133. pr_cascade tinyint NOT NULL,
  1134. -- Field for future support of per-user restriction.
  1135. pr_user int NULL,
  1136. -- Field for time-limited protection.
  1137. pr_expiry varbinary(14) NULL
  1138. ) /*$wgDBTableOptions*/;
  1139. CREATE UNIQUE INDEX /*i*/pr_pagetype ON /*_*/page_restrictions (pr_page,pr_type);
  1140. CREATE INDEX /*i*/pr_typelevel ON /*_*/page_restrictions (pr_type,pr_level);
  1141. CREATE INDEX /*i*/pr_level ON /*_*/page_restrictions (pr_level);
  1142. CREATE INDEX /*i*/pr_cascade ON /*_*/page_restrictions (pr_cascade);
  1143. -- Protected titles - nonexistent pages that have been protected
  1144. CREATE TABLE /*_*/protected_titles (
  1145. pt_namespace int NOT NULL,
  1146. pt_title varchar(255) binary NOT NULL,
  1147. pt_user int unsigned NOT NULL,
  1148. pt_reason varbinary(767),
  1149. pt_timestamp binary(14) NOT NULL,
  1150. pt_expiry varbinary(14) NOT NULL default '',
  1151. pt_create_perm varbinary(60) NOT NULL
  1152. ) /*$wgDBTableOptions*/;
  1153. CREATE UNIQUE INDEX /*i*/pt_namespace_title ON /*_*/protected_titles (pt_namespace,pt_title);
  1154. CREATE INDEX /*i*/pt_timestamp ON /*_*/protected_titles (pt_timestamp);
  1155. -- Name/value pairs indexed by page_id
  1156. CREATE TABLE /*_*/page_props (
  1157. pp_page int NOT NULL,
  1158. pp_propname varbinary(60) NOT NULL,
  1159. pp_value blob NOT NULL,
  1160. pp_sortkey float DEFAULT NULL
  1161. ) /*$wgDBTableOptions*/;
  1162. CREATE UNIQUE INDEX /*i*/pp_page_propname ON /*_*/page_props (pp_page,pp_propname);
  1163. CREATE UNIQUE INDEX /*i*/pp_propname_page ON /*_*/page_props (pp_propname,pp_page);
  1164. CREATE UNIQUE INDEX /*i*/pp_propname_sortkey_page ON /*_*/page_props (pp_propname,pp_sortkey,pp_page);
  1165. -- A table to log updates, one text key row per update.
  1166. CREATE TABLE /*_*/updatelog (
  1167. ul_key varchar(255) NOT NULL PRIMARY KEY,
  1168. ul_value blob
  1169. ) /*$wgDBTableOptions*/;
  1170. -- A table to track tags for revisions, logs and recent changes.
  1171. CREATE TABLE /*_*/change_tag (
  1172. ct_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  1173. -- RCID for the change
  1174. ct_rc_id int NULL,
  1175. -- LOGID for the change
  1176. ct_log_id int NULL,
  1177. -- REVID for the change
  1178. ct_rev_id int NULL,
  1179. -- Tag applied
  1180. ct_tag varchar(255) NOT NULL,
  1181. -- Parameters for the tag, presently unused
  1182. ct_params blob NULL
  1183. ) /*$wgDBTableOptions*/;
  1184. CREATE UNIQUE INDEX /*i*/change_tag_rc_tag ON /*_*/change_tag (ct_rc_id,ct_tag);
  1185. CREATE UNIQUE INDEX /*i*/change_tag_log_tag ON /*_*/change_tag (ct_log_id,ct_tag);
  1186. CREATE UNIQUE INDEX /*i*/change_tag_rev_tag ON /*_*/change_tag (ct_rev_id,ct_tag);
  1187. -- Covering index, so we can pull all the info only out of the index.
  1188. CREATE INDEX /*i*/change_tag_tag_id ON /*_*/change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
  1189. -- Rollup table to pull a LIST of tags simply without ugly GROUP_CONCAT
  1190. -- that only works on MySQL 4.1+
  1191. CREATE TABLE /*_*/tag_summary (
  1192. ts_id int unsigned NOT NULL PRIMARY KEY AUTO_INCREMENT,
  1193. -- RCID for the change
  1194. ts_rc_id int NULL,
  1195. -- LOGID for the change
  1196. ts_log_id int NULL,
  1197. -- REVID for the change
  1198. ts_rev_id int NULL,
  1199. -- Comma-separated list of tags
  1200. ts_tags blob NOT NULL
  1201. ) /*$wgDBTableOptions*/;
  1202. CREATE UNIQUE INDEX /*i*/tag_summary_rc_id ON /*_*/tag_summary (ts_rc_id);
  1203. CREATE UNIQUE INDEX /*i*/tag_summary_log_id ON /*_*/tag_summary (ts_log_id);
  1204. CREATE UNIQUE INDEX /*i*/tag_summary_rev_id ON /*_*/tag_summary (ts_rev_id);
  1205. CREATE TABLE /*_*/valid_tag (
  1206. vt_tag varchar(255) NOT NULL PRIMARY KEY
  1207. ) /*$wgDBTableOptions*/;
  1208. -- Table for storing localisation data
  1209. CREATE TABLE /*_*/l10n_cache (
  1210. -- Language code
  1211. lc_lang varbinary(32) NOT NULL,
  1212. -- Cache key
  1213. lc_key varchar(255) NOT NULL,
  1214. -- Value
  1215. lc_value mediumblob NOT NULL
  1216. ) /*$wgDBTableOptions*/;
  1217. CREATE INDEX /*i*/lc_lang_key ON /*_*/l10n_cache (lc_lang, lc_key);
  1218. -- Table caching which local files a module depends on that aren't
  1219. -- registered directly, used for fast retrieval of file dependency.
  1220. -- Currently only used for tracking images that CSS depends on
  1221. CREATE TABLE /*_*/module_deps (
  1222. -- Module name
  1223. md_module varbinary(255) NOT NULL,
  1224. -- Module context vary (includes skin and language; called "md_skin" for legacy reasons)
  1225. md_skin varbinary(32) NOT NULL,
  1226. -- JSON blob with file dependencies
  1227. md_deps mediumblob NOT NULL
  1228. ) /*$wgDBTableOptions*/;
  1229. CREATE UNIQUE INDEX /*i*/md_module_skin ON /*_*/module_deps (md_module, md_skin);
  1230. -- Holds all the sites known to the wiki.
  1231. CREATE TABLE /*_*/sites (
  1232. -- Numeric id of the site
  1233. site_id INT UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
  1234. -- Global identifier for the site, ie 'enwiktionary'
  1235. site_global_key varbinary(32) NOT NULL,
  1236. -- Type of the site, ie 'mediawiki'
  1237. site_type varbinary(32) NOT NULL,
  1238. -- Group of the site, ie 'wikipedia'
  1239. site_group varbinary(32) NOT NULL,
  1240. -- Source of the site data, ie 'local', 'wikidata', 'my-magical-repo'
  1241. site_source varbinary(32) NOT NULL,
  1242. -- Language code of the sites primary language.
  1243. site_language varbinary(32) NOT NULL,
  1244. -- Protocol of the site, ie 'http://', 'irc://', '//'
  1245. -- This field is an index for lookups and is build from type specific data in site_data.
  1246. site_protocol varbinary(32) NOT NULL,
  1247. -- Domain of the site in reverse order, ie 'org.mediawiki.www.'
  1248. -- This field is an index for lookups and is build from type specific data in site_data.
  1249. site_domain VARCHAR(255) NOT NULL,
  1250. -- Type dependent site data.
  1251. site_data BLOB NOT NULL,
  1252. -- If site.tld/path/key:pageTitle should forward users to the page on
  1253. -- the actual site, where "key" is the local identifier.
  1254. site_forward bool NOT NULL,
  1255. -- Type dependent site config.
  1256. -- For instance if template transclusion should be allowed if it's a MediaWiki.
  1257. site_config BLOB NOT NULL
  1258. ) /*$wgDBTableOptions*/;
  1259. CREATE UNIQUE INDEX /*i*/sites_global_key ON /*_*/sites (site_global_key);
  1260. CREATE INDEX /*i*/sites_type ON /*_*/sites (site_type);
  1261. CREATE INDEX /*i*/sites_group ON /*_*/sites (site_group);
  1262. CREATE INDEX /*i*/sites_source ON /*_*/sites (site_source);
  1263. CREATE INDEX /*i*/sites_language ON /*_*/sites (site_language);
  1264. CREATE INDEX /*i*/sites_protocol ON /*_*/sites (site_protocol);
  1265. CREATE INDEX /*i*/sites_domain ON /*_*/sites (site_domain);
  1266. CREATE INDEX /*i*/sites_forward ON /*_*/sites (site_forward);
  1267. -- Links local site identifiers to their corresponding site.
  1268. CREATE TABLE /*_*/site_identifiers (
  1269. -- Key on site.site_id
  1270. si_site INT UNSIGNED NOT NULL,
  1271. -- local key type, ie 'interwiki' or 'langlink'
  1272. si_type varbinary(32) NOT NULL,
  1273. -- local key value, ie 'en' or 'wiktionary'
  1274. si_key varbinary(32) NOT NULL
  1275. ) /*$wgDBTableOptions*/;
  1276. CREATE UNIQUE INDEX /*i*/site_ids_type ON /*_*/site_identifiers (si_type, si_key);
  1277. CREATE INDEX /*i*/site_ids_site ON /*_*/site_identifiers (si_site);
  1278. CREATE INDEX /*i*/site_ids_key ON /*_*/site_identifiers (si_key);
  1279. -- vim: sw=2 sts=2 et