Single-sign-on and self-serve account management. https://netsyms.biz/apps/accounthub
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

database.sql 16KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442
  1. -- MySQL Script generated by MySQL Workbench
  2. -- Mon 11 Feb 2019 04:07:57 PM MST
  3. -- Model: New Model Version: 1.0
  4. -- MySQL Workbench Forward Engineering
  5. SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0;
  6. SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0;
  7. SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='TRADITIONAL,ALLOW_INVALID_DATES';
  8. -- -----------------------------------------------------
  9. -- Schema accounthub
  10. -- -----------------------------------------------------
  11. -- -----------------------------------------------------
  12. -- Table `acctstatus`
  13. -- -----------------------------------------------------
  14. CREATE TABLE IF NOT EXISTS `acctstatus` (
  15. `statusid` INT NOT NULL AUTO_INCREMENT,
  16. `statuscode` VARCHAR(45) NOT NULL,
  17. PRIMARY KEY (`statusid`),
  18. UNIQUE INDEX `statusid_UNIQUE` (`statusid` ASC),
  19. UNIQUE INDEX `statuscode_UNIQUE` (`statuscode` ASC))
  20. ENGINE = InnoDB;
  21. -- -----------------------------------------------------
  22. -- Table `accttypes`
  23. -- -----------------------------------------------------
  24. CREATE TABLE IF NOT EXISTS `accttypes` (
  25. `typeid` INT NOT NULL AUTO_INCREMENT,
  26. `typecode` VARCHAR(45) NOT NULL,
  27. PRIMARY KEY (`typeid`),
  28. UNIQUE INDEX `typeid_UNIQUE` (`typeid` ASC),
  29. UNIQUE INDEX `typecode_UNIQUE` (`typecode` ASC))
  30. ENGINE = InnoDB;
  31. -- -----------------------------------------------------
  32. -- Table `accounts`
  33. -- -----------------------------------------------------
  34. CREATE TABLE IF NOT EXISTS `accounts` (
  35. `uid` INT NOT NULL AUTO_INCREMENT,
  36. `username` VARCHAR(190) NOT NULL,
  37. `password` VARCHAR(255) NULL,
  38. `realname` VARCHAR(255) NOT NULL,
  39. `email` VARCHAR(255) NULL DEFAULT 'NOEMAIL@EXAMPLE.COM',
  40. `authsecret` VARCHAR(100) NULL,
  41. `pin` VARCHAR(10) NULL,
  42. `phone1` VARCHAR(45) NOT NULL,
  43. `phone2` VARCHAR(45) NOT NULL,
  44. `acctstatus` INT NOT NULL DEFAULT 0,
  45. `accttype` INT NOT NULL,
  46. `deleted` TINYINT(1) NOT NULL DEFAULT 0,
  47. PRIMARY KEY (`uid`, `username`),
  48. UNIQUE INDEX `userid_UNIQUE` (`uid` ASC),
  49. UNIQUE INDEX `username_UNIQUE` (`username` ASC),
  50. INDEX `fk_accounts_acctstatus_idx` (`acctstatus` ASC),
  51. INDEX `email_index` (`email` ASC),
  52. INDEX `fk_accounts_accttypes1_idx` (`accttype` ASC),
  53. CONSTRAINT `fk_accounts_acctstatus`
  54. FOREIGN KEY (`acctstatus`)
  55. REFERENCES `acctstatus` (`statusid`)
  56. ON DELETE NO ACTION
  57. ON UPDATE NO ACTION,
  58. CONSTRAINT `fk_accounts_accttypes1`
  59. FOREIGN KEY (`accttype`)
  60. REFERENCES `accttypes` (`typeid`)
  61. ON DELETE NO ACTION
  62. ON UPDATE NO ACTION)
  63. ENGINE = InnoDB;
  64. -- -----------------------------------------------------
  65. -- Table `apikeys`
  66. -- -----------------------------------------------------
  67. CREATE TABLE IF NOT EXISTS `apikeys` (
  68. `key` VARCHAR(60) NOT NULL,
  69. `notes` TEXT NULL,
  70. `type` VARCHAR(45) NOT NULL DEFAULT 'FULL',
  71. PRIMARY KEY (`key`))
  72. ENGINE = InnoDB;
  73. -- -----------------------------------------------------
  74. -- Table `groups`
  75. -- -----------------------------------------------------
  76. CREATE TABLE IF NOT EXISTS `groups` (
  77. `groupid` INT NOT NULL AUTO_INCREMENT,
  78. `groupname` VARCHAR(45) NOT NULL,
  79. PRIMARY KEY (`groupid`),
  80. UNIQUE INDEX `groupid_UNIQUE` (`groupid` ASC),
  81. UNIQUE INDEX `groupname_UNIQUE` (`groupname` ASC))
  82. ENGINE = InnoDB;
  83. -- -----------------------------------------------------
  84. -- Table `assigned_groups`
  85. -- -----------------------------------------------------
  86. CREATE TABLE IF NOT EXISTS `assigned_groups` (
  87. `groupid` INT NOT NULL,
  88. `uid` INT NOT NULL,
  89. PRIMARY KEY (`groupid`, `uid`),
  90. INDEX `fk_groups_has_accounts_accounts1_idx` (`uid` ASC),
  91. INDEX `fk_groups_has_accounts_groups1_idx` (`groupid` ASC),
  92. CONSTRAINT `fk_groups_has_accounts_groups1`
  93. FOREIGN KEY (`groupid`)
  94. REFERENCES `groups` (`groupid`)
  95. ON DELETE NO ACTION
  96. ON UPDATE NO ACTION,
  97. CONSTRAINT `fk_groups_has_accounts_accounts1`
  98. FOREIGN KEY (`uid`)
  99. REFERENCES `accounts` (`uid`)
  100. ON DELETE NO ACTION
  101. ON UPDATE NO ACTION)
  102. ENGINE = InnoDB;
  103. -- -----------------------------------------------------
  104. -- Table `managers`
  105. -- -----------------------------------------------------
  106. CREATE TABLE IF NOT EXISTS `managers` (
  107. `managerid` INT NOT NULL,
  108. `employeeid` INT NOT NULL,
  109. PRIMARY KEY (`managerid`, `employeeid`),
  110. INDEX `fk_managers_accounts2_idx` (`employeeid` ASC),
  111. CONSTRAINT `fk_managers_accounts1`
  112. FOREIGN KEY (`managerid`)
  113. REFERENCES `accounts` (`uid`)
  114. ON DELETE NO ACTION
  115. ON UPDATE NO ACTION,
  116. CONSTRAINT `fk_managers_accounts2`
  117. FOREIGN KEY (`employeeid`)
  118. REFERENCES `accounts` (`uid`)
  119. ON DELETE NO ACTION
  120. ON UPDATE NO ACTION)
  121. ENGINE = InnoDB;
  122. -- -----------------------------------------------------
  123. -- Table `logtypes`
  124. -- -----------------------------------------------------
  125. CREATE TABLE IF NOT EXISTS `logtypes` (
  126. `logtype` INT NOT NULL,
  127. `typename` VARCHAR(45) NULL,
  128. PRIMARY KEY (`logtype`),
  129. UNIQUE INDEX `logtype_UNIQUE` (`logtype` ASC))
  130. ENGINE = InnoDB;
  131. -- -----------------------------------------------------
  132. -- Table `authlog`
  133. -- -----------------------------------------------------
  134. CREATE TABLE IF NOT EXISTS `authlog` (
  135. `logid` INT NOT NULL AUTO_INCREMENT,
  136. `logtime` DATETIME NOT NULL,
  137. `logtype` INT NOT NULL,
  138. `uid` INT NULL,
  139. `ip` VARCHAR(45) NULL,
  140. `otherdata` VARCHAR(255) NULL,
  141. PRIMARY KEY (`logid`),
  142. UNIQUE INDEX `logid_UNIQUE` (`logid` ASC),
  143. INDEX `fk_authlog_logtypes1_idx` (`logtype` ASC),
  144. INDEX `fk_authlog_accounts1_idx` (`uid` ASC),
  145. CONSTRAINT `fk_authlog_logtypes1`
  146. FOREIGN KEY (`logtype`)
  147. REFERENCES `logtypes` (`logtype`)
  148. ON DELETE NO ACTION
  149. ON UPDATE NO ACTION,
  150. CONSTRAINT `fk_authlog_accounts1`
  151. FOREIGN KEY (`uid`)
  152. REFERENCES `accounts` (`uid`)
  153. ON DELETE NO ACTION
  154. ON UPDATE NO ACTION)
  155. ENGINE = InnoDB;
  156. -- -----------------------------------------------------
  157. -- Table `permissions`
  158. -- -----------------------------------------------------
  159. CREATE TABLE IF NOT EXISTS `permissions` (
  160. `permid` INT NOT NULL AUTO_INCREMENT,
  161. `permcode` VARCHAR(45) NOT NULL,
  162. `perminfo` VARCHAR(200) NULL,
  163. PRIMARY KEY (`permid`),
  164. UNIQUE INDEX `permid_UNIQUE` (`permid` ASC))
  165. ENGINE = InnoDB;
  166. -- -----------------------------------------------------
  167. -- Table `assigned_permissions`
  168. -- -----------------------------------------------------
  169. CREATE TABLE IF NOT EXISTS `assigned_permissions` (
  170. `uid` INT NOT NULL,
  171. `permid` INT NOT NULL,
  172. PRIMARY KEY (`uid`, `permid`),
  173. INDEX `fk_permissions_has_accounts_accounts1_idx` (`uid` ASC),
  174. INDEX `fk_permissions_has_accounts_permissions1_idx` (`permid` ASC),
  175. CONSTRAINT `fk_permissions_has_accounts_permissions1`
  176. FOREIGN KEY (`permid`)
  177. REFERENCES `permissions` (`permid`)
  178. ON DELETE NO ACTION
  179. ON UPDATE NO ACTION,
  180. CONSTRAINT `fk_permissions_has_accounts_accounts1`
  181. FOREIGN KEY (`uid`)
  182. REFERENCES `accounts` (`uid`)
  183. ON DELETE NO ACTION
  184. ON UPDATE NO ACTION)
  185. ENGINE = InnoDB;
  186. -- -----------------------------------------------------
  187. -- Table `mobile_codes`
  188. -- -----------------------------------------------------
  189. CREATE TABLE IF NOT EXISTS `mobile_codes` (
  190. `codeid` INT NOT NULL AUTO_INCREMENT,
  191. `uid` INT NOT NULL,
  192. `code` VARCHAR(45) NOT NULL DEFAULT '',
  193. `description` VARCHAR(255) NOT NULL DEFAULT '',
  194. PRIMARY KEY (`codeid`),
  195. UNIQUE INDEX `codeid_UNIQUE` (`codeid` ASC),
  196. INDEX `fk_mobile_codes_accounts1_idx` (`uid` ASC),
  197. UNIQUE INDEX `code_UNIQUE` (`code` ASC),
  198. CONSTRAINT `fk_mobile_codes_accounts1`
  199. FOREIGN KEY (`uid`)
  200. REFERENCES `accounts` (`uid`)
  201. ON DELETE NO ACTION
  202. ON UPDATE NO ACTION)
  203. ENGINE = InnoDB;
  204. -- -----------------------------------------------------
  205. -- Table `rate_limit`
  206. -- -----------------------------------------------------
  207. CREATE TABLE IF NOT EXISTS `rate_limit` (
  208. `ipaddr` VARCHAR(45) NOT NULL,
  209. `lastaction` DATETIME NULL,
  210. PRIMARY KEY (`ipaddr`))
  211. ENGINE = MEMORY;
  212. -- -----------------------------------------------------
  213. -- Table `onetimekeys`
  214. -- -----------------------------------------------------
  215. CREATE TABLE IF NOT EXISTS `onetimekeys` (
  216. `key` VARCHAR(10) NOT NULL,
  217. `uid` INT NOT NULL,
  218. `expires` DATETIME NOT NULL,
  219. INDEX `fk_onetimekeys_accounts1_idx` (`uid` ASC),
  220. PRIMARY KEY (`key`),
  221. UNIQUE INDEX `key_UNIQUE` (`key` ASC),
  222. CONSTRAINT `fk_onetimekeys_accounts1`
  223. FOREIGN KEY (`uid`)
  224. REFERENCES `accounts` (`uid`)
  225. ON DELETE NO ACTION
  226. ON UPDATE NO ACTION)
  227. ENGINE = InnoDB;
  228. -- -----------------------------------------------------
  229. -- Table `notifications`
  230. -- -----------------------------------------------------
  231. CREATE TABLE IF NOT EXISTS `notifications` (
  232. `notificationid` INT NOT NULL AUTO_INCREMENT,
  233. `uid` INT NOT NULL,
  234. `timestamp` DATETIME NOT NULL,
  235. `title` VARCHAR(255) NOT NULL,
  236. `content` TINYTEXT NOT NULL,
  237. `url` VARCHAR(255) NOT NULL,
  238. `seen` TINYINT(1) NOT NULL DEFAULT 0,
  239. `sensitive` TINYINT(1) NOT NULL,
  240. `appid` VARCHAR(255) NULL,
  241. PRIMARY KEY (`notificationid`, `uid`),
  242. UNIQUE INDEX `notificationid_UNIQUE` (`notificationid` ASC),
  243. INDEX `fk_notifications_accounts1_idx` (`uid` ASC),
  244. CONSTRAINT `fk_notifications_accounts1`
  245. FOREIGN KEY (`uid`)
  246. REFERENCES `accounts` (`uid`)
  247. ON DELETE NO ACTION
  248. ON UPDATE NO ACTION)
  249. ENGINE = InnoDB;
  250. -- -----------------------------------------------------
  251. -- Table `userkeytypes`
  252. -- -----------------------------------------------------
  253. CREATE TABLE IF NOT EXISTS `userkeytypes` (
  254. `typeid` INT NOT NULL,
  255. `typename` VARCHAR(45) NOT NULL,
  256. PRIMARY KEY (`typeid`, `typename`))
  257. ENGINE = InnoDB;
  258. -- -----------------------------------------------------
  259. -- Table `userkeys`
  260. -- -----------------------------------------------------
  261. CREATE TABLE IF NOT EXISTS `userkeys` (
  262. `uid` INT NOT NULL,
  263. `key` VARCHAR(100) NOT NULL,
  264. `created` DATETIME NULL,
  265. `typeid` INT NOT NULL,
  266. PRIMARY KEY (`uid`),
  267. INDEX `fk_userkeys_userkeytypes1_idx` (`typeid` ASC),
  268. CONSTRAINT `fk_userkeys_accounts1`
  269. FOREIGN KEY (`uid`)
  270. REFERENCES `accounts` (`uid`)
  271. ON DELETE NO ACTION
  272. ON UPDATE NO ACTION,
  273. CONSTRAINT `fk_userkeys_userkeytypes1`
  274. FOREIGN KEY (`typeid`)
  275. REFERENCES `userkeytypes` (`typeid`)
  276. ON DELETE NO ACTION
  277. ON UPDATE NO ACTION)
  278. ENGINE = InnoDB;
  279. -- -----------------------------------------------------
  280. -- Table `userloginkeys`
  281. -- -----------------------------------------------------
  282. CREATE TABLE IF NOT EXISTS `userloginkeys` (
  283. `id` INT NOT NULL AUTO_INCREMENT,
  284. `key` VARCHAR(255) NOT NULL,
  285. `expires` DATETIME NULL,
  286. `uid` INT NULL,
  287. `appname` VARCHAR(255) NOT NULL,
  288. `appicon` TINYTEXT NULL,
  289. PRIMARY KEY (`id`, `key`),
  290. UNIQUE INDEX `id_UNIQUE` (`id` ASC),
  291. UNIQUE INDEX `key_UNIQUE` (`key` ASC),
  292. INDEX `fk_userloginkeys_accounts1_idx` (`uid` ASC),
  293. CONSTRAINT `fk_userloginkeys_accounts1`
  294. FOREIGN KEY (`uid`)
  295. REFERENCES `accounts` (`uid`)
  296. ON DELETE NO ACTION
  297. ON UPDATE NO ACTION)
  298. ENGINE = InnoDB;
  299. -- -----------------------------------------------------
  300. -- Table `apppasswords`
  301. -- -----------------------------------------------------
  302. CREATE TABLE IF NOT EXISTS `apppasswords` (
  303. `passid` INT NOT NULL AUTO_INCREMENT,
  304. `hash` VARCHAR(255) NOT NULL,
  305. `uid` INT NOT NULL,
  306. `description` VARCHAR(255) NOT NULL,
  307. PRIMARY KEY (`passid`, `uid`),
  308. UNIQUE INDEX `passid_UNIQUE` (`passid` ASC),
  309. INDEX `fk_apppasswords_accounts1_idx` (`uid` ASC),
  310. CONSTRAINT `fk_apppasswords_accounts1`
  311. FOREIGN KEY (`uid`)
  312. REFERENCES `accounts` (`uid`)
  313. ON DELETE NO ACTION
  314. ON UPDATE NO ACTION)
  315. ENGINE = InnoDB;
  316. SET SQL_MODE=@OLD_SQL_MODE;
  317. SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS;
  318. SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS;
  319. -- -----------------------------------------------------
  320. -- Data for table `acctstatus`
  321. -- -----------------------------------------------------
  322. START TRANSACTION;
  323. INSERT INTO `acctstatus` (`statusid`, `statuscode`) VALUES (1, 'NORMAL');
  324. INSERT INTO `acctstatus` (`statusid`, `statuscode`) VALUES (2, 'LOCKED_OR_DISABLED');
  325. INSERT INTO `acctstatus` (`statusid`, `statuscode`) VALUES (3, 'CHANGE_PASSWORD');
  326. INSERT INTO `acctstatus` (`statusid`, `statuscode`) VALUES (4, 'TERMINATED');
  327. INSERT INTO `acctstatus` (`statusid`, `statuscode`) VALUES (5, 'ALERT_ON_ACCESS');
  328. COMMIT;
  329. -- -----------------------------------------------------
  330. -- Data for table `accttypes`
  331. -- -----------------------------------------------------
  332. START TRANSACTION;
  333. INSERT INTO `accttypes` (`typeid`, `typecode`) VALUES (1, 'LOCAL');
  334. INSERT INTO `accttypes` (`typeid`, `typecode`) VALUES (2, 'EXTERNAL');
  335. COMMIT;
  336. -- -----------------------------------------------------
  337. -- Data for table `logtypes`
  338. -- -----------------------------------------------------
  339. START TRANSACTION;
  340. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (1, 'PORTAL_LOGIN_OK');
  341. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (2, 'PORTAL_LOGIN_FAILED');
  342. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (3, 'PASSWORD_CHANGED');
  343. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (4, 'API_LOGIN_OK');
  344. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (5, 'API_LOGIN_FAILED');
  345. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (6, 'PORTAL_BAD_AUTHCODE');
  346. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (7, 'API_BAD_AUTHCODE');
  347. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (8, 'BAD_CAPTCHA');
  348. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (9, '2FA_ADDED');
  349. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (10, '2FA_REMOVED');
  350. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (11, 'PORTAL_LOGOUT');
  351. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (12, 'API_AUTH_OK');
  352. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (13, 'API_AUTH_FAILED');
  353. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (14, 'API_BAD_KEY');
  354. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (15, 'LOG_CLEARED');
  355. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (16, 'USER_REMOVED');
  356. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (17, 'USER_ADDED');
  357. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (18, 'USER_EDITED');
  358. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (19, 'MOBILE_LOGIN_OK');
  359. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (20, 'MOBILE_LOGIN_FAILED');
  360. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (21, 'MOBILE_BAD_KEY');
  361. COMMIT;
  362. -- -----------------------------------------------------
  363. -- Data for table `permissions`
  364. -- -----------------------------------------------------
  365. START TRANSACTION;
  366. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (1, 'ADMIN', 'System administrator');
  367. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (100, 'INV_VIEW', 'Access inventory system');
  368. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (101, 'INV_EDIT', 'Edit inventory system');
  369. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (200, 'TASKFLOOR', 'Access TaskFloor');
  370. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (300, 'QWIKCLOCK', 'Access QwikClock and punch in/out');
  371. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (301, 'QWIKCLOCK_MANAGE', 'Edit punches and other data for managed users');
  372. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (302, 'QWIKCLOCK_EDITSELF', 'Edit own punches and other data');
  373. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (303, 'QWIKCLOCK_ADMIN', 'Add and edit shifts and other data for all users');
  374. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (400, 'SITEWRITER', 'Manage and edit websites, messages, and analytics');
  375. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (401, 'SITEWRITER_CONTACT', 'Manage messages sent via website contact forms');
  376. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (402, 'SITEWRITER_ANALYTICS', 'View website analytics');
  377. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (403, 'SITEWRITER_EDIT', 'Edit website content');
  378. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (404, 'SITEWRITER_FILES', 'Manage and upload files');
  379. COMMIT;
  380. -- -----------------------------------------------------
  381. -- Data for table `userkeytypes`
  382. -- -----------------------------------------------------
  383. START TRANSACTION;
  384. INSERT INTO `userkeytypes` (`typeid`, `typename`) VALUES (1, 'RSSAtomFeed');
  385. INSERT INTO `userkeytypes` (`typeid`, `typename`) VALUES (2, 'Other');
  386. COMMIT;