An unfinished system to manage all your paper documentation in an easy way.
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.

schema.sql 8.0KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307
  1. ALTER SCHEMA `autodoc` DEFAULT CHARACTER SET utf8mb4 DEFAULT COLLATE utf8mb4_general_ci ;
  2. DROP TABLE IF EXISTS `documents_tags`;
  3. DROP TABLE IF EXISTS `documents_pages`;
  4. DROP TABLE IF EXISTS `pages_words`;
  5. DROP TABLE IF EXISTS `words`;
  6. DROP TABLE IF EXISTS `dict`;
  7. DROP TABLE IF EXISTS `languages`;
  8. DROP TABLE IF EXISTS `pages`;
  9. DROP TABLE IF EXISTS `tags`;
  10. DROP TABLE IF EXISTS `users`;
  11. DROP TABLE IF EXISTS `documents`;
  12. DROP PROCEDURE IF EXISTS `create_page_word`;
  13. DROP PROCEDURE IF EXISTS `create_tag`;
  14. DROP PROCEDURE IF EXISTS `create_document`;
  15. DROP PROCEDURE IF EXISTS `create_page`;
  16. DROP PROCEDURE IF EXISTS `delete_tag`;
  17. DROP PROCEDURE IF EXISTS `get_document_filter`;
  18. DROP PROCEDURE IF EXISTS `get_primary_page`;
  19. DROP PROCEDURE IF EXISTS `set_primary_page`;
  20. DROP PROCEDURE IF EXISTS `set_page_status`;
  21. DROP FUNCTION IF EXISTS `SPLIT_STR`;
  22. CREATE TABLE `dict` (
  23. `word` varchar(255) NOT NULL,
  24. `lang` char(2) NOT NULL,
  25. PRIMARY KEY (`word`,`lang`)
  26. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
  27. CREATE TABLE `users` (
  28. `username` varchar(255) NOT NULL,
  29. `passwd` varchar(255) DEFAULT NULL,
  30. `groups` varchar(255) DEFAULT NULL,
  31. PRIMARY KEY (`username`)
  32. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
  33. CREATE TABLE `documents` (
  34. `id` binary(16) NOT NULL,
  35. `owner` varchar(45) DEFAULT NULL,
  36. `name` varchar(128) CHARACTER SET utf8mb4 DEFAULT NULL,
  37. `created` timestamp NULL DEFAULT CURRENT_TIMESTAMP,
  38. `status` enum('nodata','inprogress','deleted','ok') NOT NULL DEFAULT 'nodata',
  39. PRIMARY KEY (`id`)
  40. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
  41. CREATE TABLE `languages` (
  42. `id` binary(16) NOT NULL,
  43. `short` char(2) DEFAULT NULL,
  44. `name` varchar(45) DEFAULT NULL,
  45. PRIMARY KEY (`id`),
  46. UNIQUE KEY `short_UNIQUE` (`short`)
  47. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
  48. CREATE TABLE `pages` (
  49. `id` binary(16) NOT NULL,
  50. `owner` varchar(45) DEFAULT NULL,
  51. `created` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
  52. `status` enum('nodata','inprogress','deleted','ok') DEFAULT 'nodata',
  53. `isprimary` tinyint(4) DEFAULT '0',
  54. PRIMARY KEY (`id`)
  55. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
  56. CREATE TABLE `tags` (
  57. `id` binary(16) NOT NULL,
  58. `tag` varchar(45) DEFAULT NULL,
  59. `color` enum('primary','secondary','success','danger','warning','info','light','dark') DEFAULT NULL,
  60. PRIMARY KEY (`id`),
  61. UNIQUE KEY `tag_UNIQUE` (`tag`,`color`)
  62. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
  63. CREATE TABLE `words` (
  64. `id` binary(16) NOT NULL,
  65. `word` varchar(255) DEFAULT NULL,
  66. `languageId` binary(16) DEFAULT NULL,
  67. PRIMARY KEY (`id`),
  68. UNIQUE KEY `word_UNIQUE` (`word`,`languageId`),
  69. KEY `fk_words_langid_idx` (`languageId`),
  70. CONSTRAINT `fk_words_languageid` FOREIGN KEY (`languageId`) REFERENCES `languages` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION
  71. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
  72. CREATE TABLE `documents_tags` (
  73. `documentId` binary(16) NOT NULL,
  74. `tagId` binary(16) NOT NULL,
  75. PRIMARY KEY (`documentId`,`tagId`),
  76. KEY `fk_tags_id_idx` (`tagId`),
  77. CONSTRAINT `fk_doctags_docid` FOREIGN KEY (`documentId`) REFERENCES `documents` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION,
  78. CONSTRAINT `fk_doctags_tagid` FOREIGN KEY (`tagId`) REFERENCES `tags` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION
  79. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
  80. CREATE TABLE `pages_words` (
  81. `pageId` binary(16) NOT NULL,
  82. `wordId` binary(16) NOT NULL,
  83. `count` int(10) unsigned DEFAULT NULL,
  84. PRIMARY KEY (`pageId`,`wordId`),
  85. KEY `fk_pagword_wordid_idx` (`wordId`),
  86. CONSTRAINT `fk_pagword_pageid` FOREIGN KEY (`pageId`) REFERENCES `pages` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION,
  87. CONSTRAINT `fk_pagword_wordid` FOREIGN KEY (`wordId`) REFERENCES `words` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION
  88. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
  89. CREATE TABLE `documents_pages` (
  90. `documentId` binary(16) NOT NULL,
  91. `pageId` binary(16) NOT NULL,
  92. PRIMARY KEY (`documentId`,`pageId`),
  93. KEY `fk_docpage_pageid_idx` (`pageId`),
  94. CONSTRAINT `fk_docpage_docid` FOREIGN KEY (`documentId`) REFERENCES `documents` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION,
  95. CONSTRAINT `fk_docpage_pageid` FOREIGN KEY (`pageId`) REFERENCES `pages` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION
  96. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
  97. DELIMITER ;;
  98. CREATE FUNCTION `SPLIT_STR`(
  99. x VARCHAR(255),
  100. delim VARCHAR(12),
  101. pos INT
  102. ) RETURNS varchar(255) CHARSET utf8mb4
  103. RETURN
  104. CASE WHEN CHAR_LENGTH(SUBSTRING_INDEX(x, delim, pos - 1)) = CHAR_LENGTH(x)
  105. THEN x
  106. ELSE (REPLACE(SUBSTRING(SUBSTRING_INDEX(x, delim, pos), CHAR_LENGTH(SUBSTRING_INDEX(x, delim, pos -1)) + 1), delim, ''))
  107. END ;;
  108. DELIMITER ;
  109. DELIMITER ;;
  110. CREATE PROCEDURE `create_page_word`(
  111. IN IN_pageid CHAR(36),
  112. IN IN_word VARCHAR(255),
  113. IN IN_langid CHAR(36))
  114. BEGIN
  115. DECLARE LOC_wordid BINARY(16) DEFAULT NULL;
  116. INSERT IGNORE INTO words SET
  117. id = UUID_TO_BIN(UUID()),
  118. word = IN_word,
  119. langId = UUID_TO_BIN(IN_langid);
  120. SELECT BIN_TO_UUID(id) INTO LOC_wordid FROM words WHERE word = IN_word AND langId = UUID_TO_BIN(IN_langid);
  121. INSERT INTO pages_words SET
  122. pageId = UUID_TO_BIN(IN_pageid),
  123. wordId = UUID_TO_BIN(LOC_wordid),
  124. count = 1
  125. ON DUPLICATE KEY
  126. UPDATE count = count + 1;
  127. END ;;
  128. DELIMITER ;
  129. DELIMITER ;;
  130. CREATE PROCEDURE `create_tag`(
  131. IN IN_documentid BINARY(16),
  132. IN IN_tag VARCHAR(45))
  133. BEGIN
  134. DECLARE LOC_tagid BINARY(16) DEFAULT UUID();
  135. INSERT IGNORE INTO tags SET
  136. id = LOC_tagid,
  137. tag = IN_tag;
  138. SELECT id INTO LOC_tagid FROM tags WHERE tag = IN_tag;
  139. INSERT IGNORE INTO documents_tags SET
  140. documentId = IN_documentid,
  141. tagId = LOC_tagid;
  142. END ;;
  143. DELIMITER ;
  144. DELIMITER ;;
  145. CREATE PROCEDURE `create_document`(
  146. IN IN_owner VARCHAR(45))
  147. BEGIN
  148. DECLARE LOC_documentid BINARY(16) DEFAULT UUID();
  149. INSERT INTO documents SET
  150. id = LOC_documentid,
  151. owner = IN_owner,
  152. status = 'nodata';
  153. SELECT LOC_documentid AS documentId;
  154. END ;;
  155. DELIMITER ;
  156. DELIMITER ;;
  157. CREATE PROCEDURE `create_page`(
  158. IN IN_documentId BINARY(16))
  159. BEGIN
  160. DECLARE LOC_pageid BINARY(16) DEFAULT UUID();
  161. INSERT INTO pages SET
  162. id = LOC_pageid,
  163. status = 'nodata';
  164. INSERT INTO documents_pages SET
  165. documentId = UUID_TO_BIN(IN_documentid),
  166. pageId = LOC_pageid;
  167. SELECT BIN_TO_UUID(LOC_pageid) AS pageId;
  168. END ;;
  169. DELIMITER ;
  170. DELIMITER ;;
  171. CREATE PROCEDURE `delete_tag`(
  172. IN IN_documentid BINARY(16),
  173. IN IN_tag VARCHAR(45))
  174. BEGIN
  175. DECLARE LOC_tagid BINARY(16) DEFAULT UUID();
  176. SELECT id INTO LOC_tagid FROM tags WHERE tag = IN_tag;
  177. DELETE FROM documents_tags
  178. WHERE documentId = IN_documentid
  179. AND tagId = LOC_tagid;
  180. END ;;
  181. DELIMITER ;
  182. DELIMITER ;;
  183. CREATE PROCEDURE `get_document_filter`(
  184. IN IN_words VARCHAR(255),
  185. IN IN_tags VARCHAR(255),
  186. IN IN_lim1 INT,
  187. IN IN_lim2 INT)
  188. BEGIN
  189. DECLARE L_query TEXT default "";
  190. DECLARE L_pos INT UNSIGNED DEFAULT 0;
  191. SELECT BIN_TO_UUID(dp.documentId) AS id, SUM(pw.count) AS wordcount
  192. FROM documents_pages dp
  193. JOIN pages_words pw ON dp.pageId = pw.pageId
  194. JOIN words w ON pw.wordId = w.id
  195. WHERE w.word REGEXP CONCAT("(", IN_words, ")")
  196. GROUP BY dp.documentId
  197. ORDER BY wordcount DESC
  198. LIMIT IN_lim1, IN_lim2;
  199. END ;;
  200. DELIMITER ;
  201. DELIMITER ;;
  202. CREATE PROCEDURE `get_primary_page`(
  203. IN IN_documentid BINARY(16))
  204. BEGIN
  205. DECLARE LOC_pageid BINARY(16) DEFAULT NULL;
  206. SELECT dp.pageId INTO LOC_pageid FROM
  207. documents_pages dp
  208. JOIN pages p ON dp.pageId = p.id
  209. WHERE dp.documentId = IN_documentid
  210. AND p.isprimary = 1;
  211. IF LOC_pageid IS NULL
  212. THEN
  213. SELECT dp.pageId INTO LOC_pageid FROM
  214. documents_pages dp
  215. JOIN pages p ON dp.pageId = p.id
  216. WHERE dp.documentId = IN_documentid
  217. ORDER BY RAND() LIMIT 1;
  218. END IF;
  219. SELECT BIN_TO_UUID(LOC_pageid) AS pageId;
  220. END ;;
  221. DELIMITER ;
  222. DELIMITER ;;
  223. CREATE PROCEDURE `set_primary_page`(
  224. IN IN_pageid BINARY(16))
  225. BEGIN
  226. DECLARE LOC_documentid BINARY(16) DEFAULT NULL;
  227. SELECT documentId INTO LOC_documentid FROM documents_pages WHERE pageId = IN_pageid;
  228. UPDATE
  229. documents_pages dp
  230. JOIN pages p ON dp.pageId = p.id
  231. SET p.isprimary = 0
  232. WHERE dp.documentId = LOC_documentid;
  233. UPDATE
  234. pages
  235. SET isprimary = 1
  236. WHERE id = IN_pageid;
  237. END ;;
  238. DELIMITER ;
  239. DELIMITER ;;
  240. CREATE PROCEDURE `set_page_status`(
  241. IN IN_pageid BINARY(16),
  242. IN IN_status ENUM('nodata', 'inprogress', 'deleted', 'ok')
  243. )
  244. BEGIN
  245. UPDATE pages SET status = IN_status WHERE id = UUID_TO_BIN(IN_pageid);
  246. END ;;
  247. DELIMITER ;