Browse Source

First commit

Jonatan Gezelius 1 year ago
commit
c9f005cf9d
5 changed files with 789 additions and 0 deletions
  1. 24 0
      JCL-debug.kicad_dbl
  2. 48 0
      JCL.kicad_dbl
  3. 232 0
      sql/Scratchpad.sql
  4. 310 0
      sql/jegatroncomponents_recreate.sql
  5. 175 0
      sql/jegatroncomponents_tests.sql

+ 24 - 0
JCL-debug.kicad_dbl

@@ -0,0 +1,24 @@
+{
+    "meta": {
+        "version": 0
+    },
+    "name": "JCL",
+    "description": "A database of synth components",
+    "source": {
+        "type": "odbc",
+        "dsn": "KiCAD",
+        "username": "",
+        "password": "",
+        "timeout_seconds": 2,
+        "connection_string": ""
+    },
+    "libraries": [
+        {
+            "name": "Resistors",
+            "table": "kicad_resistors",
+            "key": "internal_pn",
+            "symbols": "kicad_symbol",
+            "footprints": "kicad_footprint"
+        }
+    ]
+}

+ 48 - 0
JCL.kicad_dbl

@@ -0,0 +1,48 @@
+{
+    "meta": {
+        "version": 0
+    },
+    "name": "JCL",
+    "description": "A database of synth components",
+    "source": {
+        "type": "odbc",
+        "dsn": "KiCAD",
+        "username": "",
+        "password": "",
+        "timeout_seconds": 2,
+        "connection_string": ""
+    },
+    "libraries": [
+        {
+            "name": "Resistors",
+            "table": "kicad_resistors",
+            "key": "internal_pn",
+            "symbols": "kicad_symbol",
+            "footprints": "kicad_footprint",
+            "fields": [
+                {
+                    "column": "internal_pn",
+                    "name": "IPN",
+                    "visible_on_add": true,
+                    "visible_in_chooser": true,
+                    "show_name": true,
+                    "inherit_properties": false
+                },
+                {
+                    "column": "value_str",
+                    "name": "Value",
+                    "visible_on_add": true,
+                    "visible_in_chooser": true,
+                    "show_name": false
+                }
+            ],
+            "properties": {
+                "description": "description",
+                "footprint_filters": "footprint_filters",
+                "keywords": "keywords",
+                "exclude_from_bom": "exclude_from_bom",
+                "exclude_from_board": "exclude_from_board"
+            }
+        }
+    ]
+}

+ 232 - 0
sql/Scratchpad.sql

@@ -0,0 +1,232 @@
+describe resistors;
+
+SET GLOBAL general_log=0;
+
+select * from resistors ;
+
+insert into resistors(`MPN`) VALUES('Yomandude');
+
+show create table resistors;
+
+drop table resistors ;
+
+DELETE FROM internal_parts ;
+
+
+SET @pn := CAST(678 AS int);
+SET @pnstrtmp := lpad(cast(@pn AS char), 7, 0);
+SELECT @pnstrtmp;
+SET @pnstr := concat(substring(@pnstrtmp, 1, 2), '-', substring(@pnstrtmp, 3, 2), '-', substring(@pnstrtmp, 5, 3));
+SELECT @pnstr;
+
+CREATE TABLE `resistors` (
+  `MPN` varchar(100) NOT NULL,
+  `Symbols` varchar(100) DEFAULT NULL,
+  `Footprints` varchar(100) DEFAULT NULL,
+  `Value` varchar(20) DEFAULT NULL,
+  `Description` varchar(100) DEFAULT NULL,
+  `Footprint Filters` varchar(100) DEFAULT NULL,
+  `Keywords` varchar(100) DEFAULT NULL,
+  `No BOM` int DEFAULT 0,
+  `Schematic Only` int DEFAULT 0,
+  `Datasheet URL` varchar(150) default NULL,
+  PRIMARY KEY `Resistors_un` (`MPN`)
+) ENGINE=InnoDB AUTO_INCREMENT=4 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci
+
+alter table resistors modify `Schematic only`  int DEFAULT 0;
+
+alter table resistors rename column `Schematic only` to `Exclude from board`;
+alter table resistors rename column `No BOM` to `Exclude from BOM`;
+
+CREATE TABLE `resistors` (
+  `mpn` varchar(100) NOT NULL,
+  `symbols` varchar(100) DEFAULT NULL,
+  `footprints` varchar(100) DEFAULT NULL,
+  `value` varchar(20) DEFAULT NULL,
+  `description` varchar(100) DEFAULT NULL,
+  `footprint_filters` varchar(100) DEFAULT NULL,
+  `keywords` varchar(100) DEFAULT NULL,
+  `exclude_from_bom` int(11) DEFAULT 0,
+  `exclude_from_board` int(11) DEFAULT 0,
+  `datasheet_url` varchar(150) DEFAULT NULL,
+  PRIMARY KEY (`MPN`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci
+
+
+show create table internal_parts ;
+
+explain select * from manufacturer_parts mp left join supplier_part_numbers spn on mp.mpn = spn.mpn and mp.mfr = spn.mfr ;
+
+select * from internal_parts ip where part_type = 'Chip Resistor';
+
+show create table manufacturer_parts ;
+
+CREATE TABLE `manufacturer_parts` (
+  `mpn` varchar(50) NOT NULL,
+  `mfr` varchar(50) NOT NULL,
+  `internal_pno` int(11) DEFAULT NULL,
+  PRIMARY KEY (`mpn`,`mfr`),
+  KEY `manufacturer_parts_FK_1` (`internal_pno`),
+  KEY `manufacturer_parts_FK` (`mfr`),
+  CONSTRAINT `manufacturer_parts_FK` FOREIGN KEY (`mfr`) REFERENCES `manufacturers` (`mfr`) ON DELETE CASCADE ON UPDATE CASCADE
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci
+
+select * from internal_parts ip
+join internal_resistor_parameters irp ON ip.internal_pno = irp.internal_pno
+join resistor_parameters rp on irp.resistor_parameters_id = rp.id ;
+
+
+select * from manufacturer_parts mp 
+join manufacturer_resistor_parameters mrp ON mp.mpn = mrp.mpn and mp.mfr = mrp.mfr
+join resistor_parameters rp on mrp.resistor_parameters_id = rp.id ;
+
+select * from resistor_parameters rp ;
+
+# CONSTRAINT CHK_NULL CHECK ((SOLD IS NOT NULL) OR (MANUFACTURED IS NOT NULL) OR (PURCHASED IS NOT NULL))
+
+ALTER TABLE resistor_parameters ADD CONSTRAINT resistor_parameters_check check (mfr is not null);
+
+alter table resistor_parameters drop constraint resistor_parameters_check;
+
+ALTER TABLE resistor_parameters ADD CONSTRAINT resistor_parameters_check_owner check
+(((internal_pno is not null) and ((mpn is null) and (mfr is null))) or
+((internal_pno is null) and ((mpn is not null) and (mfr is not null))));
+
+
+CREATE TABLE `A` (
+ `id` int NOT NULL AUTO_INCREMENT,
+ `value` int,
+ PRIMARY KEY (`id`)
+);
+drop table if exists A;
+
+
+INSERT INTO `A` (`value`) VALUES (5);
+SELECT LAST_INSERT_ID();
+
+CREATE TABLE `B` (
+ `id` int NOT NULL,
+ `val1` int,
+ PRIMARY KEY (`id`),
+ CONSTRAINT `a_nonsense_foreign_key` FOREIGN KEY (`val1`) REFERENCES `A` (`id`) ON UPDATE CASCADE,
+ CONSTRAINT `a_nonsense_check` CHECK (`val1` > 10)
+);
+drop table if exists B;
+
+CONSTRAINT `only_one_value` CHECK ((`val1`IS NOT NULL AND `val2` IS NULL) OR (`val1` IS NULL AND `val2` IS NOT NULL))
+
+show create table resistor_parameters;
+CREATE TABLE `resistor_parameters` (
+  `id` int(11) NOT NULL AUTO_INCREMENT,
+  `internal_pno` int(11) DEFAULT NULL,
+  `mpn` varchar(50) DEFAULT NULL,
+  `mfr` varchar(50) DEFAULT NULL,
+  `val2` float DEFAULT NULL,
+  PRIMARY KEY (`id`),
+  UNIQUE KEY `resistor_parameters_un` (`internal_pno`),
+  UNIQUE KEY `resistor_parameters_un_2` (`mpn`,`mfr`),
+  CONSTRAINT `resistor_parameters_check_owner` CHECK (`internal_pno` is not null and `mpn` is null and `mfr` is null or `internal_pno` is null and `mpn` is not null and `mfr` is not null)
+) ENGINE=InnoDB AUTO_INCREMENT=9 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci
+
+
+show create table internal_parts;
+CREATE TABLE `internal_parts` (
+  `internal_pno` int(11) NOT NULL AUTO_INCREMENT,
+  `part_name` varchar(50) NOT NULL,
+  `description` varchar(100) DEFAULT NULL,
+  `part_type` varchar(50) NOT NULL,
+  PRIMARY KEY (`internal_pno`),
+  UNIQUE KEY `internal_parts_un` (`part_name`),
+  KEY `internal_parts_FK` (`part_type`),
+  CONSTRAINT `internal_parts_FK` FOREIGN KEY (`part_type`) REFERENCES `part_types` (`part_type`) ON UPDATE CASCADE
+) ENGINE=InnoDB AUTO_INCREMENT=13 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci
+
+
+SELECT concat ('yoman', ' dude', ' shit', 4) AS `a`;
+
+PREPARE test_statement FROM concat('select * from ', 'a', ';');
+EXECUTE test_statement;
+DEALLOCATE PREPARE test_statement;
+
+
+USe node_todo_list;
+
+CREATE TABLE todos (
+	id_code varchar(36) NOT NULL UNIQUE,
+	to_do varchar(255) NOT NULL,
+	completed boolean
+);
+
+CREATE USER 'todo_admin'@'localhost' IDENTIFIED BY 'leelu_dallas_multipass-6';
+GRANT SELECT, INSERT, UPDATE ON node_todo_list.* TO 'todo_admin'@'localhost';
+INSERT INTO todos (id_code, to_do, completed) VALUES ('todo1','Get something done', TRUE);
+
+INSERT INTO todos (id_code, to_do, completed) VALUES ('todo2','Get another thing done', FALSE);
+
+SHOW CREATE TABLE qualified_parts ;
+
+SELECT ip.internal_pn, ip.part_description AS description, gdcr.resistance AS value, cp.package_display_name, ip.exclude_from_bom, ip.exclude_from_board, fk.kicad_footprint, fk.kicad_footprint_filter, sk.kicad_symbol  FROM internal_parts ip
+JOIN group_details_chip_resistor gdcr ON ip.internal_pn = gdcr.internal_pn
+JOIN component_packages cp ON gdcr.component_package = cp.component_package
+LEFT JOIN footprints_kicad fk ON gdcr.component_package = fk.component_package 
+LEFT JOIN symbols_kicad sk ON gdcr.component_symbol = sk.component_symbol;
+
+CREATE OR REPLACE VIEW kicad_resistors
+AS
+SELECT ip.internal_pn, ip.part_description AS description, gdcr.resistance AS value, cp.package_display_name, ip.exclude_from_bom, ip.exclude_from_board, fk.kicad_footprint, fk.kicad_footprint_filter, sk.kicad_symbol  FROM internal_parts ip
+JOIN group_details_chip_resistor gdcr ON ip.internal_pn = gdcr.internal_pn
+JOIN component_packages cp ON gdcr.component_package = cp.component_package
+LEFT JOIN footprints_kicad fk ON gdcr.component_package = fk.component_package 
+LEFT JOIN symbols_kicad sk ON gdcr.component_symbol = sk.component_symbol;
+
+
+DELIMITER //
+CREATE OR REPLACE FUNCTION to_value_string(n float, unit varchar(1)) RETURNS varchar(10)
+BEGIN
+ DECLARE exponent int;
+ DECLARE suffix varchar(2);
+ DECLARE string_to_return varchar(10);
+ 
+ SET exponent = floor(log10(n)/3);
+ SET exponent = greatest(-5, exponent);
+ SET exponent = least(3, exponent);
+
+ IF exponent <= -5 THEN
+  SET suffix = 'f';
+ ELSEIF exponent = -4 THEN
+  SET suffix = 'p';
+ ELSEIF exponent = -3 THEN
+  SET suffix = 'n';
+ ELSEIF exponent = -2 THEN
+  SET suffix = 'u';
+ ELSEIF exponent = -1 THEN
+  SET suffix = 'm';
+ ELSEIF exponent = 0 THEN
+  SET suffix = unit;
+ ELSEIF exponent = 1 THEN
+  SET suffix = 'k';
+ ELSEIF exponent = 2 THEN
+  SET suffix = 'M';
+ ELSEIF exponent >= 3 THEN
+  SET suffix = 'G';
+ END IF;
+
+ SET string_to_return = trim( TRAILING '0' from CAST( round(n/(power(1000, exponent)), 3) AS varchar(10) ));
+ -- SET string_to_return = n;
+
+ IF instr(string_to_return, '.') THEN
+  SET string_to_return = replace(string_to_return, '.', suffix);
+ ELSE
+  SET string_to_return = concat(string_to_return, suffix); 
+ END IF;
+
+ RETURN string_to_return;
+END 
+//
+DELIMITER ;
+
+SELECT to_value_string(0.001, 'R');
+SELECT to_value_string(1, 'R');
+SELECT to_value_string(1.001, 'R');
+SELECT to_value_string(10100, 'R');
+SELECT to_value_string(333333, 'R');

+ 310 - 0
sql/jegatroncomponents_recreate.sql

@@ -0,0 +1,310 @@
+
+
+/* Remove everything */
+
+
+-- Remove all group detail tables
+SET @tbls = (
+SELECT GROUP_CONCAT(TABLE_NAME)
+	FROM information_schema.TABLES t
+	WHERE t.TABLE_SCHEMA = 'jegatroncomponents'
+	AND TABLE_NAME LIKE 'group_details%');
+-- SELECT @tbls;
+
+delimiter //
+BEGIN NOT ATOMIC
+	IF @tbls IS NOT null THEN
+		PREPARE stmt FROM concat('DROP TABLE ', @tbls);
+		EXECUTE stmt;
+		DEALLOCATE PREPARE stmt;
+	END IF;
+END;
+//
+delimiter ;
+
+
+-- Remove all view that I know of
+DROP VIEW IF EXISTS kicad_resistors;
+
+-- Remove all functions and stored procedures
+DROP PROCEDURE IF EXISTS `add_part_group`;
+DROP PROCEDURE IF EXISTS `add_internal_part`;
+DROP PROCEDURE IF EXISTS `add_manufacturer_part`;
+DROP FUNCTION IF EXISTS `to_value_string`;
+DROP FUNCTION IF EXISTS `to_pn_string`;
+
+-- Remove all tables
+SET FOREIGN_KEY_CHECKS=0;
+DROP TABLE IF EXISTS `qualified_parts`;
+DROP TABLE IF EXISTS `part_group_properties`;
+DROP TABLE IF EXISTS `internal_parts`;
+DROP TABLE IF EXISTS `part_groups`;
+DROP TABLE IF EXISTS `manufacturer_parts`;
+DROP TABLE IF EXISTS `manufacturers`;
+DROP TABLE IF EXISTS `supplier_part_numbers`;
+DROP TABLE IF EXISTS `suppliers`;
+DROP TABLE IF EXISTS `debug_msg`;
+DROP TABLE IF EXISTS `component_packages`;
+DROP TABLE IF EXISTS `component_symbols`;
+DROP TABLE IF EXISTS `footprints_kicad`;
+DROP TABLE IF EXISTS `symbols_kicad`;
+SET FOREIGN_KEY_CHECKS=1;
+-- Finished removing everything
+
+/* Debug table to store whatever in */
+/*
+CREATE TABLE `debug_msg` (
+msg_id int PRIMARY KEY AUTO_INCREMENT,
+msg text
+);
+*/
+
+/* Contains listing of part groups. Each group should have a dedicated
+ * table containing part group specific details. */
+CREATE TABLE `part_groups` (
+  `part_group_id` varchar(50) NOT NULL,
+  `part_group_detail_table` varchar(50) DEFAULT NULL,
+  `group_display_name` varchar(50) DEFAULT NULL,
+  `group_description` text DEFAULT NULL,
+  PRIMARY KEY (`part_group_id`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+/* Helper function for adding component categories (groups)
+ * It creates a row in part_group table and a corresponding new table */
+DELIMITER //
+CREATE OR REPLACE PROCEDURE `add_part_group`(
+ IN group_name varchar(50),
+ IN group_display_name varchar(50),
+ IN group_description text)
+BEGIN
+	SET @table_name := concat('group_details_', group_name);
+
+	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);
+
+	SET @create_detail_table_query := concat('CREATE TABLE `', @table_name, '` (
+		`detail_id` int NOT NULL AUTO_INCREMENT,
+		PRIMARY KEY `', @table_name, '_PK` (`detail_id`),
+		`internal_pn` int DEFAULT NULL,
+		CONSTRAINT `', @table_name, '_part_FK` FOREIGN KEY (`internal_pn`) REFERENCES `internal_parts` (`internal_pn`) ON DELETE CASCADE,
+		CONSTRAINT `', @table_name, '_part_AK` UNIQUE (`internal_pn`),
+		`mpn` varchar(50) DEFAULT NULL,
+		`mfr` varchar(50) DEFAULT NULL,
+		CONSTRAINT `', @table_name, '_mpn_FK` FOREIGN KEY (`mpn`, `mfr`) REFERENCES `manufacturer_parts` (`mpn`, `mfr`) ON DELETE CASCADE ON UPDATE CASCADE,
+		CONSTRAINT `', @table_name, '_mpn_AK` UNIQUE (`mpn`, `mfr`)
+	) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+	');
+
+	-- INSERT INTO `debug_msg`(`msg`) VALUES (@create_detail_table_query);
+
+	EXECUTE IMMEDIATE @create_detail_table_query;
+	 
+END;
+//
+DELIMITER ;
+
+
+CREATE TABLE `internal_parts` (
+  `internal_pn` int(11) NOT NULL AUTO_INCREMENT,
+  `part_group_id` varchar(50) NOT NULL,
+  `part_description` text DEFAULT NULL,
+  `exclude_from_bom` tinyint(1) NOT NULL DEFAULT 0,
+  `exclude_from_board` tinyint(1) NOT NULL DEFAULT 0,
+  PRIMARY KEY (`internal_pn`),
+  KEY `internal_parts_group_id_fk` (`part_group_id`),
+  CONSTRAINT `internal_parts_group_id_fk` FOREIGN KEY (`part_group_id`) REFERENCES `part_groups` (`part_group_id`)
+) ENGINE=InnoDB AUTO_INCREMENT=1062 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+ALTER TABLE `internal_parts` AUTO_INCREMENT=1000000;
+
+# Helper function to convert int to a formatted part number string xx-xx-xxx
+delimiter //
+CREATE OR REPLACE FUNCTION to_pn_string(pn int) RETURNS varchar(9)
+BEGIN
+	DECLARE pnstrtmp varchar(7);
+	DECLARE pnstr varchar(9);
+	SET pnstrtmp := lpad(cast(pn AS char), 7, 0);
+	SET pnstr := concat(substring(pnstrtmp, 1, 2), '-', substring(pnstrtmp, 3, 2), '-', substring(pnstrtmp, 5, 3));
+	RETURN pnstr;
+END
+//
+delimiter ;
+
+/* Helper function for adding internal components
+ * It creates a row in internal parts table and a row in the corresponding details table */
+/*
+DELIMITER //
+CREATE OR REPLACE PROCEDURE `add_internal_part`(
+ IN part_display_name varchar(50),
+ IN part_group_id varchar(50),
+ IN part_description text,
+ OUT internal_pn int)
+BEGIN
+	SELECT pg.part_group_detail_table INTO @table_name FROM `part_groups` pg WHERE pg.part_group_id = part_group_id;
+
+	INSERT INTO `internal_parts` (`part_display_name`, `part_group_id`, `part_description`) VALUES (part_display_name, part_group_id, part_description);
+	SET @last_id := last_insert_id();
+	SET internal_pn := @last_id;
+	SET @part_detail_query := concat('INSERT INTO `', @table_name, '` (`internal_pn`) VALUES (', @last_id, ')');
+	-- SELECT @part_detail_query;
+	EXECUTE IMMEDIATE @part_detail_query;
+	 
+END;
+//
+DELIMITER ;
+*/
+
+CREATE TABLE `manufacturers` (
+  `mfr` varchar(50) NOT NULL,
+  `mfr_display_name` varchar(100) DEFAULT NULL,
+  `url` varchar(250) DEFAULT NULL,
+  PRIMARY KEY (`mfr`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+CREATE TABLE `manufacturer_parts` (
+  `mpn` varchar(50) NOT NULL,
+  `mfr` varchar(50) NOT NULL,
+  `part_group_id` varchar(50) NOT NULL,
+  `part_description` text DEFAULT NULL,
+  `lifecycle_status` enum('Active','NRND','Last Time Buy','Obsolete') NOT NULL,
+  PRIMARY KEY (`mpn`,`mfr`),
+  KEY `manufacturer_parts_mfr_FK` (`mfr`),
+  KEY `manufacturer_parts_group_id_fk` (`part_group_id`),
+  CONSTRAINT `manufacturer_parts_group_id_fk` FOREIGN KEY (`part_group_id`) REFERENCES `part_groups` (`part_group_id`),
+  CONSTRAINT `manufacturer_parts_mfr_FK` FOREIGN KEY (`mfr`) REFERENCES `manufacturers` (`mfr`) ON UPDATE CASCADE
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+
+/* Helper function for adding manufacturer components
+ * It creates a row in internal parts table and a row in the corresponding details table */
+/*
+DELIMITER //
+CREATE OR REPLACE PROCEDURE `add_manufacturer_part`(
+ IN mpn varchar(50),
+ IN mfr varchar(50),
+ IN part_group_id varchar(50),
+ IN part_description text)
+BEGIN
+	SELECT pg.part_group_detail_table INTO @table_name FROM `part_groups` pg WHERE pg.part_group_id = part_group_id;
+
+	INSERT INTO `manufacturer_parts` (`mpn`, `mfr`, `part_group_id`, `part_description`) VALUES (mpn, mfr, part_group_id, part_description);
+	SET @part_detail_query := concat('INSERT INTO `', @table_name, '` (`mpn`, `mfr`) VALUES (\'', mpn , '\', \'', mfr, '\' )');
+	-- SELECT @part_detail_query;
+	EXECUTE IMMEDIATE @part_detail_query;
+	 
+END;
+//
+DELIMITER ;
+*/
+
+CREATE TABLE `qualified_parts` (
+  `internal_pn` int(11) NOT NULL,
+  `mpn` varchar(50) NOT NULL,
+  `mfr` varchar(50) NOT NULL,
+  PRIMARY KEY (`internal_pn`,`mpn`,`mfr`),
+  KEY `qualified_parts_FK_1` (`mpn`,`mfr`),
+  CONSTRAINT `qualified_parts_FK` FOREIGN KEY (`internal_pn`) REFERENCES `internal_parts` (`internal_pn`) ON DELETE CASCADE ON UPDATE CASCADE,
+  CONSTRAINT `qualified_parts_FK_1` FOREIGN KEY (`mpn`, `mfr`) REFERENCES `manufacturer_parts` (`mpn`, `mfr`) ON DELETE CASCADE ON UPDATE CASCADE
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+CREATE TABLE `suppliers` (
+  `supplier` varchar(100) NOT NULL,
+  `url` varchar(100) DEFAULT NULL,
+  PRIMARY KEY (`supplier`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+CREATE TABLE `supplier_part_numbers` (
+  `supplier_pno` varchar(100) NOT NULL,
+  `supplier` varchar(100) NOT NULL,
+  `mpn` varchar(50) NOT NULL,
+  `mfr` varchar(100) NOT NULL,
+  `url` varchar(250) DEFAULT NULL,
+  PRIMARY KEY (`supplier_pno`,`supplier`),
+  KEY `supplier_part_numbers_FK_1` (`supplier`),
+  KEY `supplier_part_numbers_FK` (`mpn`,`mfr`),
+  CONSTRAINT `supplier_part_numbers_FK` FOREIGN KEY (`mpn`, `mfr`) REFERENCES `manufacturer_parts` (`mpn`, `mfr`) ON DELETE CASCADE ON UPDATE CASCADE,
+  CONSTRAINT `supplier_part_numbers_FK_1` FOREIGN KEY (`supplier`) REFERENCES `suppliers` (`supplier`) ON DELETE CASCADE ON UPDATE CASCADE
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+
+CREATE TABLE `component_packages` (
+  `component_package` varchar(50) NOT NULL,
+  `package_display_name` varchar(100) DEFAULT NULL,
+  PRIMARY KEY (`component_package`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+
+CREATE TABLE `footprints_kicad` (
+  `footprint_kicad_id` int(11) NOT NULL AUTO_INCREMENT,
+  `component_package` varchar(50) DEFAULT NULL,
+  `kicad_footprint` varchar(100) DEFAULT NULL,
+  `kicad_footprint_filter` varchar(100) DEFAULT NULL,
+  PRIMARY KEY (`footprint_kicad_id`),
+  UNIQUE KEY `footprints_kicad_AK` (`component_package`),
+  CONSTRAINT `footprints_kicad_FK` FOREIGN KEY (`component_package`) REFERENCES `component_packages` (`component_package`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+
+CREATE TABLE `component_symbols` (
+  `component_symbol` varchar(50) NOT NULL,
+  `symbol_display_name` varchar(100) DEFAULT NULL,
+  PRIMARY KEY (`component_symbol`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+
+CREATE TABLE `symbols_kicad` (
+  `kicad_symbol_id` int(11) NOT NULL AUTO_INCREMENT,
+  `component_symbol` varchar(50) DEFAULT NULL,
+  `kicad_symbol` varchar(100) DEFAULT NULL,
+  PRIMARY KEY (`kicad_symbol_id`),
+  UNIQUE KEY `symbols_kicad_AK` (`component_symbol`),
+  KEY `symbols_kicad_FK` (`component_symbol`),
+  CONSTRAINT `symbols_kicad_FK` FOREIGN KEY (`component_symbol`) REFERENCES `component_symbols` (`component_symbol`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
+
+
+/* Utility function for converting values to electrical value strings, e.g. 4k7 */
+DELIMITER //
+CREATE OR REPLACE FUNCTION to_value_string(n float, unit varchar(1)) RETURNS varchar(10)
+BEGIN
+ DECLARE exponent int;
+ DECLARE suffix varchar(2);
+ DECLARE string_to_return varchar(10);
+ 
+ SET exponent = floor(log10(n)/3);
+ SET exponent = greatest(-5, exponent);
+ SET exponent = least(3, exponent);
+
+ IF exponent <= -5 THEN
+  SET suffix = 'f';
+ ELSEIF exponent = -4 THEN
+  SET suffix = 'p';
+ ELSEIF exponent = -3 THEN
+  SET suffix = 'n';
+ ELSEIF exponent = -2 THEN
+  SET suffix = 'u';
+ ELSEIF exponent = -1 THEN
+  SET suffix = 'm';
+ ELSEIF exponent = 0 THEN
+  SET suffix = unit;
+ ELSEIF exponent = 1 THEN
+  SET suffix = 'k';
+ ELSEIF exponent = 2 THEN
+  SET suffix = 'M';
+ ELSEIF exponent >= 3 THEN
+  SET suffix = 'G';
+ END IF;
+
+ SET string_to_return = trim( TRAILING '0' from CAST( round(n/(power(1000, exponent)), 3) AS varchar(10) ));
+ -- SET string_to_return = n;
+
+ IF instr(string_to_return, '.') THEN
+  SET string_to_return = replace(string_to_return, '.', suffix);
+ ELSE
+  SET string_to_return = concat(string_to_return, suffix); 
+ END IF;
+
+ RETURN string_to_return;
+END 
+//
+DELIMITER ;
+

+ 175 - 0
sql/jegatroncomponents_tests.sql

@@ -0,0 +1,175 @@
+
+/*
+CALL `add_part_group`('krypton', 'Kryptoner', 'En krypton är typiskt dålig för stålmannen');
+CALL `add_part_group`('visp', 'Vispar', 'Med en visp kan man göra smör');
+CALL `add_part_group`('talisman', 'Tasmanska jävlar', 'Det är hittepå');
+CALL `add_part_group`('Oloong', 'Semi-grönt/svart & Te', 'Mellantinget i fermenteringen av teet, brukar förekomma i rullade bollar. Bryggs i 85 grader, 4 minuter.');
+
+
+
+
+CALL add_internal_part('Kinesiskt Oloong', 'Oloong', 'Kinesiskt Oloong som smakar mycket te', @fick_internal_pn); 
+SELECT @fick_internal_pn;
+
+SELECT * 
+FROM internal_parts ip
+JOIN part_groups pg ON ip.part_group_id = pg.part_group_id
+JOIN group_details_oloong gdo ON ip.internal_pn = gdo.internal_pn 
+WHERE ip.internal_pn = 4;
+
+
+SET @part_display_name := 'Token item nr.1';
+SET @part_group_id := 'krypton';
+SET @part_description := 'This token will make thing great again';
+CALL add_internal_part(@part_display_name, @part_group_id, @part_description, @mymandude);
+SELECT @mymandude;
+
+SET @part_display_name := 'Token item nr.2';
+SET @part_group_id := 'krypton';
+CALL add_internal_part(@part_display_name, @part_group_id, @part_description, @mymandude);
+SELECT @mymandude;
+
+SET @part_display_name := 'Token item nr.3';
+SET @part_group_id := 'visp';
+CALL add_internal_part(@part_display_name, @part_group_id, @part_description, @mymandude);
+SELECT @mymandude;
+
+DELETE FROM `internal_parts` WHERE `internal_pn` = 1;
+
+SELECT * 
+FROM `internal_parts` ip
+JOIN `group_details_krypton` gdk ON ip.internal_pn = gdk.internal_pn; 
+*/
+
+CALL `add_part_group`('car', 'Cars', 'Automotive vehicles for transporting people');
+
+ALTER TABLE jegatroncomponents.group_details_car ADD(
+  `series` varchar(100) DEFAULT NULL,
+  `color` varchar(50) NOT NULL,
+  `release_date` timestamp NOT NULL
+);
+
+INSERT INTO manufacturers (mfr) VALUES ('volvo');
+
+
+INSERT INTO manufacturer_parts (mpn, mfr, part_group_id, part_description, lifecycle_status)
+VALUES ('S60', 'volvo', 'car', 'A good car', 'Obsolete'),
+('S80', 'volvo', 'car', 'A bigger good car', 'Obsolete');
+
+
+CALL `add_part_group`('chip_resistor', 'Chip Resistor - SMD', 'Surface mount resistors');
+
+ALTER TABLE jegatroncomponents.group_details_chip_resistor ADD(
+  `series` varchar(100) DEFAULT NULL,
+  `resistance` float NOT NULL,
+  `resistance_str` varchar(10) DEFAULT NULL,
+  `resistance_tolerance_upper` float NOT NULL,
+  `resistance_tolerance_lower` float NOT NULL,
+  `power` float NOT NULL,
+  `resistor_type` varchar(50) NOT NULL,
+  `temperature_max` float NOT NULL,
+  `temperature_min` float NOT NULL,
+  `temperature_coefficient_upper` float NOT NULL,
+  `temperature_coefficient_lower` float NOT NULL,
+  `dimension_height` float NOT NULL,
+  `dimension_width` float NOT NULL,
+  `dimension_length` float NOT NULL,
+  `component_package` varchar(50) NOT NULL,
+  `component_symbol` varchar(50) NOT NULL,
+  `number_of_terminals` int DEFAULT 2 NOT NULL,
+  CONSTRAINT `group_details_chip_resistor_package_FK` FOREIGN KEY (`component_package`) REFERENCES `component_packages` (`component_package`) ON UPDATE CASCADE,
+  CONSTRAINT `group_details_chip_resistor_symbol_FK` FOREIGN KEY (`component_symbol`) REFERENCES `component_symbols` (`component_symbol`) ON UPDATE CASCADE
+);
+
+delimiter //
+CREATE OR REPLACE TRIGGER add_resistance_str
+BEFORE INSERT ON jegatroncomponents.group_details_chip_resistor
+FOR EACH ROW 
+IF NEW.`resistance_str` IS NULL THEN
+ SET NEW.resistance_str := to_value_string(NEW.resistance, 'R');
+END IF;
+//
+CREATE OR REPLACE TRIGGER add_resistance_str
+BEFORE UPDATE ON jegatroncomponents.group_details_chip_resistor
+FOR EACH ROW 
+IF NEW.`resistance_str` IS NULL THEN
+ SET NEW.resistance_str := to_value_string(NEW.resistance, 'R');
+END IF;
+//
+delimiter ;
+
+DROP VIEW IF EXISTS kicad_resistors;
+CREATE OR REPLACE VIEW kicad_resistors
+AS
+SELECT ip.internal_pn, to_pn_string(ip.internal_pn) AS internal_pn_string, ip.part_description AS description, gdcr.resistance AS value,
+ cp.package_display_name, ip.exclude_from_bom, ip.exclude_from_board, fk.kicad_footprint,
+ fk.kicad_footprint_filter, sk.kicad_symbol,
+ gdcr.resistance_str AS value_str
+FROM internal_parts ip
+JOIN group_details_chip_resistor gdcr ON ip.internal_pn = gdcr.internal_pn
+JOIN component_packages cp ON gdcr.component_package = cp.component_package
+LEFT JOIN footprints_kicad fk ON gdcr.component_package = fk.component_package 
+LEFT JOIN symbols_kicad sk ON gdcr.component_symbol = sk.component_symbol;
+
+# SELECT * FROM kicad_resistors kr ;
+
+
+INSERT INTO manufacturers (mfr) VALUES ('yageo');
+INSERT INTO manufacturers (mfr) VALUES ('tdk');
+
+DELETE FROM component_packages ;
+INSERT INTO component_packages (component_package, package_display_name)
+VALUES
+('R01005', '01005 (0402 Metric)'),
+('R0201', '0201 (0603 Metric)'),
+('R0402', '0402 (1010 Metric)'),
+('R0603', '0603 (1608 Metric)'),
+('R0805', '0805 (2012 Metric)'),
+('R1206', '1206 (3216 Metric)'),
+('R1210', '1210 (3225 Metric)'),
+('R1812', '1812 (4532 Metric)'),
+('R2010', '2010 (5025 Metric)'),
+('R2512', '2512 (6332 Metric)'),
+('C01005', '01005 (0402 Metric)'),
+('C0201', '0201 (0603 Metric)'),
+('C0402', '0402 (1010 Metric)'),
+('C0603', '0603 (1608 Metric)'),
+('C0805', '0805 (2012 Metric)'),
+('C1206', '1206 (3216 Metric)'),
+('C1210', '1210 (3225 Metric)')
+ON duplicate KEY UPDATE package_display_name = package_display_name;
+
+DELETE FROM footprints_kicad ;
+INSERT INTO footprints_kicad (component_package, kicad_footprint, kicad_footprint_filter)
+VALUES
+('R01005', 'Resistor_SMD:R_01005_0402Metric', 'Resistor_SMD:R_01005_*'),
+('R0201', 'Resistor_SMD:R_0201_0603Metric', 'Resistor_SMD:R_0201_*'),
+('R0402', 'Resistor_SMD:R_0402_1010Metric', 'Resistor_SMD:R_0402_*'),
+('R0603', 'Resistor_SMD:R_0603_1608Metric', 'Resistor_SMD:R_0603_*'),
+('R0805', 'Resistor_SMD:R_0805_2012Metric', 'Resistor_SMD:R_0805_*'),
+('R1206', 'Resistor_SMD:R_1206_3216Metric', 'Resistor_SMD:R_1206_*'),
+('R1210', 'Resistor_SMD:R_1210_3225Metric', 'Resistor_SMD:R_1210_*'),
+('R1812', 'Resistor_SMD:R_1812_4532Metric', 'Resistor_SMD:R_1812_*'),
+('R2010', 'Resistor_SMD:R_2010_5025Metric', 'Resistor_SMD:R_2010_*'),
+('R2512', 'Resistor_SMD:R_2512_6332Metric', 'Resistor_SMD:R_2512_*'),
+('C01005', 'Capacitor_SMD:R_01005_0402Metric', 'Capacitor_SMD:R_01005_*'),
+('C0201', 'Capacitor_SMD:R_0201_0603Metric', 'Capacitor_SMD:R_0201_*'),
+('C0402', 'Capacitor_SMD:R_0402_1010Metric', 'Capacitor_SMD:R_0402_*'),
+('C0603', 'Capacitor_SMD:R_0603_1608Metric', 'Capacitor_SMD:R_0603_*'),
+('C0805', 'Capacitor_SMD:R_0805_2012Metric', 'Capacitor_SMD:R_0805_*'),
+('C1206', 'Capacitor_SMD:R_1206_3216Metric', 'Capacitor_SMD:R_1206_*'),
+('C1210', 'Capacitor_SMD:R_1210_3225Metric', 'Capacitor_SMD:R_1210_*')
+ON duplicate KEY UPDATE kicad_footprint = kicad_footprint;
+
+
+INSERT INTO component_symbols (component_symbol, symbol_display_name)
+VALUES
+('resistor_2pin', 'Resistor'),
+('capacitor_2pin', 'Capacitor');
+
+INSERT INTO symbols_kicad (component_symbol, kicad_symbol)
+VALUES
+('resistor_2pin', 'Device:R'),
+('capacitor_2pin', 'Device:C');
+
+