mysql.sql 11 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323
  1. --
  2. -- Elgg database schema
  3. --
  4. -- record membership in an access collection
  5. CREATE TABLE `prefix_access_collection_membership` (
  6. `user_guid` int(11) NOT NULL,
  7. `access_collection_id` int(11) NOT NULL,
  8. PRIMARY KEY (`user_guid`,`access_collection_id`)
  9. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  10. -- define an access collection
  11. CREATE TABLE `prefix_access_collections` (
  12. `id` int(11) NOT NULL AUTO_INCREMENT,
  13. `name` text NOT NULL,
  14. `owner_guid` bigint(20) unsigned NOT NULL,
  15. `site_guid` bigint(20) unsigned NOT NULL DEFAULT '0',
  16. PRIMARY KEY (`id`),
  17. KEY `owner_guid` (`owner_guid`),
  18. KEY `site_guid` (`site_guid`)
  19. ) ENGINE=MyISAM AUTO_INCREMENT=3 DEFAULT CHARSET=utf8;
  20. -- store an annotation on an entity
  21. CREATE TABLE `prefix_annotations` (
  22. `id` int(11) NOT NULL AUTO_INCREMENT,
  23. `entity_guid` bigint(20) unsigned NOT NULL,
  24. `name_id` int(11) NOT NULL,
  25. `value_id` int(11) NOT NULL,
  26. `value_type` enum('integer','text') NOT NULL,
  27. `owner_guid` bigint(20) unsigned NOT NULL,
  28. `access_id` int(11) NOT NULL,
  29. `time_created` int(11) NOT NULL,
  30. `enabled` enum('yes','no') NOT NULL DEFAULT 'yes',
  31. PRIMARY KEY (`id`),
  32. KEY `entity_guid` (`entity_guid`),
  33. KEY `name_id` (`name_id`),
  34. KEY `value_id` (`value_id`),
  35. KEY `owner_guid` (`owner_guid`),
  36. KEY `access_id` (`access_id`)
  37. ) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
  38. -- api keys for old web services
  39. CREATE TABLE `prefix_api_users` (
  40. `id` int(11) NOT NULL AUTO_INCREMENT,
  41. `site_guid` bigint(20) unsigned DEFAULT NULL,
  42. `api_key` varchar(40) DEFAULT NULL,
  43. `secret` varchar(40) NOT NULL,
  44. `active` int(1) DEFAULT '1',
  45. PRIMARY KEY (`id`),
  46. UNIQUE KEY `api_key` (`api_key`)
  47. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  48. -- site specific configuration
  49. CREATE TABLE `prefix_config` (
  50. `name` varchar(255) NOT NULL,
  51. `value` text NOT NULL,
  52. `site_guid` int(11) NOT NULL,
  53. PRIMARY KEY (`name`,`site_guid`)
  54. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  55. -- application specific configuration
  56. CREATE TABLE `prefix_datalists` (
  57. `name` varchar(255) NOT NULL,
  58. `value` text NOT NULL,
  59. PRIMARY KEY (`name`)
  60. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  61. -- primary entity table
  62. CREATE TABLE `prefix_entities` (
  63. `guid` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
  64. `type` enum('object','user','group','site') NOT NULL,
  65. `subtype` int(11) DEFAULT NULL,
  66. `owner_guid` bigint(20) unsigned NOT NULL,
  67. `site_guid` bigint(20) unsigned NOT NULL,
  68. `container_guid` bigint(20) unsigned NOT NULL,
  69. `access_id` int(11) NOT NULL,
  70. `time_created` int(11) NOT NULL,
  71. `time_updated` int(11) NOT NULL,
  72. `last_action` int(11) NOT NULL DEFAULT '0',
  73. `enabled` enum('yes','no') NOT NULL DEFAULT 'yes',
  74. PRIMARY KEY (`guid`),
  75. KEY `type` (`type`),
  76. KEY `subtype` (`subtype`),
  77. KEY `owner_guid` (`owner_guid`),
  78. KEY `site_guid` (`site_guid`),
  79. KEY `container_guid` (`container_guid`),
  80. KEY `access_id` (`access_id`),
  81. KEY `time_created` (`time_created`),
  82. KEY `time_updated` (`time_updated`)
  83. ) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
  84. -- relationships between entities
  85. CREATE TABLE `prefix_entity_relationships` (
  86. `id` int(11) NOT NULL AUTO_INCREMENT,
  87. `guid_one` bigint(20) unsigned NOT NULL,
  88. `relationship` varchar(50) NOT NULL,
  89. `guid_two` bigint(20) unsigned NOT NULL,
  90. `time_created` int(11) NOT NULL,
  91. PRIMARY KEY (`id`),
  92. UNIQUE KEY `guid_one` (`guid_one`,`relationship`,`guid_two`),
  93. KEY `relationship` (`relationship`),
  94. KEY `guid_two` (`guid_two`)
  95. ) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
  96. -- entity type/subtype pairs
  97. CREATE TABLE `prefix_entity_subtypes` (
  98. `id` int(11) NOT NULL AUTO_INCREMENT,
  99. `type` enum('object','user','group','site') NOT NULL,
  100. `subtype` varchar(50) NOT NULL,
  101. `class` varchar(50) NOT NULL DEFAULT '',
  102. PRIMARY KEY (`id`),
  103. UNIQUE KEY `type` (`type`,`subtype`)
  104. ) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
  105. -- cache lookups of latitude and longitude for place names
  106. CREATE TABLE `prefix_geocode_cache` (
  107. `id` int(11) NOT NULL AUTO_INCREMENT,
  108. `location` varchar(128) DEFAULT NULL,
  109. `lat` varchar(20) DEFAULT NULL,
  110. `long` varchar(20) DEFAULT NULL,
  111. PRIMARY KEY (`id`),
  112. UNIQUE KEY `location` (`location`)
  113. ) ENGINE=MEMORY DEFAULT CHARSET=utf8;
  114. -- secondary table for group entities
  115. CREATE TABLE `prefix_groups_entity` (
  116. `guid` bigint(20) unsigned NOT NULL,
  117. `name` text NOT NULL,
  118. `description` text NOT NULL,
  119. PRIMARY KEY (`guid`),
  120. KEY `name` (`name`(50)),
  121. KEY `description` (`description`(50)),
  122. FULLTEXT KEY `name_2` (`name`,`description`)
  123. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  124. -- cache for hmac signatures for old web services
  125. CREATE TABLE `prefix_hmac_cache` (
  126. `hmac` varchar(255) NOT NULL,
  127. `ts` int(11) NOT NULL,
  128. PRIMARY KEY (`hmac`),
  129. KEY `ts` (`ts`)
  130. ) ENGINE=MEMORY DEFAULT CHARSET=utf8;
  131. -- metadata that describes an entity
  132. CREATE TABLE `prefix_metadata` (
  133. `id` int(11) NOT NULL AUTO_INCREMENT,
  134. `entity_guid` bigint(20) unsigned NOT NULL,
  135. `name_id` int(11) NOT NULL,
  136. `value_id` int(11) NOT NULL,
  137. `value_type` enum('integer','text') NOT NULL,
  138. `owner_guid` bigint(20) unsigned NOT NULL,
  139. `access_id` int(11) NOT NULL,
  140. `time_created` int(11) NOT NULL,
  141. `enabled` enum('yes','no') NOT NULL DEFAULT 'yes',
  142. PRIMARY KEY (`id`),
  143. KEY `entity_guid` (`entity_guid`),
  144. KEY `name_id` (`name_id`),
  145. KEY `value_id` (`value_id`),
  146. KEY `owner_guid` (`owner_guid`),
  147. KEY `access_id` (`access_id`)
  148. ) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
  149. -- string normalization table for metadata and annotations
  150. CREATE TABLE `prefix_metastrings` (
  151. `id` int(11) NOT NULL AUTO_INCREMENT,
  152. `string` text NOT NULL,
  153. PRIMARY KEY (`id`),
  154. KEY `string` (`string`(50))
  155. ) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
  156. -- secondary table for object entities
  157. CREATE TABLE `prefix_objects_entity` (
  158. `guid` bigint(20) unsigned NOT NULL,
  159. `title` text NOT NULL,
  160. `description` text NOT NULL,
  161. PRIMARY KEY (`guid`),
  162. FULLTEXT KEY `title` (`title`,`description`)
  163. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  164. -- settings for an entity
  165. CREATE TABLE `prefix_private_settings` (
  166. `id` int(11) NOT NULL AUTO_INCREMENT,
  167. `entity_guid` int(11) NOT NULL,
  168. `name` varchar(128) NOT NULL,
  169. `value` text NOT NULL,
  170. PRIMARY KEY (`id`),
  171. UNIQUE KEY `entity_guid` (`entity_guid`,`name`),
  172. KEY `name` (`name`),
  173. KEY `value` (`value`(50))
  174. ) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
  175. -- queue for asynchronous operations
  176. CREATE TABLE `prefix_queue` (
  177. `id` int(11) NOT NULL AUTO_INCREMENT,
  178. `name` varchar(255) NOT NULL,
  179. `data` mediumblob NOT NULL,
  180. `timestamp` int(11) NOT NULL,
  181. `worker` varchar(32) NULL,
  182. PRIMARY KEY (`id`),
  183. KEY `name` (`name`),
  184. KEY `retrieve` (`timestamp`,`worker`)
  185. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  186. -- activity stream
  187. CREATE TABLE `prefix_river` (
  188. `id` int(11) NOT NULL AUTO_INCREMENT,
  189. `type` varchar(8) NOT NULL,
  190. `subtype` varchar(32) NOT NULL,
  191. `action_type` varchar(32) NOT NULL,
  192. `access_id` int(11) NOT NULL,
  193. `view` text NOT NULL,
  194. `subject_guid` int(11) NOT NULL,
  195. `object_guid` int(11) NOT NULL,
  196. `target_guid` int(11) NOT NULL,
  197. `annotation_id` int(11) NOT NULL,
  198. `posted` int(11) NOT NULL,
  199. `enabled` enum('yes','no') NOT NULL DEFAULT 'yes',
  200. PRIMARY KEY (`id`),
  201. KEY `type` (`type`),
  202. KEY `action_type` (`action_type`),
  203. KEY `access_id` (`access_id`),
  204. KEY `subject_guid` (`subject_guid`),
  205. KEY `object_guid` (`object_guid`),
  206. KEY `target_guid` (`target_guid`),
  207. KEY `annotation_id` (`annotation_id`),
  208. KEY `posted` (`posted`)
  209. ) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
  210. -- secondary table for site entities
  211. CREATE TABLE `prefix_sites_entity` (
  212. `guid` bigint(20) unsigned NOT NULL,
  213. `name` text NOT NULL,
  214. `description` text NOT NULL,
  215. `url` varchar(255) NOT NULL,
  216. PRIMARY KEY (`guid`),
  217. UNIQUE KEY `url` (`url`),
  218. FULLTEXT KEY `name` (`name`,`description`,`url`)
  219. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  220. -- log activity for the admin
  221. CREATE TABLE `prefix_system_log` (
  222. `id` int(11) NOT NULL AUTO_INCREMENT,
  223. `object_id` int(11) NOT NULL,
  224. `object_class` varchar(50) NOT NULL,
  225. `object_type` varchar(50) NOT NULL,
  226. `object_subtype` varchar(50) NOT NULL,
  227. `event` varchar(50) NOT NULL,
  228. `performed_by_guid` int(11) NOT NULL,
  229. `owner_guid` int(11) NOT NULL,
  230. `access_id` int(11) NOT NULL,
  231. `enabled` enum('yes','no') NOT NULL DEFAULT 'yes',
  232. `time_created` int(11) NOT NULL,
  233. `ip_address` varchar(46) NOT NULL,
  234. PRIMARY KEY (`id`),
  235. KEY `object_id` (`object_id`),
  236. KEY `object_class` (`object_class`),
  237. KEY `object_type` (`object_type`),
  238. KEY `object_subtype` (`object_subtype`),
  239. KEY `event` (`event`),
  240. KEY `performed_by_guid` (`performed_by_guid`),
  241. KEY `access_id` (`access_id`),
  242. KEY `time_created` (`time_created`),
  243. KEY `river_key` (`object_type`,`object_subtype`,`event`)
  244. ) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
  245. -- session table for old web services
  246. CREATE TABLE `prefix_users_apisessions` (
  247. `id` int(11) NOT NULL AUTO_INCREMENT,
  248. `user_guid` bigint(20) unsigned NOT NULL,
  249. `site_guid` bigint(20) unsigned NOT NULL,
  250. `token` varchar(40) DEFAULT NULL,
  251. `expires` int(11) NOT NULL,
  252. PRIMARY KEY (`id`),
  253. UNIQUE KEY `user_guid` (`user_guid`,`site_guid`),
  254. KEY `token` (`token`)
  255. ) ENGINE=MEMORY DEFAULT CHARSET=utf8;
  256. -- secondary table for user entities
  257. CREATE TABLE `prefix_users_entity` (
  258. `guid` bigint(20) unsigned NOT NULL,
  259. `name` text NOT NULL,
  260. `username` varchar(128) NOT NULL DEFAULT '',
  261. `password` varchar(32) NOT NULL DEFAULT '' COMMENT 'Legacy password hashes',
  262. `salt` varchar(8) NOT NULL DEFAULT '' COMMENT 'Legacy password salts',
  263. -- 255 chars is recommended by PHP.net to hold future hash formats
  264. `password_hash` varchar(255) NOT NULL DEFAULT '',
  265. `email` text NOT NULL,
  266. `language` varchar(6) NOT NULL DEFAULT '',
  267. `banned` enum('yes','no') NOT NULL DEFAULT 'no',
  268. `admin` enum('yes','no') NOT NULL DEFAULT 'no',
  269. `last_action` int(11) NOT NULL DEFAULT '0',
  270. `prev_last_action` int(11) NOT NULL DEFAULT '0',
  271. `last_login` int(11) NOT NULL DEFAULT '0',
  272. `prev_last_login` int(11) NOT NULL DEFAULT '0',
  273. PRIMARY KEY (`guid`),
  274. UNIQUE KEY `username` (`username`),
  275. KEY `password` (`password`),
  276. KEY `email` (`email`(50)),
  277. KEY `last_action` (`last_action`),
  278. KEY `last_login` (`last_login`),
  279. KEY `admin` (`admin`),
  280. FULLTEXT KEY `name` (`name`),
  281. FULLTEXT KEY `name_2` (`name`,`username`)
  282. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  283. -- user remember me cookies
  284. CREATE TABLE `prefix_users_remember_me_cookies` (
  285. `code` varchar(32) NOT NULL,
  286. `guid` bigint(20) unsigned NOT NULL,
  287. `timestamp` int(11) unsigned NOT NULL,
  288. PRIMARY KEY (`code`),
  289. KEY `timestamp` (`timestamp`)
  290. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
  291. -- user sessions
  292. CREATE TABLE `prefix_users_sessions` (
  293. `session` varchar(255) NOT NULL,
  294. `ts` int(11) unsigned NOT NULL DEFAULT '0',
  295. `data` mediumblob,
  296. PRIMARY KEY (`session`),
  297. KEY `ts` (`ts`)
  298. ) ENGINE=MyISAM DEFAULT CHARSET=utf8;