diff --git a/.gitignore b/.gitignore index 151a90e..0dbaa06 100644 --- a/.gitignore +++ b/.gitignore @@ -28,6 +28,7 @@ krusty.sqlite3 *.sqlite3 *.db *.tar.gz +*.zip *.minisig *.jpg *.pdf diff --git a/README.md b/README.md index 5f1ac04..017c7d0 100644 --- a/README.md +++ b/README.md @@ -2,8 +2,26 @@ > Krusty Kookies is a bakery which specializes in cookies, and they need a database to keep track of their production and deliveries. +## Building and testing + +This project uses sqlite3 as a database. Migrations happens automatically on launch. +Migrations drop all tables and recreate them, so all data is lost on restart. +By default jdbc connects sqlite to an in-memory database, so all data is lost on restart anyway. + +```bash +./gradlew build +./gradlew test +``` + +The gradle environment is bumped to a recent version, and it is configured with kotlin and junit5. +The syntax for junit4 was ported to junit5. +**Most** of the pre-configured deps in the handout contained CVEs of varying severity, so they were updated to newer versions. +No tests were changed, some helper classes were implemented. + ## Base tables +**This description is no longer consistent with the current state of the project.** + Unsuprisingly, we will need a cookie table. ```sql diff --git a/app/Migrations/create-schema.sql b/app/Migrations/create-schema.sql index b0aee90..d5561ef 100644 --- a/app/Migrations/create-schema.sql +++ b/app/Migrations/create-schema.sql @@ -9,15 +9,9 @@ DROP TABLE IF EXISTS customers; DROP TABLE IF EXISTS cookies; -------------------------------------------- --- Recipe/Cookie related tables +-- Orders, deliveries and customers -------------------------------------------- --- Holds the different types of cookies we can make. -CREATE TABLE IF NOT EXISTS cookies ( - cookie_id INTEGER PRIMARY KEY, - cookie_name VARCHAR(50) NOT NULL UNIQUE -); - -- Our known customers, may need more fields CREATE TABLE IF NOT EXISTS customers ( customer_id INTEGER PRIMARY KEY, @@ -29,17 +23,35 @@ CREATE TABLE IF NOT EXISTS customers ( CREATE TABLE IF NOT EXISTS orders ( order_id INTEGER PRIMARY KEY, customer_id INT NOT NULL, - cookie_id INT NOT NULL, order_date DATE NOT NULL DEFAULT CURRENT_DATE CHECK (order_date >= CURRENT_DATE), - FOREIGN KEY (customer_id) REFERENCES customers(customer_id), - FOREIGN KEY (cookie_id) REFERENCES cookies(cookie_id) + expected_delivery_date DATE NOT NULL, + FOREIGN KEY (customer_id) REFERENCES customers(customer_id) +); + +CREATE TABLE IF NOT EXISTS order_spec ( + nbr_pallets INTEGER NOT NULL, + order_id INTEGER NOT NULL, + cookie_id INTEGER NOT NULL, + FOREIGN KEY (order_id) REFERENCES orders(order_id), + FOREIGN KEY (cookie_id) REFERENCES cookies(cookie_id), + PRIMARY KEY (order_id, cookie_id) ); -------------------------------------------- --- Recipe/Cookie related tables +-- Cookies, raw_materials and recipes -------------------------------------------- +-- Notes: the unit type can be defined in terms +-- of volume or weight instead. Here we choose +-- to use static si-prefixes in relevant tables. --- Describes ingredients and stock. +-- Holds the different types of cookies we can make. +CREATE TABLE IF NOT EXISTS cookies ( + cookie_id INTEGER PRIMARY KEY, + cookie_name VARCHAR(50) NOT NULL UNIQUE +); + +-- What types of raw_materials do we handle. +-- raw_materials quantity tells us amount in stock CREATE TABLE IF NOT EXISTS raw_materials ( ingredient_id INTEGER PRIMARY KEY, ingredient_name VARCHAR(50) NOT NULL UNIQUE, @@ -47,7 +59,19 @@ CREATE TABLE IF NOT EXISTS raw_materials ( unit VARCHAR(50) NOT NULL CHECK (unit IN ('g', 'ml')) ); --- When did we get the ingredients? +-- What raw_materials are in what cookies? +-- Glues together the cookies and raw_materials, a 'recipe'. +CREATE TABLE IF NOT EXISTS recipe_contents ( + cookie_id INT NOT NULL, + ingredient_id INT NOT NULL, + quantity INT NOT NULL, + unit VARCHAR(50) NOT NULL CHECK (unit IN ('g', 'ml')), + PRIMARY KEY (cookie_id, ingredient_id), + FOREIGN KEY (cookie_id) REFERENCES cookies(cookie_id), + FOREIGN KEY (ingredient_id) REFERENCES raw_materials(ingredient_id) +); + +-- When did we get the raw_materials? CREATE TABLE IF NOT EXISTS raw_materials_deliveries ( delivery_id INTEGER PRIMARY KEY, ingredient_id INT NOT NULL, @@ -66,12 +90,35 @@ CREATE TABLE IF NOT EXISTS raw_materials_deliveries ( CREATE TABLE IF NOT EXISTS pallets ( pallet_id INTEGER PRIMARY KEY, cookie_id INT NOT NULL, - -- order_id INT NOT NULL, status VARCHAR(50) NOT NULL CHECK (status IN ('freezer', 'delivered', 'blocked')), - production_date DATE NOT NULL, - delivery_date DATE DEFAULT NULL, + production_date DATE NOT NULL DEFAULT NOW, FOREIGN KEY (cookie_id) REFERENCES cookies(cookie_id) - -- FOREIGN KEY (order_id) REFERENCES orders(order_id) ); +-- Connects pallets to orders +CREATE TABLE IF NOT EXISTS deliveries ( + delivery_date DATE DEFAULT NOW, + order_id INT NOT NULL, + pallet_id INT NOT NULL, + FOREIGN KEY (order_id) REFERENCES orders(order_id), + FOREIGN KEY (pallet_id) REFERENCES pallets(pallet_id), + PRIMARY KEY (order_id, pallet_id) +); + +-------------------------------------------- +-- Views +-------------------------------------------- + +-- Pallet +CREATE VIEW IF NOT EXISTS pallets_view AS +SELECT + pallets.pallet_id, + cookie_name, + status, + production_date, + delivery_date +FROM pallets +LEFT JOIN cookies ON pallets.cookie_id = cookies.cookie_id +LEFT JOIN deliveries ON pallets.pallet_id = deliveries.pallet_id; + PRAGMA foreign_keys = ON; \ No newline at end of file diff --git a/app/src/main/java/krusty/Database.java b/app/src/main/java/krusty/Database.java index 8ccc97f..6f59bbf 100644 --- a/app/src/main/java/krusty/Database.java +++ b/app/src/main/java/krusty/Database.java @@ -69,53 +69,56 @@ public class Database { Optional from = Optional.empty(); // Holds the from date Optional to = Optional.empty(); // Holds the to date - // First we need the cookie parameter - String cookie = req.queryParams("cookie"); + // Parameter validation block + { + // First we need the cookie parameter + String cookie = req.queryParams("cookie"); - // And the blocked parameter - String blocked_str = req.queryParams("blocked"); + // And the blocked parameter + String blocked_str = req.queryParams("blocked"); - // Then we need the date parameters - String from_str = req.queryParams("from"); - String to_str = req.queryParams("to"); + // Then we need the date parameters + String from_str = req.queryParams("from"); + String to_str = req.queryParams("to"); - // Fancy functional one-liner to get the recipe if the cookie is present - if (cookie != null) { - r = Optional.ofNullable(DefaultRecipes.recipes.stream() - .filter(recipe -> recipe.name.equals(cookie)) - .findFirst().orElse(null)); - } - - if (blocked_str != null) { - blocked = switch (blocked_str) { - case "yes" -> Optional.of(true); - case "no" -> Optional.of(false); - default -> Optional.empty(); - }; - } - - if(from_str != null) { - try { - from = Optional.of(new SimpleDateFormat("yyyy-MM-dd").parse(from_str)); - } catch (Exception e) { - from = Optional.empty(); + // Fancy functional one-liner to get the recipe if the cookie is present + if (cookie != null) { + r = Optional.ofNullable(DefaultRecipes.recipes.stream() + .filter(recipe -> recipe.name.equals(cookie)) + .findFirst().orElse(null)); } - } - if(to_str != null) { - try { - to = Optional.of(new SimpleDateFormat("yyyy-MM-dd").parse(to_str)); - } catch (Exception e) { + if (blocked_str != null) { + blocked = switch (blocked_str) { + case "yes" -> Optional.of(true); + case "no" -> Optional.of(false); + default -> Optional.empty(); + }; + } + + if (from_str != null) { + try { + from = Optional.of(new SimpleDateFormat("yyyy-MM-dd").parse(from_str)); + } catch (Exception e) { + from = Optional.empty(); + } + } + + if (to_str != null) { + try { + to = Optional.of(new SimpleDateFormat("yyyy-MM-dd").parse(to_str)); + } catch (Exception e) { + to = Optional.empty(); + } + } + + // If the interval is negative, reset the dates + if (from.isPresent() && to.isPresent() && from.get().after(to.get())) { + from = Optional.empty(); to = Optional.empty(); } } - // If the interval is negative, reset the dates - if(from.isPresent() && to.isPresent() && from.get().after(to.get())) { - from = Optional.empty(); - to = Optional.empty(); - } - // This type of code is unreadable, error prone and hard to maintain. // The fact that im responsible for this code makes my soul hurt. // This part almost made me write a simple query factory to handle this. @@ -127,14 +130,13 @@ public class Database { try { Statement stmt = conn.createStatement(); StringBuilder query = new StringBuilder( - "SELECT cookie_name, status FROM pallets JOIN cookies ON pallets.cookie_id = cookies.cookie_id"); + "SELECT cookie_name, status FROM pallets_view"); // r is validated here if (r.isPresent()) { query.append(" WHERE cookie_name = '" + r.get().name + "'"); } - // If both from and to are present if (from.isPresent()) { String query_from = new SimpleDateFormat("yyyy-MM-dd").format(from.get()); @@ -144,7 +146,7 @@ public class Database { query.append(clause + "production_date >= '" + query_from + "'"); } - if(to.isPresent()) { + if (to.isPresent()) { String query_to = new SimpleDateFormat("yyyy-MM-dd").format(to.get()); // Super hacky, low quality code @@ -153,17 +155,7 @@ public class Database { query.append(clause + "production_date <= '" + query_to + "'"); } - // if (from.isPresent() && to.isPresent()) { - // String query_from = new SimpleDateFormat("yyyy-MM-dd").format(from.get()); - // String query_to = new SimpleDateFormat("yyyy-MM-dd").format(to.get()); - - // // Super hacky, low quality code - // String clause = query.toString().contains("WHERE") ? " AND " : " WHERE "; - - // query.append(clause + "production_date BETWEEN '" + query_from + "' AND '" + query_to + "'"); - // } - - if(blocked.isPresent()) { + if (blocked.isPresent()) { // This again String clause = query.toString().contains("WHERE") ? " AND " : " WHERE "; query.append(clause); @@ -173,8 +165,6 @@ public class Database { query.append("status = " + (blocked.get() ? "'blocked'" : "'freezer'")); } - query.append(";"); - System.out.println(query.toString()); ResultSet result = stmt.executeQuery(query.toString()); @@ -226,13 +216,10 @@ public class Database { } if (r.isEmpty()) { - // Return 404 res.status(404); return "{}"; } - // System.out.println(r.get()); - try (PreparedStatement getRawMaterials = conn .prepareStatement("SELECT * FROM raw_materials WHERE ingredient_name = ?"); PreparedStatement decrementRawMaterials = conn.prepareStatement( @@ -248,23 +235,21 @@ public class Database { getRawMaterials.setString(1, i.name); ResultSet result = getRawMaterials.executeQuery(); if (!result.next()) { - // Rollback transaction conn.rollback(); - // Return 500 res.status(500); return "{}"; } + int amount_per_pallet = i.amount * 54; // 54 * 100 + // Check if we have enough raw materials - if (result.getInt("ingredient_quantity") < i.amount) { - // Rollback transaction + if (result.getInt("ingredient_quantity") < amount_per_pallet) { conn.rollback(); - // Return 500 res.status(500); return "{}"; } - decrementRawMaterials.setInt(1, i.amount * 54); // 5400 / 100 + decrementRawMaterials.setInt(1, amount_per_pallet); decrementRawMaterials.setString(2, i.name); decrementRawMaterials.executeUpdate(); } @@ -273,9 +258,7 @@ public class Database { getCookieId.setString(1, cookie); ResultSet cookie_rs = getCookieId.executeQuery(); if (!cookie_rs.next()) { - // Rollback transaction conn.rollback(); - // Return 500 res.status(500); return "{}"; } @@ -286,21 +269,15 @@ public class Database { insertPallet.setString(2, new SimpleDateFormat("yyyy-MM-dd").format(new Date())); insertPallet.setString(3, "freezer"); + System.out.println(insertPallet.toString()); + insertPallet.executeUpdate(); conn.commit(); } catch (SQLException e) { System.out.printf("Error starting transaction: \n%s", e); } - // TODO: NOT DONE - - // 1. Get query param - // 2. Check if cookie exists (is in DefaultRecipes) - // 3. Start transaction - // 3. Check with db if raw materials are available -> decrement if so - // 4. Insert into pallets - // 5. Commit transaction - // 6. Return pallet id + res.status(201); return "{}"; } @@ -347,6 +324,7 @@ public class Database { // The script location is relative to the gradle // build script ("build.gradle.kts", in this case). + // Assumes every statement ends with a semicolon. (notably broken for triggers) /** Reads an sql script into the database */ public void migrateScript(String filename) throws IOException, SQLException { try (Stream lines = Files.lines(Paths.get(filename))) { diff --git a/makefile b/makefile index a6ea063..1459c69 100644 --- a/makefile +++ b/makefile @@ -8,7 +8,7 @@ run: clean: ./gradlew clean - rm -f *.tar.gz *.tar.gz.minisig + rm -f *.tar.gz *.tar.gz.minisig *.zip *.jpg rm -f app/krusty.db test: @@ -28,8 +28,12 @@ release: scp krusty-imbus_$(GITHASH).tar.gz server:/public/krusty/krusty-imbus_$(GITHASH).tar.gz scp krusty-imbus_$(GITHASH).tar.gz.minisig server:/public/krusty/krusty-imbus_$(GITHASH).tar.gz.minisig +zip: + git archive --format=zip --prefix Rest11/ --output=Rest11.zip HEAD + 7za a -tzip CourseProject11.zip ./app/Migrations/*.sql + # Generate ERD. Requires eralchemy2 (pip install eralchemy2) -erd: +erd: migrate eralchemy2 -i sqlite:///app/krusty.db -o erd.jpg .PHONY: run clean test build dbdump migrate release erd