An unfinished system to manage all your paper documentation in an easy way.
選択できるのは25トピックまでです。 トピックは、先頭が英数字で、英数字とダッシュ('-')を使用した35文字以内のものにしてください。

autodoc.sql 7.8KB

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