jegatroncomponents_recreate.sql 10.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288
  1. /* Remove everything */
  2. -- Remove all group detail tables
  3. SET @tbls = (
  4. SELECT GROUP_CONCAT(TABLE_NAME)
  5. FROM information_schema.TABLES t
  6. WHERE t.TABLE_SCHEMA = 'jegatroncomponents'
  7. AND TABLE_NAME LIKE 'group_details%');
  8. -- SELECT @tbls;
  9. delimiter //
  10. BEGIN NOT ATOMIC
  11. IF @tbls IS NOT null THEN
  12. PREPARE stmt FROM concat('DROP TABLE ', @tbls);
  13. EXECUTE stmt;
  14. DEALLOCATE PREPARE stmt;
  15. END IF;
  16. END;
  17. //
  18. delimiter ;
  19. -- Remove all view that I know of
  20. DROP VIEW IF EXISTS kicad_resistors;
  21. -- Remove all functions and stored procedures
  22. DROP PROCEDURE IF EXISTS `add_part_group`;
  23. DROP PROCEDURE IF EXISTS `add_internal_part`;
  24. DROP PROCEDURE IF EXISTS `add_manufacturer_part`;
  25. DROP FUNCTION IF EXISTS `to_value_string`;
  26. DROP FUNCTION IF EXISTS `to_pn_string`;
  27. -- Remove all tables
  28. SET FOREIGN_KEY_CHECKS=0;
  29. DROP TABLE IF EXISTS `qualified_parts`;
  30. DROP TABLE IF EXISTS `part_group_properties`;
  31. DROP TABLE IF EXISTS `internal_parts`;
  32. DROP TABLE IF EXISTS `part_groups`;
  33. DROP TABLE IF EXISTS `manufacturer_parts`;
  34. DROP TABLE IF EXISTS `manufacturers`;
  35. DROP TABLE IF EXISTS `supplier_part_numbers`;
  36. DROP TABLE IF EXISTS `suppliers`;
  37. DROP TABLE IF EXISTS `debug_msg`;
  38. DROP TABLE IF EXISTS `component_packages`;
  39. DROP TABLE IF EXISTS `component_symbols`;
  40. DROP TABLE IF EXISTS `footprints_kicad`;
  41. DROP TABLE IF EXISTS `symbols_kicad`;
  42. SET FOREIGN_KEY_CHECKS=1;
  43. -- Finished removing everything
  44. /* Debug table to store whatever in */
  45. CREATE TABLE `debug_msg` (
  46. msg_id int PRIMARY KEY AUTO_INCREMENT,
  47. msg text
  48. );
  49. /* Contains listing of part groups. Each group should have a dedicated
  50. * table containing part group specific details. */
  51. CREATE TABLE `part_groups` (
  52. `part_group_id` varchar(50) NOT NULL,
  53. `part_group_detail_table` varchar(50) DEFAULT NULL,
  54. `group_display_name` varchar(50) DEFAULT NULL,
  55. `group_description` text DEFAULT NULL,
  56. PRIMARY KEY (`part_group_id`)
  57. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  58. /* Helper function for adding component categories (groups)
  59. * It creates a row in part_group table and a corresponding new table */
  60. DELIMITER //
  61. CREATE OR REPLACE PROCEDURE `add_part_group`(
  62. IN group_name varchar(50),
  63. IN group_display_name varchar(50),
  64. IN group_description text)
  65. BEGIN
  66. SET @table_name := concat('group_details_', group_name);
  67. INSERT INTO `part_groups` (`part_group_id`, `group_display_name`, `group_description`, `part_group_detail_table`) VALUES (group_name, group_display_name, group_description, @table_name);
  68. SET @create_detail_table_query := concat('CREATE TABLE `', @table_name, '` (
  69. `detail_id` int NOT NULL AUTO_INCREMENT,
  70. PRIMARY KEY `', @table_name, '_PK` (`detail_id`),
  71. `internal_pn` int DEFAULT NULL,
  72. CONSTRAINT `', @table_name, '_part_FK` FOREIGN KEY (`internal_pn`) REFERENCES `internal_parts` (`internal_pn`) ON DELETE CASCADE,
  73. CONSTRAINT `', @table_name, '_part_AK` UNIQUE (`internal_pn`),
  74. `internal_pn_str` varchar(9) DEFAULT NULL,
  75. `mpn` varchar(50) DEFAULT NULL,
  76. `mfr` varchar(50) DEFAULT NULL,
  77. CONSTRAINT `', @table_name, '_mpn_FK` FOREIGN KEY (`mpn`, `mfr`) REFERENCES `manufacturer_parts` (`mpn`, `mfr`) ON DELETE CASCADE ON UPDATE CASCADE,
  78. CONSTRAINT `', @table_name, '_mpn_AK` UNIQUE (`mpn`, `mfr`)
  79. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  80. ');
  81. -- INSERT INTO `debug_msg`(`msg`) VALUES (@create_detail_table_query);
  82. EXECUTE IMMEDIATE @create_detail_table_query;
  83. SET @create_trigger_a := concat('
  84. CREATE OR REPLACE TRIGGER ', @table_name, '_add_pn_str
  85. BEFORE INSERT ON `', @table_name, '`
  86. FOR EACH ROW
  87. SET NEW.internal_pn_str := to_pn_string(NEW.internal_pn);');
  88. -- INSERT INTO `debug_msg`(`msg`) VALUES (@create_trigger_a);
  89. EXECUTE IMMEDIATE @create_trigger_a;
  90. SET @create_triggers_b := concat('
  91. CREATE OR REPLACE TRIGGER ', @table_name, '_update_pn_str
  92. BEFORE UPDATE ON `', @table_name, '`
  93. FOR EACH ROW
  94. SET NEW.internal_pn_str := to_pn_string(NEW.internal_pn);');
  95. -- INSERT INTO `debug_msg`(`msg`) VALUES (@create_triggers_b);
  96. EXECUTE IMMEDIATE @create_triggers_b;
  97. END;
  98. //
  99. DELIMITER ;
  100. CREATE TABLE `internal_parts` (
  101. `internal_pn` int(11) NOT NULL AUTO_INCREMENT,
  102. `part_group_id` varchar(50) NOT NULL,
  103. `part_description` text DEFAULT NULL,
  104. `exclude_from_bom` tinyint(1) NOT NULL DEFAULT 0,
  105. `exclude_from_board` tinyint(1) NOT NULL DEFAULT 0,
  106. PRIMARY KEY (`internal_pn`),
  107. KEY `internal_parts_group_id_fk` (`part_group_id`),
  108. CONSTRAINT `internal_parts_group_id_fk` FOREIGN KEY (`part_group_id`) REFERENCES `part_groups` (`part_group_id`)
  109. ) ENGINE=InnoDB AUTO_INCREMENT=1062 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  110. ALTER TABLE `internal_parts` AUTO_INCREMENT=1000000;
  111. # Helper function to convert int to a formatted part number string xx-xx-xxx
  112. delimiter //
  113. CREATE OR REPLACE FUNCTION to_pn_string(pn int) RETURNS varchar(9)
  114. BEGIN
  115. DECLARE pnstrtmp varchar(7);
  116. DECLARE pnstr varchar(9);
  117. SET pnstrtmp := lpad(cast(pn AS char), 7, 0);
  118. SET pnstr := concat(substring(pnstrtmp, 1, 2), '-', substring(pnstrtmp, 3, 2), '-', substring(pnstrtmp, 5, 3));
  119. RETURN pnstr;
  120. END
  121. //
  122. delimiter ;
  123. CREATE TABLE `manufacturers` (
  124. `mfr` varchar(50) NOT NULL,
  125. `mfr_display_name` varchar(100) DEFAULT NULL,
  126. `url` varchar(250) DEFAULT NULL,
  127. PRIMARY KEY (`mfr`)
  128. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  129. CREATE TABLE `manufacturer_parts` (
  130. `mpn` varchar(50) NOT NULL,
  131. `mfr` varchar(50) NOT NULL,
  132. `part_group_id` varchar(50) NOT NULL,
  133. `part_description` text DEFAULT NULL,
  134. `lifecycle_status` enum('Active','NRND','Last Time Buy','Obsolete') NOT NULL,
  135. PRIMARY KEY (`mpn`,`mfr`),
  136. KEY `manufacturer_parts_mfr_FK` (`mfr`),
  137. KEY `manufacturer_parts_group_id_fk` (`part_group_id`),
  138. CONSTRAINT `manufacturer_parts_group_id_fk` FOREIGN KEY (`part_group_id`) REFERENCES `part_groups` (`part_group_id`),
  139. CONSTRAINT `manufacturer_parts_mfr_FK` FOREIGN KEY (`mfr`) REFERENCES `manufacturers` (`mfr`) ON UPDATE CASCADE
  140. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  141. CREATE TABLE `qualified_parts` (
  142. `internal_pn` int(11) NOT NULL,
  143. `mpn` varchar(50) NOT NULL,
  144. `mfr` varchar(50) NOT NULL,
  145. PRIMARY KEY (`internal_pn`,`mpn`,`mfr`),
  146. KEY `qualified_parts_FK_1` (`mpn`,`mfr`),
  147. CONSTRAINT `qualified_parts_FK` FOREIGN KEY (`internal_pn`) REFERENCES `internal_parts` (`internal_pn`) ON DELETE CASCADE ON UPDATE CASCADE,
  148. CONSTRAINT `qualified_parts_FK_1` FOREIGN KEY (`mpn`, `mfr`) REFERENCES `manufacturer_parts` (`mpn`, `mfr`) ON DELETE CASCADE ON UPDATE CASCADE
  149. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  150. CREATE TABLE `suppliers` (
  151. `supplier` varchar(100) NOT NULL,
  152. `url` varchar(100) DEFAULT NULL,
  153. PRIMARY KEY (`supplier`)
  154. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  155. CREATE TABLE `supplier_part_numbers` (
  156. `supplier_pno` varchar(100) NOT NULL,
  157. `supplier` varchar(100) NOT NULL,
  158. `mpn` varchar(50) NOT NULL,
  159. `mfr` varchar(100) NOT NULL,
  160. `url` varchar(250) DEFAULT NULL,
  161. PRIMARY KEY (`supplier_pno`,`supplier`),
  162. KEY `supplier_part_numbers_FK_1` (`supplier`),
  163. KEY `supplier_part_numbers_FK` (`mpn`,`mfr`),
  164. CONSTRAINT `supplier_part_numbers_FK` FOREIGN KEY (`mpn`, `mfr`) REFERENCES `manufacturer_parts` (`mpn`, `mfr`) ON DELETE CASCADE ON UPDATE CASCADE,
  165. CONSTRAINT `supplier_part_numbers_FK_1` FOREIGN KEY (`supplier`) REFERENCES `suppliers` (`supplier`) ON DELETE CASCADE ON UPDATE CASCADE
  166. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  167. CREATE TABLE `component_packages` (
  168. `component_package` varchar(50) NOT NULL,
  169. `package_display_name` varchar(100) DEFAULT NULL,
  170. PRIMARY KEY (`component_package`)
  171. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  172. CREATE TABLE `footprints_kicad` (
  173. `footprint_kicad_id` int(11) NOT NULL AUTO_INCREMENT,
  174. `component_package` varchar(50) DEFAULT NULL,
  175. `kicad_footprint` varchar(100) DEFAULT NULL,
  176. `kicad_footprint_filter` varchar(100) DEFAULT NULL,
  177. PRIMARY KEY (`footprint_kicad_id`),
  178. UNIQUE KEY `footprints_kicad_AK` (`component_package`),
  179. CONSTRAINT `footprints_kicad_FK` FOREIGN KEY (`component_package`) REFERENCES `component_packages` (`component_package`)
  180. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  181. CREATE TABLE `component_symbols` (
  182. `component_symbol` varchar(50) NOT NULL,
  183. `symbol_display_name` varchar(100) DEFAULT NULL,
  184. PRIMARY KEY (`component_symbol`)
  185. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  186. CREATE TABLE `symbols_kicad` (
  187. `kicad_symbol_id` int(11) NOT NULL AUTO_INCREMENT,
  188. `component_symbol` varchar(50) DEFAULT NULL,
  189. `kicad_symbol` varchar(100) DEFAULT NULL,
  190. PRIMARY KEY (`kicad_symbol_id`),
  191. UNIQUE KEY `symbols_kicad_AK` (`component_symbol`),
  192. KEY `symbols_kicad_FK` (`component_symbol`),
  193. CONSTRAINT `symbols_kicad_FK` FOREIGN KEY (`component_symbol`) REFERENCES `component_symbols` (`component_symbol`)
  194. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
  195. /* Utility function for converting values to electrical value strings, e.g. 4k7 */
  196. DELIMITER //
  197. CREATE OR REPLACE FUNCTION to_value_string(n float, unit varchar(1)) RETURNS varchar(10)
  198. BEGIN
  199. DECLARE exponent int;
  200. DECLARE suffix varchar(2);
  201. DECLARE string_to_return varchar(10);
  202. IF n != 0 THEN
  203. SET exponent = floor(log10(n)/3);
  204. ELSE
  205. SET exponent = 0;
  206. END IF;
  207. SET exponent = greatest(-5, exponent);
  208. SET exponent = least(3, exponent);
  209. IF exponent <= -5 THEN
  210. SET suffix = 'f';
  211. ELSEIF exponent = -4 THEN
  212. SET suffix = 'p';
  213. ELSEIF exponent = -3 THEN
  214. SET suffix = 'n';
  215. ELSEIF exponent = -2 THEN
  216. SET suffix = 'u';
  217. ELSEIF exponent = -1 THEN
  218. SET suffix = 'm';
  219. ELSEIF exponent = 0 THEN
  220. SET suffix = unit;
  221. ELSEIF exponent = 1 THEN
  222. SET suffix = 'k';
  223. ELSEIF exponent = 2 THEN
  224. SET suffix = 'M';
  225. ELSEIF exponent >= 3 THEN
  226. SET suffix = 'G';
  227. END IF;
  228. SET string_to_return = trim( TRAILING '0' from CAST( round(n/(power(1000, exponent)), 3) AS varchar(10) ));
  229. -- SET string_to_return = n;
  230. IF instr(string_to_return, '.') THEN
  231. SET string_to_return = replace(string_to_return, '.', suffix);
  232. ELSE
  233. SET string_to_return = concat(string_to_return, suffix);
  234. END IF;
  235. RETURN string_to_return;
  236. END
  237. //
  238. DELIMITER ;