-- DROP TABLE IF EXISTS `lcc`.`calculation_job`, `lcc`.`calculation_job_destination`, `lcc`.`calculation_job_route_section`, `lcc`.`container_rate`, `lcc`.`country`, `lcc`.`country_matrix_rate`, `lcc`.`country_property`, `lcc`.`country_property_type`, `lcc`.`distance_matrix`, `lcc`.`material`, `lcc`.`node`, `lcc`.`node_predecessor_chain`, `lcc`.`node_predecessor_entry`, `lcc`.`outbound_country_mapping`, `lcc`.`packaging`, `lcc`.`packaging_dimension`, `lcc`.`packaging_property`, `lcc`.`packaging_property_type`, `lcc`.`premise`, `lcc`.`premise_destination`, `lcc`.`premise_route`, `lcc`.`premise_route_node`, `lcc`.`premise_route_section`, `lcc`.`property_set`, `lcc`.`sys_group`, `lcc`.`sys_user`, `lcc`.`sys_user_group_mapping`, `lcc`.`sys_user_node`, `lcc`.`system_property`, `lcc`.`system_property_type`, `lcc`.`validity_period`; -- Property management tables CREATE TABLE IF NOT EXISTS `property_set` ( -- Represents a collection of properties valid for a specific time period `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `start_date` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, `end_date` TIMESTAMP NULL, `state` CHAR(8) NOT NULL, CONSTRAINT `chk_property_state_values` CHECK (`state` IN ('DRAFT', 'VALID', 'INVALID', 'EXPIRED')), CONSTRAINT `chk_property_date_range` CHECK (`end_date` IS NULL OR `end_date` > `start_date`), INDEX `idx_dates` (`start_date`, `end_date`), INDEX `idx_property_set_id` (id) ) COMMENT 'Manages versioned sets of properties with temporal validity'; CREATE TABLE IF NOT EXISTS `system_property_type` ( -- Stores system-wide configuration property types `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(255) NOT NULL, `external_mapping_id` VARCHAR(16), `description` VARCHAR(512) NOT NULL, `property_group` VARCHAR(32) NOT NULL, `sequence_number` INT NOT NULL, `data_type` VARCHAR(16) NOT NULL, `validation_rule` VARCHAR(64), UNIQUE KEY `idx_external_mapping` (`external_mapping_id`), CONSTRAINT `chk_system_data_type_values` CHECK (`data_type` IN ('INT', 'PERCENTAGE', 'BOOLEAN', 'CURRENCY', 'ENUMERATION', 'TEXT')) ) COMMENT 'Stores system-wide configuration property types'; CREATE TABLE IF NOT EXISTS `system_property` ( -- Stores system-wide configuration properties `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `property_set_id` INT NOT NULL, `system_property_type_id` INT NOT NULL, `property_value` VARCHAR(500), FOREIGN KEY (`property_set_id`) REFERENCES `property_set` (`id`), FOREIGN KEY (`system_property_type_id`) REFERENCES `system_property_type` (`id`), INDEX `idx_system_property_type_id` (system_property_type_id), INDEX `idx_property_set_id` (id), UNIQUE KEY `idx_system_property_type_id_property_set` (`system_property_type_id`, `property_set_id`) ) COMMENT 'Stores system-wide configuration properties'; -- country CREATE TABLE IF NOT EXISTS `country` ( `id` INT NOT NULL AUTO_INCREMENT, `iso_code` CHAR(2) NOT NULL COMMENT 'ISO 3166-1 alpha-2 country code', `region_code` CHAR(5) NOT NULL COMMENT 'Geographic region code (EMEA/LATAM/APAC/NAM)', `name` VARCHAR(255) NOT NULL, `is_deprecated` BOOLEAN NOT NULL DEFAULT FALSE, PRIMARY KEY (`id`), UNIQUE KEY `uk_country_iso_code` (`iso_code`), CONSTRAINT `chk_country_region_code` CHECK (`region_code` IN ('EMEA', 'LATAM', 'APAC', 'NAM')) ) COMMENT 'Master data table for country information and regional classification'; CREATE TABLE IF NOT EXISTS `country_property_type` ( `id` INT NOT NULL AUTO_INCREMENT, `name` VARCHAR(255) NOT NULL, `external_mapping_id` VARCHAR(16), `data_type` VARCHAR(16) NOT NULL, `validation_rule` VARCHAR(64), `description` VARCHAR(512) NOT NULL, `property_group` VARCHAR(32) NOT NULL, `sequence_number` INT NOT NULL, `is_required` BOOLEAN NOT NULL DEFAULT FALSE, CONSTRAINT `chk_country_data_type_values` CHECK (`data_type` IN ('INT', 'PERCENTAGE', 'BOOLEAN', 'CURRENCY', 'ENUMERATION', 'TEXT')), PRIMARY KEY (`id`), INDEX `idx_property_type_data_type` (`data_type`) ) COMMENT 'Defines available property types for country-specific configurations'; CREATE TABLE IF NOT EXISTS `country_property` ( `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `country_id` INT NOT NULL, `country_property_type_id` INT NOT NULL, `property_set_id` INT NOT NULL, `property_value` VARCHAR(500), FOREIGN KEY (`country_id`) REFERENCES `country` (`id`), FOREIGN KEY (`country_property_type_id`) REFERENCES `country_property_type` (`id`), FOREIGN KEY (`property_set_id`) REFERENCES `property_set` (`id`), UNIQUE KEY `idx_country_property` (`country_id`, `country_property_type_id`, `property_set_id`) ) COMMENT 'Stores country-specific property values with versioning support'; -- Main table for user information CREATE TABLE IF NOT EXISTS `sys_user` ( `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `workday_id` CHAR(32) NOT NULL, `email` VARCHAR(254) NOT NULL, `firstname` VARCHAR(100) NOT NULL, `lastname` VARCHAR(100) NOT NULL, `is_active` BOOLEAN NOT NULL DEFAULT TRUE, UNIQUE KEY `idx_user_email` (`email`), UNIQUE KEY `idx_user_workday` (`workday_id`) ) COMMENT 'Stores basic information about system users'; -- Group definitions CREATE TABLE IF NOT EXISTS `sys_group` ( `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `group_name` VARCHAR(64) NOT NULL, `group_description` VARCHAR(128) NOT NULL, UNIQUE KEY `idx_group_name` (`group_name`) ) COMMENT 'Defines user groups for access management'; -- Junction table for user-group assignments CREATE TABLE IF NOT EXISTS `sys_user_group_mapping` ( `user_id` INT NOT NULL, `group_id` INT NOT NULL, PRIMARY KEY (`user_id`, `group_id`), FOREIGN KEY (`user_id`) REFERENCES `sys_user` (`id`), FOREIGN KEY (`group_id`) REFERENCES `sys_group` (`id`) ) COMMENT 'Links users with their associated groups'; CREATE TABLE IF NOT EXISTS `sys_user_node` ( `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `user_id` INT NOT NULL, `country_id` INT NOT NULL, `name` VARCHAR(254) NOT NULL, `address` VARCHAR(500) NOT NULL, `geo_lat` DECIMAL(8, 4) CHECK (geo_lat BETWEEN -90 AND 90), `geo_lng` DECIMAL(8, 4) CHECK (geo_lng BETWEEN -180 AND 180), `is_deprecated` BOOLEAN DEFAULT FALSE, FOREIGN KEY (`user_id`) REFERENCES `sys_user` (`id`), FOREIGN KEY (`country_id`) REFERENCES `country` (`id`) ) COMMENT 'Contains user generated logistic nodes'; -- Main table for user information CREATE TABLE IF NOT EXISTS `sys_app` ( `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, client_id VARCHAR(255) NOT NULL UNIQUE, client_secret VARCHAR(255) NOT NULL, -- BCrypt gehashed name VARCHAR(255) NOT NULL ) COMMENT 'Stores basic information about external applications'; -- Junction table for user-group assignments CREATE TABLE IF NOT EXISTS `sys_app_group_mapping` ( `app_id` INT NOT NULL, `group_id` INT NOT NULL, PRIMARY KEY (`app_id`, `group_id`), FOREIGN KEY (`app_id`) REFERENCES `sys_app` (`id`), FOREIGN KEY (`group_id`) REFERENCES `sys_group` (`id`) ) COMMENT 'Links app with their associated groups'; -- logistic nodes CREATE TABLE IF NOT EXISTS node ( id INT AUTO_INCREMENT PRIMARY KEY, country_id INT NOT NULL, name VARCHAR(255) NOT NULL, address VARCHAR(500) NOT NULL, external_mapping_id VARCHAR(32), predecessor_required BOOLEAN NOT NULL DEFAULT FALSE, is_destination BOOLEAN NOT NULL, is_source BOOLEAN NOT NULL, is_intermediate BOOLEAN NOT NULL, geo_lat DECIMAL(8, 4) CHECK (geo_lat BETWEEN -90 AND 90), geo_lng DECIMAL(8, 4) CHECK (geo_lng BETWEEN -180 AND 180), updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, is_deprecated BOOLEAN NOT NULL DEFAULT FALSE, FOREIGN KEY (country_id) REFERENCES country (id), INDEX idx_country_id (country_id) ) COMMENT ''; CREATE TABLE IF NOT EXISTS node_predecessor_chain ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, node_id INT NOT NULL, FOREIGN KEY (node_id) REFERENCES node (id) ); CREATE TABLE IF NOT EXISTS node_predecessor_entry ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, node_id INT NOT NULL, node_predecessor_chain_id INT NOT NULL, sequence_number INT NOT NULL CHECK (sequence_number > 0), FOREIGN KEY (node_id) REFERENCES node (id), FOREIGN KEY (node_predecessor_chain_id) REFERENCES node_predecessor_chain (id), UNIQUE KEY uk_node_predecessor (node_predecessor_chain_id, sequence_number), INDEX idx_node_predecessor (node_predecessor_chain_id), INDEX idx_sequence (sequence_number) ); CREATE TABLE IF NOT EXISTS outbound_country_mapping ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, node_id INT NOT NULL, country_id INT NOT NULL, FOREIGN KEY (node_id) REFERENCES node (id), FOREIGN KEY (country_id) REFERENCES country (id), UNIQUE KEY uk_node_id_country_id (node_id, country_id), INDEX idx_node_id (node_id), INDEX idx_country_id (country_id) ); CREATE TABLE IF NOT EXISTS distance_matrix ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, from_node_id INT DEFAULT NULL, to_node_id INT DEFAULT NULL, from_user_node_id INT DEFAULT NULL, to_user_node_id INT DEFAULT NULL, from_geo_lat DECIMAL(8, 4) CHECK (from_geo_lat BETWEEN -90 AND 90), from_geo_lng DECIMAL(8, 4) CHECK (from_geo_lng BETWEEN -180 AND 180), to_geo_lat DECIMAL(8, 4) CHECK (to_geo_lat BETWEEN -90 AND 90), to_geo_lng DECIMAL(8, 4) CHECK (to_geo_lng BETWEEN -180 AND 180), distance DECIMAL(15, 2) NOT NULL COMMENT 'travel distance between the two nodes in meters', updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, state CHAR(10) NOT NULL, FOREIGN KEY (from_node_id) REFERENCES node (id), FOREIGN KEY (to_node_id) REFERENCES node (id), FOREIGN KEY (from_user_node_id) REFERENCES sys_user_node (id), FOREIGN KEY (to_user_node_id) REFERENCES sys_user_node (id), CONSTRAINT `chk_distance_matrix_state` CHECK (`state` IN ('VALID', 'STALE')), CONSTRAINT `chk_from_node_xor` CHECK ( (from_node_id IS NOT NULL AND from_user_node_id IS NULL) OR (from_node_id IS NULL AND from_user_node_id IS NOT NULL) ), CONSTRAINT `chk_to_node_xor` CHECK ( (to_node_id IS NOT NULL AND to_user_node_id IS NULL) OR (to_node_id IS NULL AND to_user_node_id IS NOT NULL) ), INDEX idx_from_to_nodes (from_node_id, to_node_id), INDEX idx_user_from_to_nodes (from_user_node_id, to_user_node_id), CONSTRAINT uk_nodes_unique UNIQUE (from_node_id, to_node_id, from_user_node_id, to_user_node_id) ); -- container rates CREATE TABLE IF NOT EXISTS validity_period ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, start_date TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, end_date TIMESTAMP DEFAULT NULL, renewals INT UNSIGNED DEFAULT 0, state CHAR(8) NOT NULL CHECK (state IN ('DRAFT', 'VALID', 'INVALID', 'EXPIRED')), CONSTRAINT `chk_validity_date_range` CHECK (`end_date` IS NULL OR `end_date` > `start_date`) ); CREATE TABLE IF NOT EXISTS container_rate ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, from_node_id INT NOT NULL, to_node_id INT NOT NULL, container_rate_type CHAR(8) CHECK (container_rate_type IN ('RAIL', 'SEA', 'POST_RUN', 'ROAD')), rate_teu DECIMAL(15, 2) NOT NULL COMMENT 'rate for 20ft container in EUR', rate_feu DECIMAL(15, 2) NOT NULL COMMENT 'rate for 40ft container in EUR', rate_hc DECIMAL(15, 2) NOT NULL COMMENT 'rate for 40ft HQ container in EUR', lead_time INT UNSIGNED NOT NULL COMMENT 'lead time in days', validity_period_id INT NOT NULL, FOREIGN KEY (from_node_id) REFERENCES node (id), FOREIGN KEY (to_node_id) REFERENCES node (id), FOREIGN KEY (validity_period_id) REFERENCES validity_period (id), INDEX idx_from_to_nodes (from_node_id, to_node_id), INDEX idx_validity_period_id (validity_period_id), CONSTRAINT uk_container_rate_unique UNIQUE (from_node_id, to_node_id, validity_period_id, container_rate_type) ); CREATE TABLE IF NOT EXISTS country_matrix_rate ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, from_country_id INT NOT NULL, to_country_id INT NOT NULL, rate DECIMAL(15, 2) NOT NULL COMMENT 'rate for full truck load per kilometer in EUR', validity_period_id INT NOT NULL, FOREIGN KEY (from_country_id) REFERENCES country (id), FOREIGN KEY (to_country_id) REFERENCES country (id), FOREIGN KEY (validity_period_id) REFERENCES validity_period (id), INDEX idx_from_to_country (from_country_id, to_country_id), INDEX idx_validity_period_id (validity_period_id), CONSTRAINT uk_country_matrix_rate_unique UNIQUE (from_country_id, to_country_id, validity_period_id) ); -- packaging and material CREATE TABLE IF NOT EXISTS material ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, part_number CHAR(12) NOT NULL, normalized_part_number CHAR(12) NOT NULL, hs_code CHAR(11), name VARCHAR(500) NOT NULL, is_deprecated BOOLEAN NOT NULL DEFAULT FALSE, CONSTRAINT `uq_normalized_part_number` UNIQUE (`normalized_part_number`) ); CREATE TABLE IF NOT EXISTS packaging_dimension ( `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `type` CHAR(3) DEFAULT 'HU', `length` INT UNSIGNED NOT NULL COMMENT 'length stored in mm', `width` INT UNSIGNED NOT NULL COMMENT 'width stored in mm', `height` INT UNSIGNED NOT NULL COMMENT 'height stored in mm', `displayed_dimension_unit` CHAR(2) DEFAULT 'CM', `weight` INT UNSIGNED NOT NULL COMMENT 'weight stored in g', `displayed_weight_unit` CHAR(2) DEFAULT 'KG', `content_unit_count` INT UNSIGNED NOT NULL COMMENT 'how many units are contained in packaging (if there is a child packaging this references to the child packaging, otherwise this references a single unit)', `is_deprecated` BOOLEAN NOT NULL DEFAULT FALSE, CONSTRAINT `chk_packaging_dimension_type_values` CHECK (`type` IN ('SHU', 'HU')), CONSTRAINT `chk_packaging_dimension_displayed_dimension_unit` CHECK (`displayed_dimension_unit` IN ('MM', 'CM', 'M')), CONSTRAINT `chk_packaging_dimension_displayed_weight_unit` CHECK (`displayed_weight_unit` IN ('T', 'G', 'KG')) ); CREATE TABLE IF NOT EXISTS packaging ( `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `supplier_node_id` INT NOT NULL, `material_id` INT NOT NULL, `hu_dimension_id` INT NOT NULL, `shu_dimension_id` INT NOT NULL, `is_deprecated` BOOLEAN NOT NULL DEFAULT FALSE, FOREIGN KEY (supplier_node_id) REFERENCES node (id), FOREIGN KEY (material_id) REFERENCES material (id), FOREIGN KEY (hu_dimension_id) REFERENCES packaging_dimension (id), FOREIGN KEY (shu_dimension_id) REFERENCES packaging_dimension (id), INDEX idx_material_id (material_id), INDEX idx_hu_dimension_id (hu_dimension_id), INDEX idx_shu_dimension_id (shu_dimension_id) ); CREATE TABLE IF NOT EXISTS packaging_property_type ( `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(255) NOT NULL, external_mapping_id VARCHAR(16) NOT NULL, `description` VARCHAR(255) NOT NULL, `property_group` VARCHAR(32) NOT NULL, `sequence_number` INT NOT NULL, `data_type` VARCHAR(16), `validation_rule` VARCHAR(64), `is_required` BOOLEAN NOT NULL DEFAULT FALSE, UNIQUE KEY idx_packaging_property_type (`external_mapping_id`), CONSTRAINT `chk_packaging_data_type_values` CHECK (`data_type` IN ('INT', 'PERCENTAGE', 'BOOLEAN', 'CURRENCY', 'ENUMERATION', 'TEXT')) ); CREATE TABLE IF NOT EXISTS packaging_property ( `id` INT NOT NULL AUTO_INCREMENT PRIMARY KEY, `packaging_property_type_id` INT NOT NULL, `packaging_id` INT NOT NULL, `property_value` VARCHAR(500), FOREIGN KEY (packaging_property_type_id) REFERENCES packaging_property_type (id), FOREIGN KEY (packaging_id) REFERENCES packaging (id), INDEX idx_packaging_property_type_id (packaging_property_type_id), INDEX idx_packaging_id (packaging_id), UNIQUE KEY idx_packaging_property_unique (packaging_property_type_id, packaging_id) ); CREATE TABLE IF NOT EXISTS premise ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, material_id INT NOT NULL, supplier_node_id INT, user_supplier_node_id INT, geo_lat DECIMAL(8, 4) CHECK (geo_lat BETWEEN -90 AND 90), geo_lng DECIMAL(8, 4) CHECK (geo_lng BETWEEN -180 AND 180), country_id INT NOT NULL, packaging_id INT DEFAULT NULL, user_id INT NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, material_cost DECIMAL(15, 2) DEFAULT NULL COMMENT 'aka MEK_A in EUR', is_fca_enabled BOOLEAN DEFAULT FALSE, oversea_share DECIMAL(8, 4) DEFAULT NULL, hs_code CHAR(11) DEFAULT NULL, tariff_measure INT UNSIGNED DEFAULT NULL COMMENT 'measure code of the selected tariff', tariff_rate DECIMAL(8, 4) DEFAULT NULL, tariff_unlocked BOOLEAN DEFAULT FALSE, state CHAR(10) NOT NULL DEFAULT 'DRAFT', individual_hu_length INT UNSIGNED COMMENT 'user entered dimensions in mm (if system-wide packaging is used, packaging dimensions are copied here after creation)', individual_hu_height INT UNSIGNED COMMENT 'user entered dimensions in mm (if system-wide packaging is used, packaging dimensions are copied here after creation)', individual_hu_width INT UNSIGNED COMMENT 'user entered dimensions in mm (if system-wide packaging is used, packaging dimensions are copied here after creation)', individual_hu_weight INT UNSIGNED COMMENT 'user entered weight in g (if system-wide packaging is used, packaging weight are copied here after creation)', hu_displayed_dimension_unit CHAR(2) DEFAULT 'MM', hu_displayed_weight_unit CHAR(2) DEFAULT 'KG', hu_unit_count INT UNSIGNED DEFAULT NULL, hu_stackable BOOLEAN DEFAULT TRUE, hu_mixable BOOLEAN DEFAULT TRUE, FOREIGN KEY (material_id) REFERENCES material (id), FOREIGN KEY (supplier_node_id) REFERENCES node (id), FOREIGN KEY (user_supplier_node_id) REFERENCES sys_user_node (id), FOREIGN KEY (packaging_id) REFERENCES packaging (id), FOREIGN KEY (user_id) REFERENCES sys_user (id), CONSTRAINT `chk_premise_state_values` CHECK (`state` IN ('DRAFT', 'COMPLETED', 'ARCHIVED')), CONSTRAINT `chk_premise_displayed_dimension_unit` CHECK (`hu_displayed_dimension_unit` IN ('MM', 'CM', 'M')), CONSTRAINT `chk_premise_displayed_weight_unit` CHECK (`hu_displayed_weight_unit` IN ('T', 'G', 'KG')), INDEX idx_material_id (material_id), INDEX idx_supplier_node_id (supplier_node_id), INDEX idx_packaging_id (packaging_id), INDEX idx_user_id (user_id), INDEX idx_user_supplier_node_id (user_supplier_node_id) ); CREATE TABLE IF NOT EXISTS premise_destination ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, premise_id INT NOT NULL, annual_amount INT UNSIGNED COMMENT 'annual amount in single pieces', destination_node_id INT NOT NULL, is_d2d BOOLEAN DEFAULT FALSE, rate_d2d DECIMAL(15, 2) DEFAULT NULL CHECK (rate_d2d >= 0), lead_time_d2d INT UNSIGNED DEFAULT NULL CHECK (lead_time_d2d >= 0), repacking_cost DECIMAL(15, 2) DEFAULT NULL CHECK (repacking_cost >= 0), handling_cost DECIMAL(15, 2) DEFAULT NULL CHECK (handling_cost >= 0), disposal_cost DECIMAL(15, 2) DEFAULT NULL CHECK (disposal_cost >= 0), geo_lat DECIMAL(8, 4) CHECK (geo_lat BETWEEN -90 AND 90), geo_lng DECIMAL(8, 4) CHECK (geo_lng BETWEEN -180 AND 180), country_id INT NOT NULL, FOREIGN KEY (premise_id) REFERENCES premise (id), FOREIGN KEY (country_id) REFERENCES country (id), FOREIGN KEY (destination_node_id) REFERENCES node (id), INDEX idx_destination_node_id (destination_node_id), INDEX idx_premise_id (premise_id) ); CREATE TABLE IF NOT EXISTS premise_route_node ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, node_id INT DEFAULT NULL, user_node_id INT DEFAULT NULL, name VARCHAR(255) NOT NULL, address VARCHAR(500), external_mapping_id VARCHAR(32) NOT NULL, country_id INT NOT NULL, is_destination BOOLEAN DEFAULT FALSE, is_intermediate BOOLEAN DEFAULT FALSE, is_source BOOLEAN DEFAULT FALSE, geo_lat DECIMAL(8, 4) CHECK (geo_lat BETWEEN -90 AND 90), geo_lng DECIMAL(8, 4) CHECK (geo_lng BETWEEN -180 AND 180), is_outdated BOOLEAN DEFAULT FALSE, FOREIGN KEY (node_id) REFERENCES node (id), FOREIGN KEY (country_id) REFERENCES country (id), FOREIGN KEY (user_node_id) REFERENCES sys_user_node (id), INDEX idx_node_id (node_id), INDEX idx_user_node_id (user_node_id), CONSTRAINT `chk_node` CHECK (`user_node_id` IS NULL OR `node_id` IS NULL) ); CREATE TABLE IF NOT EXISTS premise_route ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, premise_destination_id INT NOT NULL, is_fastest BOOLEAN DEFAULT FALSE, is_cheapest BOOLEAN DEFAULT FALSE, is_selected BOOLEAN DEFAULT FALSE, FOREIGN KEY (premise_destination_id) REFERENCES premise_destination (id) ); CREATE TABLE IF NOT EXISTS premise_route_section ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, premise_route_id INT NOT NULL, from_route_node_id INT NOT NULL, to_route_node_id INT NOT NULL, list_position INT NOT NULL, transport_type CHAR(16) CHECK (transport_type IN ('RAIL', 'SEA', 'ROAD', 'POST_RUN')), rate_type CHAR(16) CHECK (rate_type IN ('CONTAINER', 'MATRIX', 'NEAR_BY')), is_pre_run BOOLEAN DEFAULT FALSE, is_main_run BOOLEAN DEFAULT FALSE, is_post_run BOOLEAN DEFAULT FALSE, is_outdated BOOLEAN DEFAULT FALSE, CONSTRAINT fk_premise_route_section_premise_route_id FOREIGN KEY (premise_route_id) REFERENCES premise_route (id), FOREIGN KEY (from_route_node_id) REFERENCES premise_route_node (id), FOREIGN KEY (to_route_node_id) REFERENCES premise_route_node (id), CONSTRAINT chk_main_run CHECK (transport_type = 'ROAD' OR transport_type = 'POST_RUN' OR is_main_run IS TRUE), INDEX idx_premise_route_id (premise_route_id), INDEX idx_from_route_node_id (from_route_node_id), INDEX idx_to_route_node_id (to_route_node_id) ); CREATE TABLE IF NOT EXISTS calculation_job ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, premise_id INT NOT NULL, calculation_date TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, validity_period_id INT NOT NULL, property_set_id INT NOT NULL, job_state CHAR(10) NOT NULL CHECK (job_state IN ('CREATED', 'SCHEDULED', 'VALID', 'INVALID', 'EXCEPTION')), error_id INT DEFAULT NULL, user_id INT NOT NULL, FOREIGN KEY (premise_id) REFERENCES premise (id), FOREIGN KEY (validity_period_id) REFERENCES validity_period (id), FOREIGN KEY (property_set_id) REFERENCES property_set (id), FOREIGN KEY (user_id) REFERENCES sys_user (id), INDEX idx_premise_id (premise_id), INDEX idx_validity_period_id (validity_period_id), INDEX idx_property_set_id (property_set_id) ); CREATE TABLE IF NOT EXISTS calculation_job_destination ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, calculation_job_id INT NOT NULL, premise_destination_id INT NOT NULL, shipping_frequency INT UNSIGNED COMMENT 'annual shipping frequency', total_cost DECIMAL(15, 2) COMMENT 'aka MEK_B in EUR (excl. Airfreight)', annual_amount DECIMAL(15, 2) COMMENT 'annual quantity for this destinations in pieces', -- risk annual_risk_cost DECIMAL(15, 2) NOT NULL COMMENT 'complete calculation with globally stored worst case container rates (excl. Airfreight)', annual_chance_cost DECIMAL(15, 2) NOT NULL COMMENT 'complete calculation with globally stored best case container rates (excl. Airfreight)', -- handling is_small_unit BOOLEAN DEFAULT FALSE COMMENT 'small unit equals KLT, volume of a handling unit is smaller than 0.08 cbm ', annual_repacking_cost DECIMAL(15, 2) NOT NULL, annual_handling_cost DECIMAL(15, 2) NOT NULL, annual_disposal_cost DECIMAL(15, 2) NOT NULL, -- inventory operational_stock DECIMAL(15, 2) NOT NULL COMMENT 'operational stock in single pieces', safety_stock DECIMAL(15, 2) NOT NULL COMMENT 'safety stock in single pieces', stocked_inventory DECIMAL(15, 2) NOT NULL COMMENT 'sum of operational and safety stock', in_transport_stock DECIMAL(15, 2) NOT NULL, stock_before_payment DECIMAL(15, 2) NOT NULL, annual_capital_cost DECIMAL(15, 2) NOT NULL, annual_storage_cost DECIMAL(15, 2) NOT NULL, -- Flächenkosten -- custom custom_value DECIMAL(15, 2) NOT NULL,-- Zollwert, custom_duties DECIMAL(15, 2) NOT NULL,-- Zollabgaben, tariff_rate DECIMAL(8, 4) NOT NULL,-- Zollsatz, annual_custom_cost DECIMAL(15, 2) NOT NULL,-- Zollabgaben inkl. Einmalkosten, -- air freight risk air_freight_share_max DECIMAL(8, 4) NOT NULL, air_freight_share DECIMAL(8, 4) NOT NULL, air_freight_volumetric_weight DECIMAL(15, 2) NOT NULL, air_freight_weight DECIMAL(15, 2) NOT NULL, annual_air_freight_cost DECIMAL(15, 2) NOT NULL, -- transportation is_d2d BOOLEAN DEFAULT FALSE, rate_d2d DECIMAL(15, 2) DEFAULT NULL, container_type CHAR(8), hu_count INT UNSIGNED NOT NULL COMMENT 'number of handling units in total (full container, with layers)', layer_structure JSON COMMENT 'json representation of a single layer', layer_count INT UNSIGNED NOT NULL COMMENT 'number of layers per full container or truck', transport_weight_exceeded BOOLEAN DEFAULT FALSE COMMENT 'limiting factor: TRUE if weight limited or FALSE if volume limited', annual_transportation_cost DECIMAL(15, 2) NOT NULL COMMENT 'total annual transportation costs in EUR', container_utilization DECIMAL(8, 4) NOT NULL, transit_time_in_days INT UNSIGNED NOT NULL, safety_stock_in_days INT UNSIGNED NOT NULL, -- material cost material_cost DECIMAL(15, 2) NOT NULL, fca_cost DECIMAL(15, 2) NOT NULL, FOREIGN KEY (calculation_job_id) REFERENCES calculation_job (id), FOREIGN KEY (premise_destination_id) REFERENCES premise_destination (id), INDEX idx_calculation_job_id (calculation_job_id), INDEX idx_premise_destination_id (premise_destination_id), CONSTRAINT chk_container_type CHECK (container_type IN ('TEU', 'FEU', 'HC', 'TRUCK')) ); CREATE TABLE IF NOT EXISTS calculation_job_route_section ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, premise_route_section_id INT, calculation_job_destination_id INT NOT NULL, transport_type CHAR(16) CHECK (transport_type IN ('RAIL', 'SEA', 'ROAD', 'POST_RUN', 'MATRIX', 'D2D')), is_unmixed_price BOOLEAN DEFAULT FALSE, is_cbm_price BOOLEAN DEFAULT FALSE, is_weight_price BOOLEAN DEFAULT FALSE, is_stacked BOOLEAN DEFAULT FALSE, is_pre_run BOOLEAN DEFAULT FALSE, is_main_run BOOLEAN DEFAULT FALSE, is_post_run BOOLEAN DEFAULT FALSE, rate DECIMAL(15, 2) NOT NULL COMMENT 'copy of the container rate resp. price matrix in EUR (depends on used_rule)', distance DECIMAL(15, 2) DEFAULT NULL COMMENT 'distance of this routeInformationObject section im meters', cbm_price DECIMAL(15, 2) NOT NULL COMMENT 'calculated price per cubic meter', weight_price DECIMAL(15, 2) NOT NULL COMMENT 'calculated price per kilogram', annual_cost DECIMAL(15, 2) NOT NULL COMMENT 'annual costs for this routeInformationObject section, result depends on calculation method (mixed or unmixed, stacked or unstacked, per volume/per weight resp. container rate/price matrix)', transit_time INT UNSIGNED NOT NULL, FOREIGN KEY (premise_route_section_id) REFERENCES premise_route_section (id), FOREIGN KEY (calculation_job_destination_id) REFERENCES calculation_job_destination (id), INDEX idx_premise_route_section_id (premise_route_section_id), INDEX idx_calculation_job_destination_id (calculation_job_destination_id), CONSTRAINT chk_stacked CHECK (is_unmixed_price IS TRUE OR is_stacked IS TRUE) -- only unmixed transports can be unstacked ); CREATE TABLE IF NOT EXISTS bulk_operation ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, user_id INT NOT NULL, bulk_file_type CHAR(32) NOT NULL, bulk_processing_type CHAR(32) NOT NULL, state CHAR(10) NOT NULL, file LONGBLOB DEFAULT NULL, validity_period_id INT DEFAULT NULL, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (user_id) REFERENCES sys_user (id), FOREIGN KEY (validity_period_id) REFERENCES validity_period (id), CONSTRAINT chk_bulk_file_type CHECK (bulk_file_type IN ('CONTAINER_RATE', 'COUNTRY_MATRIX', 'MATERIAL', 'PACKAGING', 'NODE')), CONSTRAINT chk_bulk_operation_state CHECK (state IN ('SCHEDULED', 'PROCESSING', 'COMPLETED', 'EXCEPTION')), CONSTRAINT chk_bulk_processing_type CHECK (bulk_processing_type IN ('IMPORT', 'EXPORT')) ); CREATE TABLE IF NOT EXISTS sys_error ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, user_id INT DEFAULT NULL, title VARCHAR(255) NOT NULL, code VARCHAR(255) NOT NULL, message VARCHAR(1024) NOT NULL, request TEXT, pinia TEXT, calculation_job_id INT DEFAULT NULL, bulk_operation_id INT DEFAULT NULL, type CHAR(16) NOT NULL DEFAULT 'BACKEND', created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (user_id) REFERENCES sys_user (id), FOREIGN KEY (calculation_job_id) REFERENCES calculation_job (id), FOREIGN KEY (bulk_operation_id) REFERENCES bulk_operation (id), CONSTRAINT chk_error_type CHECK (type IN ('BACKEND', 'FRONTEND', 'BULK', 'CALCULATION')), INDEX idx_user_id (user_id), INDEX idx_calculation_job_id (calculation_job_id) ); CREATE TABLE IF NOT EXISTS sys_error_trace_item ( id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, error_id INT NOT NULL, line INT, file VARCHAR(255) NOT NULL, method VARCHAR(255) NOT NULL, fullPath VARCHAR(1024) NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (error_id) REFERENCES sys_error (id) );