diff --git a/src/main/java/com/andrewlalis/perfin/data/impl/JdbcDataSourceFactory.java b/src/main/java/com/andrewlalis/perfin/data/impl/JdbcDataSourceFactory.java index bf18f06..e61e096 100644 --- a/src/main/java/com/andrewlalis/perfin/data/impl/JdbcDataSourceFactory.java +++ b/src/main/java/com/andrewlalis/perfin/data/impl/JdbcDataSourceFactory.java @@ -32,7 +32,7 @@ public class JdbcDataSourceFactory { * the profile has a newer schema version, we'll exit and prompt the user * to update their app. */ - public static final int SCHEMA_VERSION = 1; + public static final int SCHEMA_VERSION = 2; public DataSource getDataSource(String profileName) throws ProfileLoadException { final boolean dbExists = Files.exists(getDatabaseFile(profileName)); diff --git a/src/main/java/com/andrewlalis/perfin/data/impl/migration/Migrations.java b/src/main/java/com/andrewlalis/perfin/data/impl/migration/Migrations.java index 79a7d6c..bd8122d 100644 --- a/src/main/java/com/andrewlalis/perfin/data/impl/migration/Migrations.java +++ b/src/main/java/com/andrewlalis/perfin/data/impl/migration/Migrations.java @@ -4,10 +4,19 @@ import java.util.HashMap; import java.util.List; import java.util.Map; +/** + * Utility class for defining and using all known migrations. + */ public class Migrations { + /** + * Gets a list of migrations, as a map with the key being the version to + * migrate from. For example, a migration that takes us from version 42 to + * 43 would exist in the map with key 42. + * @return The map of all migrations. + */ public static Map getMigrations() { final Map migrations = new HashMap<>(); - migrations.put(1, new PlainSQLMigration("/sql/migration/M1_AddBalanceRecordDeleted.sql")); + migrations.put(1, new PlainSQLMigration("/sql/migration/M001_AddTransactionProperties.sql")); return migrations; } diff --git a/src/main/java/com/andrewlalis/perfin/data/util/FileUtil.java b/src/main/java/com/andrewlalis/perfin/data/util/FileUtil.java index 0edab5c..09bb389 100644 --- a/src/main/java/com/andrewlalis/perfin/data/util/FileUtil.java +++ b/src/main/java/com/andrewlalis/perfin/data/util/FileUtil.java @@ -1,5 +1,6 @@ package com.andrewlalis.perfin.data.util; +import com.andrewlalis.perfin.model.Profile; import javafx.stage.FileChooser; import org.slf4j.Logger; import org.slf4j.LoggerFactory; @@ -103,4 +104,14 @@ public class FileUtil { throw new RuntimeException(e); } } + + public static void copyResourceFile(String resource, Path dest) throws IOException { + try ( + var in = Profile.class.getResourceAsStream(resource); + var out = Files.newOutputStream(dest) + ) { + if (in == null) throw new IOException("Could not load resource " + resource); + in.transferTo(out); + } + } } diff --git a/src/main/java/com/andrewlalis/perfin/model/Profile.java b/src/main/java/com/andrewlalis/perfin/model/Profile.java index 7dc8ee9..8881b3d 100644 --- a/src/main/java/com/andrewlalis/perfin/model/Profile.java +++ b/src/main/java/com/andrewlalis/perfin/model/Profile.java @@ -17,6 +17,8 @@ import java.util.List; import java.util.Properties; import java.util.function.Consumer; +import static com.andrewlalis.perfin.data.util.FileUtil.copyResourceFile; + /** * A profile is essentially a complete set of data that the application can * operate on, sort of like a save file or user account. The profile contains @@ -153,16 +155,6 @@ public class Profile { copyResourceFile("/text/contentDirReadme.txt", getContentDir(name).resolve("README.txt")); } - private static void copyResourceFile(String resource, Path dest) throws IOException { - try ( - var in = Profile.class.getResourceAsStream(resource); - var out = Files.newOutputStream(dest) - ) { - if (in == null) throw new IOException("Could not load resource " + resource); - in.transferTo(out); - } - } - public static boolean validateName(String name) { return name != null && name.matches("\\w+") && diff --git a/src/main/resources/sql/migration/M001_AddTransactionProperties.sql b/src/main/resources/sql/migration/M001_AddTransactionProperties.sql new file mode 100644 index 0000000..da29d91 --- /dev/null +++ b/src/main/resources/sql/migration/M001_AddTransactionProperties.sql @@ -0,0 +1,73 @@ +/* +Migration to add additional properties to transactions as per this GitHub issue: +https://github.com/andrewlalis/perfin/issues/10 + +Adds the following: +- An optional "vendor" field and associated vendor entity. +- An optional "category" field and associated category entity. +- An optional set of "tags" that are user-defined strings. +- An optional set of "line items" that comprise some subtotal of the transaction + and can be used to specify that X amount of the total was spent on some + specific item. +- An optional address of the purchase. +*/ + +CREATE TABLE transaction_vendor ( + id BIGINT PRIMARY KEY AUTO_INCREMENT, + name VARCHAR(255) NOT NULL UNIQUE, + description VARCHAR(255) +); + +CREATE TABLE transaction_category ( + id BIGINT PRIMARY KEY AUTO_INCREMENT, + parent_id BIGINT DEFAULT NULL, + name VARCHAR(63) NOT NULL UNIQUE, + color VARCHAR(6) NOT NULL DEFAULT 'FFFFFF', + CONSTRAINT fk_transaction_category_parent + FOREIGN KEY (parent_id) REFERENCES transaction_category(id) + ON UPDATE CASCADE ON DELETE CASCADE +); + +CREATE TABLE transaction_tag ( + id BIGINT PRIMARY KEY AUTO_INCREMENT, + name VARCHAR(63) NOT NULL UNIQUE +); + +CREATE TABLE transaction_tag_join ( + transaction_id BIGINT NOT NULL, + tag_id BIGINT NOT NULL, + PRIMARY KEY (transaction_id, tag_id), + CONSTRAINT fk_transaction_tag_join_transaction + FOREIGN KEY (transaction_id) REFERENCES transaction(id) + ON UPDATE CASCADE ON DELETE CASCADE, + CONSTRAINT fk_transaction_tag_join_tag + FOREIGN KEY (tag_id) REFERENCES transaction_tag(id) + ON UPDATE CASCADE ON DELETE CASCADE +); + +CREATE TABLE transaction_line_item ( + id BIGINT PRIMARY KEY AUTO_INCREMENT, + transaction_id BIGINT NOT NULL, + value_per_item NUMERIC(12, 4) NOT NULL, + quantity INT NOT NULL DEFAULT 1, + description VARCHAR(255) NOT NULL, + CONSTRAINT fk_transaction_line_item_transaction + FOREIGN KEY (transaction_id) REFERENCES transaction(id) + ON UPDATE CASCADE ON DELETE CASCADE, + CONSTRAINT ck_transaction_line_item_quantity_positive + CHECK quantity > 0 +); + +ALTER TABLE transaction + ADD COLUMN vendor_id BIGINT DEFAULT NULL AFTER description; +ALTER TABLE transaction + ADD COLUMN category_id BIGINT DEFAULT NULL AFTER vendor_id; +ALTER TABLE transaction + ADD CONSTRAINT fk_transaction_vendor + FOREIGN KEY (vendor_id) REFERENCES transaction_vendor(id) + ON UPDATE CASCADE ON DELETE SET NULL; +ALTER TABLE transaction + ADD CONSTRAINT fk_transaction_category + FOREIGN KEY (category_id) REFERENCES transaction_category(id) + ON UPDATE CASCADE ON DELETE SET NULL; + diff --git a/src/main/resources/sql/schema.sql b/src/main/resources/sql/schema.sql index 71010d6..17ff5f9 100644 --- a/src/main/resources/sql/schema.sql +++ b/src/main/resources/sql/schema.sql @@ -8,14 +8,6 @@ CREATE TABLE account ( currency VARCHAR(3) NOT NULL ); -CREATE TABLE transaction ( - id BIGINT PRIMARY KEY AUTO_INCREMENT, - timestamp TIMESTAMP NOT NULL, - amount NUMERIC(12, 4) NOT NULL, - currency VARCHAR(3) NOT NULL, - description VARCHAR(255) NULL -); - CREATE TABLE attachment ( id BIGINT PRIMARY KEY AUTO_INCREMENT, uploaded_at TIMESTAMP NOT NULL, @@ -24,6 +16,45 @@ CREATE TABLE attachment ( content_type VARCHAR(255) NOT NULL ); +/* TRANSACTION ENTITIES */ + +CREATE TABLE transaction_vendor ( + id BIGINT PRIMARY KEY AUTO_INCREMENT, + name VARCHAR(255) NOT NULL UNIQUE, + description VARCHAR(255) +); + +CREATE TABLE transaction_category ( + id BIGINT PRIMARY KEY AUTO_INCREMENT, + parent_id BIGINT DEFAULT NULL, + name VARCHAR(63) NOT NULL UNIQUE, + color VARCHAR(6) NOT NULL DEFAULT 'FFFFFF', + CONSTRAINT fk_transaction_category_parent + FOREIGN KEY (parent_id) REFERENCES transaction_category(id) + ON UPDATE CASCADE ON DELETE CASCADE +); + +CREATE TABLE transaction_tag ( + id BIGINT PRIMARY KEY AUTO_INCREMENT, + name VARCHAR(63) NOT NULL UNIQUE +); + +CREATE TABLE transaction ( + id BIGINT PRIMARY KEY AUTO_INCREMENT, + timestamp TIMESTAMP NOT NULL, + amount NUMERIC(12, 4) NOT NULL, + currency VARCHAR(3) NOT NULL, + description VARCHAR(255) NULL, + vendor_id BIGINT DEFAULT NULL, + category_id BIGINT DEFAULT NULL, + CONSTRAINT fk_transaction_vendor + FOREIGN KEY (vendor_id) REFERENCES transaction_vendor(id) + ON UPDATE CASCADE ON DELETE SET NULL, + CONSTRAINT fk_transaction_category + FOREIGN KEY (category_id) REFERENCES transaction_category(id) + ON UPDATE CASCADE ON DELETE SET NULL +); + CREATE TABLE account_entry ( id BIGINT PRIMARY KEY AUTO_INCREMENT, timestamp TIMESTAMP NOT NULL, @@ -52,6 +83,34 @@ CREATE TABLE transaction_attachment ( ON UPDATE CASCADE ON DELETE CASCADE ); +CREATE TABLE transaction_tag_join ( + transaction_id BIGINT NOT NULL, + tag_id BIGINT NOT NULL, + PRIMARY KEY (transaction_id, tag_id), + CONSTRAINT fk_transaction_tag_join_transaction + FOREIGN KEY (transaction_id) REFERENCES transaction(id) + ON UPDATE CASCADE ON DELETE CASCADE, + CONSTRAINT fk_transaction_tag_join_tag + FOREIGN KEY (tag_id) REFERENCES transaction_tag(id) + ON UPDATE CASCADE ON DELETE CASCADE +); + +CREATE TABLE transaction_line_item ( + id BIGINT PRIMARY KEY AUTO_INCREMENT, + transaction_id BIGINT NOT NULL, + value_per_item NUMERIC(12, 4) NOT NULL, + quantity INT NOT NULL DEFAULT 1, + idx INT NOT NULL DEFAULT 0, + description VARCHAR(255) NOT NULL, + CONSTRAINT fk_transaction_line_item_transaction + FOREIGN KEY (transaction_id) REFERENCES transaction(id) + ON UPDATE CASCADE ON DELETE CASCADE, + CONSTRAINT ck_transaction_line_item_quantity_positive + CHECK quantity > 0 +); + +/* BALANCE RECORD ENTITIES */ + CREATE TABLE balance_record ( id BIGINT PRIMARY KEY AUTO_INCREMENT, timestamp TIMESTAMP NOT NULL,