Import product zusatzstoffe and added new data

This commit is contained in:
Administrator 2022-05-11 15:17:18 +02:00
parent 07678220be
commit b02327dd88
2 changed files with 139 additions and 25 deletions

View File

@ -96,8 +96,7 @@ CREATE TABLE IF NOT EXISTS enthaeltZusatzstoff
Anwendungsgrund varchar(5), Anwendungsgrund varchar(5),
foreign key (ProduktID) references Produkt (ProduktID), foreign key (ProduktID) references Produkt (ProduktID),
foreign key (E_Nummer) references Zusatzstoff (E_Nummer), foreign key (E_Nummer) references Zusatzstoff (E_Nummer),
foreign key (Anwendungsgrund) references Zusatzstoffklase(Anwendungsgrund), primary key (ProduktID, E_Nummer)
primary key (ProduktID, E_Nummer, Anwendungsgrund)
); );
CREATE TABLE IF NOT EXISTS Zusatzstoffunvertraeglichkeit CREATE TABLE IF NOT EXISTS Zusatzstoffunvertraeglichkeit

View File

@ -1,14 +1,35 @@
/* /*
---------------------------------- Zusatzstoff ---------------------------------- ---------------------------------- Zusatzstoffklasse ----------------------------------
*/ */
LOAD DATA LOCAL INFILE 'Programmentwurf/E_nummern.csv' INTO TABLE Zusatzstoff LOAD DATA LOCAL INFILE 'Programmentwurf/Zusatzstoffe_Klassen.csv' INTO TABLE Zusatzstoffklase
CHARACTER SET latin1 CHARACTER SET latin1
FIELDS terminated by ';' FIELDS terminated by ';'
LINES TERMINATED BY '\n' LINES TERMINATED BY '\n'
(@e, @z, @dummy) (@b, @g)
SET E_Nummer = TRIM(@e), Zusatzstoffbezeichnung = TRIM(@z); SET Anwendungsgrund = REGEXP_REPLACE(@g, '[^a-zäöüßA-ZÄÖÜ]+', ''), Anwendungsgrundbezeichnung = TRIM(@b);
/*
---------------------------------- Zusatzstoff ----------------------------------
*/
DROP TEMPORARY TABLE IF EXISTS tmp_import_0;
CREATE TABLE IF NOT EXISTS tmp_import_0
(
E_Nummer varchar(5),
Zusatzstoffbezeichnung varchar(100),
Anwendungsgrund varchar(5),
primary key (E_Nummer)
);
LOAD DATA LOCAL INFILE 'Programmentwurf/E_nummern.csv' INTO TABLE tmp_import_0
CHARACTER SET latin1
FIELDS terminated by ';'
LINES TERMINATED BY '\r\n'
(@e, @z, @k)
SET E_Nummer = TRIM(@e), Zusatzstoffbezeichnung = TRIM(@z), Anwendungsgrund = TRIM(@k);
INSERT INTO Zusatzstoff (SELECT E_Nummer, Zusatzstoffbezeichnung FROM tmp_import_0);
/* /*
---------------------------------- Produkt ---------------------------------- ---------------------------------- Produkt ----------------------------------
*/ */
@ -55,17 +76,6 @@ LOAD DATA LOCAL INFILE 'Programmentwurf/MD_produkte_Allergene.csv' INTO TABLE Al
SET Allergenbezeichnung = TRIM(@a); SET Allergenbezeichnung = TRIM(@a);
/*
---------------------------------- Zusatzstoffklasse ----------------------------------
*/
LOAD DATA LOCAL INFILE 'Programmentwurf/Zusatzstoffe_Klassen.csv' INTO TABLE Zusatzstoffklase
CHARACTER SET latin1
FIELDS terminated by ';'
LINES TERMINATED BY '\n'
(@b, @g)
SET Anwendungsgrund = REGEXP_REPLACE(@g, '[^a-zäöüßA-ZÄÖÜ]+', ''), Anwendungsgrundbezeichnung = TRIM(@b);
/* /*
---------------------------------- Produktallergen ---------------------------------- ---------------------------------- Produktallergen ----------------------------------
*/ */
@ -494,14 +504,58 @@ LIMIT 4;
/* /*
---------------------------------- enthält Zusatzstoff ---------------------------------- ---------------------------------- enthält Zusatzstoff ----------------------------------
*/ */
# TODO DROP TABLE IF EXISTS tmp_import_3;
CREATE TABLE IF NOT EXISTS tmp_import_3
(
Produkt_name VARCHAR(100),
E_Nummern VARCHAR(100)
);
LOAD DATA LOCAL INFILE 'Programmentwurf/MD_Produkte_Enummern.csv' REPLACE INTO TABLE tmp_import_3
CHARACTER SET latin1
FIELDS terminated by ';'
LINES TERMINATED BY '\n'
(@col1, @col2) SET Produkt_Name = trim(@col1), E_Nummern = trim(@col2);
/* DROP TABLE IF EXISTS tmp_import_4;
---------------------------------- Naehstoff ---------------------------------- CREATE TABLE IF NOT EXISTS tmp_import_4
*/ (
# TODO id int NOT NULL auto_increment,
E_Nummern VARCHAR(100),
PRIMARY KEY (id)
);
DROP TABLE IF EXISTS tmp_import_5;
CREATE TABLE IF NOT EXISTS tmp_import_5
(
Produkt_Name varchar(100),
E_nummern VARCHAR(100)
);
/* Delete all seperators and create new rows */
INSERT INTO tmp_import_5(Produkt_Name, E_Nummern)
SELECT Produkt_Name,
SUBSTRING_INDEX(SUBSTRING_INDEX(tmp_import_3.E_Nummern, ',', numbers.n), ',', -1)
FROM (SELECT 1 n
UNION ALL
SELECT 2
UNION ALL
SELECT 3
UNION ALL
SELECT 4) numbers
INNER JOIN tmp_import_3
ON CHAR_LENGTH(tmp_import_3.E_Nummern)
- CHAR_LENGTH(REPLACE(tmp_import_3.E_Nummern, ',', '')) >= numbers.n - 1;
UPDATE tmp_import_5
SET Produkt_name = (SELECT ProduktID FROM Produkt WHERE Produktname = Produkt_name);
INSERT INTO enthaeltZusatzstoff (SELECT Produkt_Name,
E_nummern,
(SELECT Anwendungsgrund FROM tmp_import_0 WHERE E_Nummer = E_nummern)
FROM tmp_import_5
WHERE Produkt_Name IN (SELECT ProduktID FROM Produkt)
AND E_nummern IN (SELECT E_Nummer FROM Zusatzstoff));
/* /*
---------------------------------- Naehrwerte ---------------------------------- ---------------------------------- Naehrwerte ----------------------------------
@ -515,9 +569,11 @@ LOAD DATA LOCAL INFILE 'Programmentwurf/MD_Produkte_Naehrwerte.csv' INTO TABLE N
SET ProduktID = (SELECT ProduktID SET ProduktID = (SELECT ProduktID
from Produkt from Produkt
WHERE Produktname = @produkt), Menge = (IF(@menge1 != '-', (REPLACE(@menge1, ' g', '')), WHERE Produktname = @produkt), Menge = (IF(@menge1 != '-', (REPLACE(@menge1, ' g', '')),
(REPLACE(@menge2, ' ml', '')))), Einheit = (IF(@menge1 != '-', 'g', 'ml')), Kohlenhydrate = @kh, Eiweiss = @ew, Fett = CAST(REPLACE(REPLACE(@fett, CHAR(13), ''), CHAR(10), '') (REPLACE(@menge2, ' ml', '')))), Einheit = (IF(@menge1 != '-', 'g', 'ml')), Kohlenhydrate = @kh, Eiweiss = @ew,
Fett = CAST(REPLACE(REPLACE(@fett, CHAR(13), ''), CHAR(10), '')
as double), Brennwert = @kcal; as double), Brennwert = @kcal;
# Issue at last for lines: ProduktID cannot be null, ... # Issue at last four lines: ProduktID cannot be null, ...
/* /*
---------------------------------- eigene Datensätze ---------------------------------- ---------------------------------- eigene Datensätze ----------------------------------
@ -527,6 +583,8 @@ INSERT INTO Person (Personenname, Personenvorname, Naehrwertziel, Ernaerungsstil
VALUES ('Kaiser', 'Florian', 5000, null); VALUES ('Kaiser', 'Florian', 5000, null);
INSERT INTO Person (Personenname, Personenvorname, Naehrwertziel, Ernaerungsstil) INSERT INTO Person (Personenname, Personenvorname, Naehrwertziel, Ernaerungsstil)
VALUES ('Amtmann', 'Leon', 10000, null); VALUES ('Amtmann', 'Leon', 10000, null);
INSERT INTO Person (Personenname, Personenvorname, Naehrwertziel, Ernaerungsstil)
VALUES ('Mustermann', 'Max', 15000, null);
/* /*
@ -535,6 +593,12 @@ VALUES ('Amtmann', 'Leon', 10000, null);
INSERT INTO Allergie (PersonID, AllergenID) INSERT INTO Allergie (PersonID, AllergenID)
VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Kaiser'), VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Kaiser'),
(SELECT AllergenID FROM Allergen WHERE Allergenbezeichnung = 'Glutenhaltiges Getreide')); (SELECT AllergenID FROM Allergen WHERE Allergenbezeichnung = 'Glutenhaltiges Getreide'));
INSERT INTO Allergie (PersonID, AllergenID)
VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Kaiser'),
(SELECT AllergenID FROM Allergen WHERE Allergenbezeichnung = 'Erdnuesse'));
INSERT INTO Allergie (PersonID, AllergenID)
VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Amtmann'),
(SELECT AllergenID FROM Allergen WHERE Allergenbezeichnung = 'Sesamsamen'));
/* /*
@ -542,14 +606,45 @@ VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Kaiser'),
*/ */
INSERT INTO Menu (Menuname) INSERT INTO Menu (Menuname)
VALUES ('Test Menu'); VALUES ('Test Menu');
INSERT INTO Menu (Menuname)
VALUES ('Test Menu #2');
INSERT INTO Menu (Menuname)
VALUES ('Test Menu #3');
/* /*
---------------------------------- Menucontent ---------------------------------- ---------------------------------- Menucontent ----------------------------------
*/ */
INSERT INTO Menucontent (MenuID, ProduktID) INSERT INTO Menucontent (MenuID, ProduktID)
VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu'), VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu'),
(SELECT ProduktID FROM Produkt WHERE Produktname = 'Butter'));
INSERT INTO Menucontent (MenuID, ProduktID)
VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu'),
(SELECT ProduktID FROM Produkt WHERE Produktname = 'Pommes Frites'));
INSERT INTO Menucontent (MenuID, ProduktID)
VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu'),
(SELECT ProduktID FROM Produkt WHERE Produktname = 'Curry Sauce'));
INSERT INTO Menucontent (MenuID, ProduktID)
VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu #2'),
(SELECT ProduktID FROM Produkt WHERE Produktname = 'Ketchup'));
INSERT INTO Menucontent (MenuID, ProduktID)
VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu #2'),
(SELECT ProduktID FROM Produkt WHERE Produktname = 'Big Mac'));
INSERT INTO Menucontent (MenuID, ProduktID)
VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu #2'),
(SELECT ProduktID FROM Produkt WHERE Produktname = 'Cheeseburger')); (SELECT ProduktID FROM Produkt WHERE Produktname = 'Cheeseburger'));
INSERT INTO Menucontent (MenuID, ProduktID)
VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu #3'),
(SELECT ProduktID FROM Produkt WHERE Produktname = 'Cheeseburger'));
INSERT INTO Menucontent (MenuID, ProduktID)
VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu #3'),
(SELECT ProduktID FROM Produkt WHERE Produktname = 'McSundae Karamell'));
INSERT INTO Menucontent (MenuID, ProduktID)
VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu #3'),
(SELECT ProduktID FROM Produkt WHERE Produktname = 'Big Mac'));
/* /*
---------------------------------- konsumiert ---------------------------------- ---------------------------------- konsumiert ----------------------------------
@ -557,6 +652,12 @@ VALUES ((SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu'),
INSERT INTO konsumiert (PersonID, MenuID, Datum) INSERT INTO konsumiert (PersonID, MenuID, Datum)
VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Kaiser'), VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Kaiser'),
(SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu'), now()); (SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu'), now());
INSERT INTO konsumiert (PersonID, MenuID, Datum)
VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Amtmann'),
(SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu #2'), now());
INSERT INTO konsumiert (PersonID, MenuID, Datum)
VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Kaiser'),
(SELECT MenuID FROM Menu WHERE Menuname = 'Test Menu #2'), now());
/* /*
@ -568,3 +669,17 @@ VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Kaiser'),
INSERT INTO Zusatzstoffunvertraeglichkeit (PersonID, E_Nummer) INSERT INTO Zusatzstoffunvertraeglichkeit (PersonID, E_Nummer)
VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Kaiser'), VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Kaiser'),
(SELECT E_Nummer FROM Zusatzstoff WHERE Zusatzstoffbezeichnung = 'Gold')); (SELECT E_Nummer FROM Zusatzstoff WHERE Zusatzstoffbezeichnung = 'Gold'));
INSERT INTO Zusatzstoffunvertraeglichkeit (PersonID, E_Nummer)
VALUES ((SELECT PersonID FROM Person WHERE Personenname = 'Amtmann'),
(SELECT E_Nummer FROM Zusatzstoff WHERE Zusatzstoffbezeichnung = 'Gold'));
/*
---------------------------------- Clean up ----------------------------------
*/
DROP TABLE IF EXISTS tmp_import_0;
DROP TABLE IF EXISTS tmp_import_1;
DROP TABLE IF EXISTS tmp_import_2;
DROP TABLE IF EXISTS tmp_import_3;
DROP TABLE IF EXISTS tmp_import_4;
DROP TABLE IF EXISTS tmp_import_5;