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 15KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392
  1. -- MySQL Script generated by MySQL Workbench
  2. -- Sat 28 Jul 2018 03:55:27 PM MDT
  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 `apps`
  66. -- -----------------------------------------------------
  67. CREATE TABLE IF NOT EXISTS `apps` (
  68. `appid` INT NOT NULL AUTO_INCREMENT,
  69. `appname` VARCHAR(45) NULL,
  70. `appcode` VARCHAR(45) NULL,
  71. PRIMARY KEY (`appid`),
  72. UNIQUE INDEX `appid_UNIQUE` (`appid` ASC))
  73. ENGINE = InnoDB;
  74. -- -----------------------------------------------------
  75. -- Table `available_apps`
  76. -- -----------------------------------------------------
  77. CREATE TABLE IF NOT EXISTS `available_apps` (
  78. `appid` INT NOT NULL,
  79. `uid` INT NOT NULL,
  80. PRIMARY KEY (`appid`, `uid`),
  81. INDEX `fk_apps_has_accounts_accounts1_idx` (`uid` ASC),
  82. INDEX `fk_apps_has_accounts_apps1_idx` (`appid` ASC),
  83. CONSTRAINT `fk_apps_has_accounts_apps1`
  84. FOREIGN KEY (`appid`)
  85. REFERENCES `apps` (`appid`)
  86. ON DELETE NO ACTION
  87. ON UPDATE NO ACTION,
  88. CONSTRAINT `fk_apps_has_accounts_accounts1`
  89. FOREIGN KEY (`uid`)
  90. REFERENCES `accounts` (`uid`)
  91. ON DELETE NO ACTION
  92. ON UPDATE NO ACTION)
  93. ENGINE = InnoDB;
  94. -- -----------------------------------------------------
  95. -- Table `apikeys`
  96. -- -----------------------------------------------------
  97. CREATE TABLE IF NOT EXISTS `apikeys` (
  98. `key` VARCHAR(60) NOT NULL,
  99. `notes` TEXT NULL,
  100. PRIMARY KEY (`key`))
  101. ENGINE = InnoDB;
  102. -- -----------------------------------------------------
  103. -- Table `groups`
  104. -- -----------------------------------------------------
  105. CREATE TABLE IF NOT EXISTS `groups` (
  106. `groupid` INT NOT NULL AUTO_INCREMENT,
  107. `groupname` VARCHAR(45) NOT NULL,
  108. PRIMARY KEY (`groupid`),
  109. UNIQUE INDEX `groupid_UNIQUE` (`groupid` ASC),
  110. UNIQUE INDEX `groupname_UNIQUE` (`groupname` ASC))
  111. ENGINE = InnoDB;
  112. -- -----------------------------------------------------
  113. -- Table `assigned_groups`
  114. -- -----------------------------------------------------
  115. CREATE TABLE IF NOT EXISTS `assigned_groups` (
  116. `groupid` INT NOT NULL,
  117. `uid` INT NOT NULL,
  118. PRIMARY KEY (`groupid`, `uid`),
  119. INDEX `fk_groups_has_accounts_accounts1_idx` (`uid` ASC),
  120. INDEX `fk_groups_has_accounts_groups1_idx` (`groupid` ASC),
  121. CONSTRAINT `fk_groups_has_accounts_groups1`
  122. FOREIGN KEY (`groupid`)
  123. REFERENCES `groups` (`groupid`)
  124. ON DELETE NO ACTION
  125. ON UPDATE NO ACTION,
  126. CONSTRAINT `fk_groups_has_accounts_accounts1`
  127. FOREIGN KEY (`uid`)
  128. REFERENCES `accounts` (`uid`)
  129. ON DELETE NO ACTION
  130. ON UPDATE NO ACTION)
  131. ENGINE = InnoDB;
  132. -- -----------------------------------------------------
  133. -- Table `managers`
  134. -- -----------------------------------------------------
  135. CREATE TABLE IF NOT EXISTS `managers` (
  136. `managerid` INT NOT NULL,
  137. `employeeid` INT NOT NULL,
  138. PRIMARY KEY (`managerid`, `employeeid`),
  139. INDEX `fk_managers_accounts2_idx` (`employeeid` ASC),
  140. CONSTRAINT `fk_managers_accounts1`
  141. FOREIGN KEY (`managerid`)
  142. REFERENCES `accounts` (`uid`)
  143. ON DELETE NO ACTION
  144. ON UPDATE NO ACTION,
  145. CONSTRAINT `fk_managers_accounts2`
  146. FOREIGN KEY (`employeeid`)
  147. REFERENCES `accounts` (`uid`)
  148. ON DELETE NO ACTION
  149. ON UPDATE NO ACTION)
  150. ENGINE = InnoDB;
  151. -- -----------------------------------------------------
  152. -- Table `logtypes`
  153. -- -----------------------------------------------------
  154. CREATE TABLE IF NOT EXISTS `logtypes` (
  155. `logtype` INT NOT NULL,
  156. `typename` VARCHAR(45) NULL,
  157. PRIMARY KEY (`logtype`),
  158. UNIQUE INDEX `logtype_UNIQUE` (`logtype` ASC))
  159. ENGINE = InnoDB;
  160. -- -----------------------------------------------------
  161. -- Table `authlog`
  162. -- -----------------------------------------------------
  163. CREATE TABLE IF NOT EXISTS `authlog` (
  164. `logid` INT NOT NULL AUTO_INCREMENT,
  165. `logtime` DATETIME NOT NULL,
  166. `logtype` INT NOT NULL,
  167. `uid` INT NULL,
  168. `ip` VARCHAR(45) NULL,
  169. `otherdata` VARCHAR(255) NULL,
  170. PRIMARY KEY (`logid`),
  171. UNIQUE INDEX `logid_UNIQUE` (`logid` ASC),
  172. INDEX `fk_authlog_logtypes1_idx` (`logtype` ASC),
  173. INDEX `fk_authlog_accounts1_idx` (`uid` ASC),
  174. CONSTRAINT `fk_authlog_logtypes1`
  175. FOREIGN KEY (`logtype`)
  176. REFERENCES `logtypes` (`logtype`)
  177. ON DELETE NO ACTION
  178. ON UPDATE NO ACTION,
  179. CONSTRAINT `fk_authlog_accounts1`
  180. FOREIGN KEY (`uid`)
  181. REFERENCES `accounts` (`uid`)
  182. ON DELETE NO ACTION
  183. ON UPDATE NO ACTION)
  184. ENGINE = InnoDB;
  185. -- -----------------------------------------------------
  186. -- Table `permissions`
  187. -- -----------------------------------------------------
  188. CREATE TABLE IF NOT EXISTS `permissions` (
  189. `permid` INT NOT NULL AUTO_INCREMENT,
  190. `permcode` VARCHAR(45) NOT NULL,
  191. `perminfo` VARCHAR(200) NULL,
  192. PRIMARY KEY (`permid`),
  193. UNIQUE INDEX `permid_UNIQUE` (`permid` ASC))
  194. ENGINE = InnoDB;
  195. -- -----------------------------------------------------
  196. -- Table `assigned_permissions`
  197. -- -----------------------------------------------------
  198. CREATE TABLE IF NOT EXISTS `assigned_permissions` (
  199. `uid` INT NOT NULL,
  200. `permid` INT NOT NULL,
  201. PRIMARY KEY (`uid`, `permid`),
  202. INDEX `fk_permissions_has_accounts_accounts1_idx` (`uid` ASC),
  203. INDEX `fk_permissions_has_accounts_permissions1_idx` (`permid` ASC),
  204. CONSTRAINT `fk_permissions_has_accounts_permissions1`
  205. FOREIGN KEY (`permid`)
  206. REFERENCES `permissions` (`permid`)
  207. ON DELETE NO ACTION
  208. ON UPDATE NO ACTION,
  209. CONSTRAINT `fk_permissions_has_accounts_accounts1`
  210. FOREIGN KEY (`uid`)
  211. REFERENCES `accounts` (`uid`)
  212. ON DELETE NO ACTION
  213. ON UPDATE NO ACTION)
  214. ENGINE = InnoDB;
  215. -- -----------------------------------------------------
  216. -- Table `mobile_codes`
  217. -- -----------------------------------------------------
  218. CREATE TABLE IF NOT EXISTS `mobile_codes` (
  219. `codeid` INT NOT NULL AUTO_INCREMENT,
  220. `uid` INT NOT NULL,
  221. `code` VARCHAR(45) NOT NULL DEFAULT '',
  222. `description` VARCHAR(255) NOT NULL DEFAULT '',
  223. PRIMARY KEY (`codeid`),
  224. UNIQUE INDEX `codeid_UNIQUE` (`codeid` ASC),
  225. INDEX `fk_mobile_codes_accounts1_idx` (`uid` ASC),
  226. UNIQUE INDEX `code_UNIQUE` (`code` ASC),
  227. CONSTRAINT `fk_mobile_codes_accounts1`
  228. FOREIGN KEY (`uid`)
  229. REFERENCES `accounts` (`uid`)
  230. ON DELETE NO ACTION
  231. ON UPDATE NO ACTION)
  232. ENGINE = InnoDB;
  233. -- -----------------------------------------------------
  234. -- Table `rate_limit`
  235. -- -----------------------------------------------------
  236. CREATE TABLE IF NOT EXISTS `rate_limit` (
  237. `ipaddr` VARCHAR(45) NOT NULL,
  238. `lastaction` DATETIME NULL,
  239. PRIMARY KEY (`ipaddr`))
  240. ENGINE = MEMORY;
  241. -- -----------------------------------------------------
  242. -- Table `onetimekeys`
  243. -- -----------------------------------------------------
  244. CREATE TABLE IF NOT EXISTS `onetimekeys` (
  245. `key` VARCHAR(10) NOT NULL,
  246. `uid` INT NOT NULL,
  247. `expires` DATETIME NOT NULL,
  248. INDEX `fk_onetimekeys_accounts1_idx` (`uid` ASC),
  249. PRIMARY KEY (`key`),
  250. UNIQUE INDEX `key_UNIQUE` (`key` ASC),
  251. CONSTRAINT `fk_onetimekeys_accounts1`
  252. FOREIGN KEY (`uid`)
  253. REFERENCES `accounts` (`uid`)
  254. ON DELETE NO ACTION
  255. ON UPDATE NO ACTION)
  256. ENGINE = InnoDB;
  257. -- -----------------------------------------------------
  258. -- Table `notifications`
  259. -- -----------------------------------------------------
  260. CREATE TABLE IF NOT EXISTS `notifications` (
  261. `notificationid` INT NOT NULL AUTO_INCREMENT,
  262. `uid` INT NOT NULL,
  263. `timestamp` DATETIME NOT NULL,
  264. `title` VARCHAR(255) NOT NULL,
  265. `content` TINYTEXT NOT NULL,
  266. `url` VARCHAR(255) NOT NULL,
  267. `seen` TINYINT(1) NOT NULL DEFAULT 0,
  268. `sensitive` TINYINT(1) NOT NULL,
  269. `appid` VARCHAR(255) NULL,
  270. PRIMARY KEY (`notificationid`, `uid`),
  271. UNIQUE INDEX `notificationid_UNIQUE` (`notificationid` ASC),
  272. INDEX `fk_notifications_accounts1_idx` (`uid` ASC),
  273. CONSTRAINT `fk_notifications_accounts1`
  274. FOREIGN KEY (`uid`)
  275. REFERENCES `accounts` (`uid`)
  276. ON DELETE NO ACTION
  277. ON UPDATE NO ACTION)
  278. ENGINE = InnoDB;
  279. SET SQL_MODE=@OLD_SQL_MODE;
  280. SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS;
  281. SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS;
  282. -- -----------------------------------------------------
  283. -- Data for table `acctstatus`
  284. -- -----------------------------------------------------
  285. START TRANSACTION;
  286. INSERT INTO `acctstatus` (`statusid`, `statuscode`) VALUES (1, 'NORMAL');
  287. INSERT INTO `acctstatus` (`statusid`, `statuscode`) VALUES (2, 'LOCKED_OR_DISABLED');
  288. INSERT INTO `acctstatus` (`statusid`, `statuscode`) VALUES (3, 'CHANGE_PASSWORD');
  289. INSERT INTO `acctstatus` (`statusid`, `statuscode`) VALUES (4, 'TERMINATED');
  290. INSERT INTO `acctstatus` (`statusid`, `statuscode`) VALUES (5, 'ALERT_ON_ACCESS');
  291. COMMIT;
  292. -- -----------------------------------------------------
  293. -- Data for table `accttypes`
  294. -- -----------------------------------------------------
  295. START TRANSACTION;
  296. INSERT INTO `accttypes` (`typeid`, `typecode`) VALUES (1, 'LOCAL');
  297. INSERT INTO `accttypes` (`typeid`, `typecode`) VALUES (2, 'LDAP');
  298. INSERT INTO `accttypes` (`typeid`, `typecode`) VALUES (3, 'LIGHT');
  299. COMMIT;
  300. -- -----------------------------------------------------
  301. -- Data for table `logtypes`
  302. -- -----------------------------------------------------
  303. START TRANSACTION;
  304. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (1, 'PORTAL_LOGIN_OK');
  305. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (2, 'PORTAL_LOGIN_FAILED');
  306. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (3, 'PASSWORD_CHANGED');
  307. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (4, 'API_LOGIN_OK');
  308. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (5, 'API_LOGIN_FAILED');
  309. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (6, 'PORTAL_BAD_AUTHCODE');
  310. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (7, 'API_BAD_AUTHCODE');
  311. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (8, 'BAD_CAPTCHA');
  312. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (9, '2FA_ADDED');
  313. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (10, '2FA_REMOVED');
  314. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (11, 'PORTAL_LOGOUT');
  315. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (12, 'API_AUTH_OK');
  316. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (13, 'API_AUTH_FAILED');
  317. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (14, 'API_BAD_KEY');
  318. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (15, 'LOG_CLEARED');
  319. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (16, 'USER_REMOVED');
  320. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (17, 'USER_ADDED');
  321. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (18, 'USER_EDITED');
  322. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (19, 'MOBILE_LOGIN_OK');
  323. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (20, 'MOBILE_LOGIN_FAILED');
  324. INSERT INTO `logtypes` (`logtype`, `typename`) VALUES (21, 'MOBILE_BAD_KEY');
  325. COMMIT;
  326. -- -----------------------------------------------------
  327. -- Data for table `permissions`
  328. -- -----------------------------------------------------
  329. START TRANSACTION;
  330. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (1, 'ADMIN', 'System administrator');
  331. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (100, 'INV_VIEW', 'Access inventory system');
  332. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (101, 'INV_EDIT', 'Edit inventory system');
  333. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (200, 'TASKFLOOR', 'Access TaskFloor');
  334. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (300, 'QWIKCLOCK', 'Access QwikClock and punch in/out');
  335. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (301, 'QWIKCLOCK_MANAGE', 'Edit punches and other data for managed users');
  336. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (302, 'QWIKCLOCK_EDITSELF', 'Edit own punches and other data');
  337. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (303, 'QWIKCLOCK_ADMIN', 'Add and edit shifts and other data for all users');
  338. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (400, 'SITEWRITER', 'Manage and edit websites, messages, and analytics');
  339. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (401, 'SITEWRITER_CONTACT', 'Manage messages sent via website contact forms');
  340. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (402, 'SITEWRITER_ANALYTICS', 'View website analytics');
  341. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (403, 'SITEWRITER_EDIT', 'Edit website content');
  342. INSERT INTO `permissions` (`permid`, `permcode`, `perminfo`) VALUES (404, 'SITEWRITER_FILES', 'Manage and upload files');
  343. COMMIT;