From fb6a7d777b8901fc18e8ff5e1e0b821fe5b0bf40 Mon Sep 17 00:00:00 2001 From: Rachid Flih Date: Fri, 27 Dec 2024 00:47:22 -0300 Subject: [PATCH] feat: wms db schema --- packages/api/prisma/schema.prisma | 566 ++++++++++++++++++++++++++++++ packages/api/scripts/db/wms.sql | 523 +++++++++++++++++++++++++++ 2 files changed, 1089 insertions(+) create mode 100644 packages/api/scripts/db/wms.sql diff --git a/packages/api/prisma/schema.prisma b/packages/api/prisma/schema.prisma index 5fac61ffe..33bdd4878 100644 --- a/packages/api/prisma/schema.prisma +++ b/packages/api/prisma/schema.prisma @@ -1530,3 +1530,569 @@ model projects_pull_frequency { id_project String @unique(map: "uq_projects_pull_frequency_project") @db.Uuid projects projects @relation(fields: [id_project], references: [id_project], onDelete: NoAction, onUpdate: NoAction, map: "fk_projects_pull_frequency_project") } + +model wms_addresses { + id_wms_address String @id @db.Uuid + full_name String? + company String? + address1 String? + address2 String? + address3 String? + city String? + state String? + postal_code String? + country String? + wms_orders_addresses wms_orders_addresses[] + wms_shipments_addresses wms_shipments_addresses[] + wms_warehouses_addresses wms_warehouses_addresses[] +} + +model wms_audit_log { + id_wms_audit_log String @id @db.Uuid + id_wms_user String? @db.Uuid + action String? + entity_type String? + entity_id String? @db.Uuid + created_at DateTime @db.Timestamptz(6) +} + +model wms_channels { + id_wms_channel String @id @db.Uuid + name String? + wms_orders wms_orders[] +} + +model wms_inbound_notes { + id_wms_inbound_shipment String @db.Uuid + note String + wms_inbound_shipments wms_inbound_shipments @relation(fields: [id_wms_inbound_shipment], references: [id_wms_inbound_shipment], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_inbound_shipment, note]) +} + +model wms_inbound_receipts { + id_wms_inbound_receipt String @id @db.Uuid + id_wms_inbound_shipment String? @db.Uuid + arrived_date DateTime? @db.Timestamptz(6) + wms_inbound_shipments wms_inbound_shipments? @relation(fields: [id_wms_inbound_shipment], references: [id_wms_inbound_shipment], onDelete: NoAction, onUpdate: NoAction) + wms_inbound_receipts_line_items wms_inbound_receipts_line_items[] +} + +model wms_inbound_receipts_line_items { + id_wms_inbound_receipt_line_item String @id @db.Uuid + id_wms_inbound_receipt String? @db.Uuid + id_wms_inventory_item String? @db.Uuid + sku String? + quantity Int? + wms_inbound_receipts wms_inbound_receipts? @relation(fields: [id_wms_inbound_receipt], references: [id_wms_inbound_receipt], onDelete: NoAction, onUpdate: NoAction) +} + +model wms_inbound_shipments { + id_wms_inbound_shipment String @id @db.Uuid + id_wms_warehouse_customer String? @db.Uuid + created_at DateTime @db.Timestamptz(6) + modified_at DateTime @db.Timestamptz(6) + id_connection String @db.Uuid + remote_id String? + remote_was_deleted Boolean @default(false) + purchase_order_number String? + status String? + raw_status String? + supplier String? + expected_arrival_date DateTime? @db.Timestamptz(6) + id_wms_warehouse String? @db.Uuid + external_system_url String? + wms_inbound_notes wms_inbound_notes[] + wms_inbound_receipts wms_inbound_receipts[] + wms_warehouse_customers wms_warehouse_customers? @relation(fields: [id_wms_warehouse_customer], references: [id_wms_warehouse_customer], onDelete: NoAction, onUpdate: NoAction) + wms_warehouses wms_warehouses? @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) + wms_inbound_shipments_line_items wms_inbound_shipments_line_items[] + wms_inbound_tracking_numbers wms_inbound_tracking_numbers[] +} + +model wms_inbound_shipments_line_items { + id_wms_inbound_shipment_line_item String @id @db.Uuid + id_wms_inbound_shipment String? @db.Uuid + id_wms_inventory_item String? @db.Uuid + sku String? + expected_quantity Int? + received_quantity Int? + unit_cost Decimal? @db.Decimal(10, 2) + external_id String? + wms_inbound_shipments wms_inbound_shipments? @relation(fields: [id_wms_inbound_shipment], references: [id_wms_inbound_shipment], onDelete: NoAction, onUpdate: NoAction) +} + +model wms_inbound_tracking_numbers { + id_wms_inbound_shipment String @db.Uuid + tracking_number String + wms_inbound_shipments wms_inbound_shipments @relation(fields: [id_wms_inbound_shipment], references: [id_wms_inbound_shipment], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_inbound_shipment, tracking_number]) +} + +model wms_inventory_items { + id_wms_inventory_item String @id @db.Uuid + id_wms_warehouse_customer String? @db.Uuid + created_at DateTime @db.Timestamptz(6) + modified_at DateTime @db.Timestamptz(6) + id_connection String @db.Uuid + remote_id String? + remote_was_deleted Boolean @default(false) + name String? + sku String? + unit_cost Decimal? @db.Decimal(10, 2) + active Boolean? + external_system_url String? + wms_warehouse_customers wms_warehouse_customers? @relation(fields: [id_wms_warehouse_customer], references: [id_wms_warehouse_customer], onDelete: NoAction, onUpdate: NoAction) + wms_inventory_items_measurements wms_inventory_items_measurements? + wms_inventory_levels wms_inventory_levels[] + wms_inventory_locations wms_inventory_locations[] + wms_inventory_substitutes wms_inventory_substitutes[] + wms_lots wms_lots[] + + @@index([sku], map: "idx_wms_inventory_items_sku") +} + +model wms_inventory_items_measurements { + id_wms_inventory_item String @id @db.Uuid + length Decimal? @db.Decimal(10, 2) + width Decimal? @db.Decimal(10, 2) + height Decimal? @db.Decimal(10, 2) + unit String? + weight Decimal? @db.Decimal(10, 2) + weight_unit String? + wms_inventory_items wms_inventory_items @relation(fields: [id_wms_inventory_item], references: [id_wms_inventory_item], onDelete: NoAction, onUpdate: NoAction) +} + +model wms_inventory_levels { + id_wms_inventory_item String @db.Uuid + id_wms_warehouse String @db.Uuid + onhand Int? + committed Int? + unfulfillable Int? + fulfillable Int? + unsellable Int? + sellable Int? + awaiting Int? + wms_inventory_items wms_inventory_items @relation(fields: [id_wms_inventory_item], references: [id_wms_inventory_item], onDelete: NoAction, onUpdate: NoAction) + wms_warehouses wms_warehouses @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_inventory_item, id_wms_warehouse]) +} + +model wms_inventory_locations { + id_wms_inventory_item String @db.Uuid + id_wms_location String @db.Uuid + id_wms_warehouse String? @db.Uuid + quantity Int? + wms_inventory_items wms_inventory_items @relation(fields: [id_wms_inventory_item], references: [id_wms_inventory_item], onDelete: NoAction, onUpdate: NoAction) + wms_locations wms_locations @relation(fields: [id_wms_location], references: [id_wms_location], onDelete: NoAction, onUpdate: NoAction) + wms_warehouses wms_warehouses? @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_inventory_item, id_wms_location]) +} + +model wms_inventory_substitutes { + id_wms_inventory_item String @db.Uuid + substitute_sku String + wms_inventory_items wms_inventory_items @relation(fields: [id_wms_inventory_item], references: [id_wms_inventory_item], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_inventory_item, substitute_sku]) +} + +model wms_locations { + id_wms_location String @id @db.Uuid + id_wms_warehouse String? @db.Uuid + wms_inventory_locations wms_inventory_locations[] + wms_warehouses wms_warehouses? @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) + wms_stock_movements_wms_stock_movements_id_wms_from_locationTowms_locations wms_stock_movements[] @relation("wms_stock_movements_id_wms_from_locationTowms_locations") + wms_stock_movements_wms_stock_movements_id_wms_to_locationTowms_locations wms_stock_movements[] @relation("wms_stock_movements_id_wms_to_locationTowms_locations") +} + +model wms_lots { + id_wms_lot String @id @db.Uuid + id_wms_inventory_item String? @db.Uuid + id_wms_warehouse String? @db.Uuid + onhand Int? + expiration_date DateTime? @db.Timestamptz(6) + wms_inventory_items wms_inventory_items? @relation(fields: [id_wms_inventory_item], references: [id_wms_inventory_item], onDelete: NoAction, onUpdate: NoAction) + wms_warehouses wms_warehouses? @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) +} + +/// This table contains check constraints and requires additional setup for migrations. Visit https://pris.ly/d/check-constraints for more info. +model wms_metadata { + id_wms_metadata String @id @db.Uuid + entity_type String + entity_id String @db.Uuid + key String + value String? + created_at DateTime @default(now()) @db.Timestamptz(6) + modified_at DateTime @default(now()) @db.Timestamptz(6) + + @@unique([entity_type, entity_id, key]) + @@index([entity_type, entity_id], map: "idx_wms_metadata_entity") + @@index([key], map: "idx_wms_metadata_key") +} + +model wms_orders { + id_wms_order String @id @db.Uuid + id_wms_warehouse_customer String? @db.Uuid + id_wms_warehouse String? @db.Uuid + created_at DateTime @db.Timestamptz(6) + modified_at DateTime @db.Timestamptz(6) + id_connection String @db.Uuid + remote_id String? + remote_was_deleted Boolean @default(false) + reference_id String? + order_number String? + status String? + raw_status String? + id_wms_channel String? @db.Uuid + type String? + trading_partner String? + id_wms_shipping_method String? @db.Uuid + is_third_party_freight Boolean? + invoice_currency_code String? + total_price Decimal? @db.Decimal(10, 2) + total_tax Decimal? @db.Decimal(10, 2) + total_discount Decimal? @db.Decimal(10, 2) + total_shipping Decimal? @db.Decimal(10, 2) + required_ship_date DateTime? @db.Timestamptz(6) + external_system_url String? + wms_channels wms_channels? @relation(fields: [id_wms_channel], references: [id_wms_channel], onDelete: NoAction, onUpdate: NoAction) + wms_shipping_methods wms_shipping_methods? @relation(fields: [id_wms_shipping_method], references: [id_wms_shipping_method], onDelete: NoAction, onUpdate: NoAction) + wms_warehouse_customers wms_warehouse_customers? @relation(fields: [id_wms_warehouse_customer], references: [id_wms_warehouse_customer], onDelete: NoAction, onUpdate: NoAction) + wms_warehouses wms_warehouses? @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) + wms_orders_addresses wms_orders_addresses[] + wms_orders_line_items wms_orders_line_items[] + wms_returns wms_returns[] + wms_shipments wms_shipments[] + + @@index([order_number], map: "idx_wms_orders_number") + @@index([status], map: "idx_wms_orders_status") +} + +model wms_orders_addresses { + id_wms_order String @db.Uuid + id_wms_address String? @db.Uuid + type String + wms_addresses wms_addresses? @relation(fields: [id_wms_address], references: [id_wms_address], onDelete: NoAction, onUpdate: NoAction) + wms_orders wms_orders @relation(fields: [id_wms_order], references: [id_wms_order], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_order, type]) +} + +model wms_orders_line_items { + id_wms_order_line_item String @id @db.Uuid + id_wms_order String? @db.Uuid + id_wms_product String? @db.Uuid + sku String? + quantity Int? + unit_price Decimal? @db.Decimal(10, 2) + is_picked Boolean? + discount_amount Decimal? @db.Decimal(10, 2) + wms_orders wms_orders? @relation(fields: [id_wms_order], references: [id_wms_order], onDelete: NoAction, onUpdate: NoAction) +} + +model wms_packages { + id_wms_package String @id @db.Uuid + id_wms_shipment String? @db.Uuid + package_name String? + tracking_number String? + tracking_url String? + id_wms_shipping_method String? @db.Uuid + carrier String? + scac String? + shipping_cost Decimal? @db.Decimal(10, 2) + wms_shipments wms_shipments? @relation(fields: [id_wms_shipment], references: [id_wms_shipment], onDelete: NoAction, onUpdate: NoAction) + wms_shipping_methods wms_shipping_methods? @relation(fields: [id_wms_shipping_method], references: [id_wms_shipping_method], onDelete: NoAction, onUpdate: NoAction) + wms_packages_line_items wms_packages_line_items[] + wms_packages_measurements wms_packages_measurements? +} + +model wms_packages_line_items { + id_wms_package_line_item String @id @db.Uuid + id_wms_package String? @db.Uuid + id_wms_inventory_item String? @db.Uuid + sku String? + quantity Int? + id_wms_lot String? @db.Uuid + expiration_date DateTime? @db.Timestamptz(6) + id_wms_parent_product String? @db.Uuid + wms_packages wms_packages? @relation(fields: [id_wms_package], references: [id_wms_package], onDelete: NoAction, onUpdate: NoAction) +} + +model wms_packages_measurements { + id_wms_package String @id @db.Uuid + length Decimal? @db.Decimal(10, 2) + width Decimal? @db.Decimal(10, 2) + height Decimal? @db.Decimal(10, 2) + unit String? + weight Decimal? @db.Decimal(10, 2) + weight_unit String? + wms_packages wms_packages @relation(fields: [id_wms_package], references: [id_wms_package], onDelete: NoAction, onUpdate: NoAction) +} + +model wms_permissions { + id_wms_permission String @id @db.Uuid + name String? + description String? + wms_user_permissions wms_user_permissions[] +} + +model wms_products { + id_wms_product String @id @db.Uuid + id_wms_warehouse_customer String? @db.Uuid + created_at DateTime @db.Timestamptz(6) + modified_at DateTime @db.Timestamptz(6) + id_connection String @db.Uuid + remote_id String? + remote_was_deleted Boolean @default(false) + name String? + sku String? + gtin String? + unit_price Decimal? @db.Decimal(10, 2) + is_kit Boolean? + active Boolean? + supplier String? + country_of_origin String? + harmonized_code String? + external_system_url String? + wms_warehouse_customers wms_warehouse_customers? @relation(fields: [id_wms_warehouse_customer], references: [id_wms_warehouse_customer], onDelete: NoAction, onUpdate: NoAction) + wms_products_inventory_items wms_products_inventory_items[] + wms_products_supplier_items wms_products_supplier_items[] + + @@index([sku], map: "idx_wms_products_sku") +} + +model wms_products_inventory_items { + id_wms_product String @db.Uuid + id_wms_inventory_item String @db.Uuid + sku String? + unit_quantity Int? + wms_products wms_products @relation(fields: [id_wms_product], references: [id_wms_product], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_product, id_wms_inventory_item]) +} + +model wms_products_supplier_items { + id_wms_product String @db.Uuid + id_wms_supplier String @db.Uuid + supplier_name String? + external_id String? + unit_cost Decimal? @db.Decimal(10, 2) + wms_products wms_products @relation(fields: [id_wms_product], references: [id_wms_product], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_product, id_wms_supplier]) +} + +model wms_returns { + id_wms_return String @id @db.Uuid + id_wms_warehouse_customer String? @db.Uuid + created_at DateTime @db.Timestamptz(6) + modified_at DateTime @db.Timestamptz(6) + id_connection String @db.Uuid + remote_id String? + remote_was_deleted Boolean @default(false) + status String? + raw_status String? + id_wms_order String? @db.Uuid + external_system_url String? + wms_orders wms_orders? @relation(fields: [id_wms_order], references: [id_wms_order], onDelete: NoAction, onUpdate: NoAction) + wms_warehouse_customers wms_warehouse_customers? @relation(fields: [id_wms_warehouse_customer], references: [id_wms_warehouse_customer], onDelete: NoAction, onUpdate: NoAction) + wms_returns_line_items wms_returns_line_items[] + wms_returns_notes wms_returns_notes[] + wms_returns_shipments wms_returns_shipments[] +} + +model wms_returns_line_items { + id_wms_return_line_item String @id @db.Uuid + id_wms_return String? @db.Uuid + id_wms_inventory_item String? @db.Uuid + sku String? + expected_quantity Int? + received_quantity Int? + restocked_quantity Int? + return_reason String? + quantity Int? + id_wms_warehouse String? @db.Uuid + returned_date DateTime? @db.Timestamptz(6) + wms_returns wms_returns? @relation(fields: [id_wms_return], references: [id_wms_return], onDelete: NoAction, onUpdate: NoAction) + wms_warehouses wms_warehouses? @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) +} + +model wms_returns_notes { + id_wms_return String @db.Uuid + note String + wms_returns wms_returns @relation(fields: [id_wms_return], references: [id_wms_return], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_return, note]) +} + +model wms_returns_receiving_details { + id_wms_return_shipment_item String @db.Uuid + quantity Int? + condition String + disposition String + wms_returns_shipments_items wms_returns_shipments_items @relation(fields: [id_wms_return_shipment_item], references: [id_wms_return_shipment_item], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_return_shipment_item, condition, disposition]) +} + +model wms_returns_shipments { + id_wms_return_shipment String @id @db.Uuid + id_wms_return String? @db.Uuid + tracking_number String? + shipped_date DateTime? @db.Timestamptz(6) + arrived_date DateTime? @db.Timestamptz(6) + id_wms_warehouse String? @db.Uuid + carrier String? + shipping_cost Decimal? @db.Decimal(10, 2) + wms_returns wms_returns? @relation(fields: [id_wms_return], references: [id_wms_return], onDelete: NoAction, onUpdate: NoAction) + wms_warehouses wms_warehouses? @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) + wms_returns_shipments_items wms_returns_shipments_items[] + wms_returns_shipments_measurements wms_returns_shipments_measurements? +} + +model wms_returns_shipments_items { + id_wms_return_shipment_item String @id @db.Uuid + id_wms_return_shipment String? @db.Uuid + id_wms_inventory_item String? @db.Uuid + sku String? + quantity Int? + wms_returns_receiving_details wms_returns_receiving_details[] + wms_returns_shipments wms_returns_shipments? @relation(fields: [id_wms_return_shipment], references: [id_wms_return_shipment], onDelete: NoAction, onUpdate: NoAction) +} + +model wms_returns_shipments_measurements { + id_wms_return_shipment String @id @db.Uuid + length Decimal? @db.Decimal(10, 2) + width Decimal? @db.Decimal(10, 2) + height Decimal? @db.Decimal(10, 2) + unit String? + weight Decimal? @db.Decimal(10, 2) + weight_unit String? + wms_returns_shipments wms_returns_shipments @relation(fields: [id_wms_return_shipment], references: [id_wms_return_shipment], onDelete: NoAction, onUpdate: NoAction) +} + +model wms_shipments { + id_wms_shipment String @id @db.Uuid + id_wms_order String? @db.Uuid + id_wms_warehouse String? @db.Uuid + shipped_date DateTime? @db.Timestamptz(6) + raw_status String? + status String? + id_wms_shipping_method String? @db.Uuid + wms_packages wms_packages[] + wms_orders wms_orders? @relation(fields: [id_wms_order], references: [id_wms_order], onDelete: NoAction, onUpdate: NoAction) + wms_shipping_methods wms_shipping_methods? @relation(fields: [id_wms_shipping_method], references: [id_wms_shipping_method], onDelete: NoAction, onUpdate: NoAction) + wms_warehouses wms_warehouses? @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) + wms_shipments_addresses wms_shipments_addresses[] +} + +model wms_shipments_addresses { + id_wms_shipment String @db.Uuid + id_wms_address String? @db.Uuid + type String + wms_addresses wms_addresses? @relation(fields: [id_wms_address], references: [id_wms_address], onDelete: NoAction, onUpdate: NoAction) + wms_shipments wms_shipments @relation(fields: [id_wms_shipment], references: [id_wms_shipment], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_shipment, type]) +} + +model wms_shipping_methods { + id_wms_shipping_method String @id @db.Uuid + created_at DateTime @db.Timestamptz(6) + modified_at DateTime @db.Timestamptz(6) + id_connection String @db.Uuid + remote_id String? + remote_was_deleted Boolean @default(false) + name String? + carrier String? + wms_orders wms_orders[] + wms_packages wms_packages[] + wms_shipments wms_shipments[] +} + +model wms_stock_movements { + id_wms_stock_movement String @id @db.Uuid + id_wms_inventory_item String? @db.Uuid + id_wms_warehouse String? @db.Uuid + movement_type String? + quantity Int? + id_wms_from_location String? @db.Uuid + id_wms_to_location String? @db.Uuid + id_wms_reference String? @db.Uuid + reference_type String? + created_at DateTime @db.Timestamptz(6) + id_wms_user String? @db.Uuid + wms_locations_wms_stock_movements_id_wms_from_locationTowms_locations wms_locations? @relation("wms_stock_movements_id_wms_from_locationTowms_locations", fields: [id_wms_from_location], references: [id_wms_location], onDelete: NoAction, onUpdate: NoAction) + wms_locations_wms_stock_movements_id_wms_to_locationTowms_locations wms_locations? @relation("wms_stock_movements_id_wms_to_locationTowms_locations", fields: [id_wms_to_location], references: [id_wms_location], onDelete: NoAction, onUpdate: NoAction) + wms_warehouses wms_warehouses? @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) +} + +model wms_user_permissions { + id_wms_user String @db.Uuid + id_wms_permission String @db.Uuid + wms_permissions wms_permissions @relation(fields: [id_wms_permission], references: [id_wms_permission], onDelete: NoAction, onUpdate: NoAction) + wms_users wms_users @relation(fields: [id_wms_user], references: [id_wms_user], onDelete: NoAction, onUpdate: NoAction) + + @@id([id_wms_user, id_wms_permission]) +} + +model wms_users { + id_wms_user String @id @db.Uuid + email String? + name String? + role String? + wms_user_permissions wms_user_permissions[] +} + +model wms_warehouse_customers { + id_wms_warehouse_customer String @id @db.Uuid + created_at DateTime @db.Timestamptz(6) + modified_at DateTime @db.Timestamptz(6) + id_connection String @db.Uuid + remote_id String? + remote_was_deleted Boolean @default(false) + name String? + email String? + wms_inbound_shipments wms_inbound_shipments[] + wms_inventory_items wms_inventory_items[] + wms_orders wms_orders[] + wms_products wms_products[] + wms_returns wms_returns[] + + @@index([email], map: "idx_wms_warehouse_customers_email") +} + +model wms_warehouses { + id_wms_warehouse String @id @db.Uuid + created_at DateTime @db.Timestamptz(6) + modified_at DateTime @db.Timestamptz(6) + id_connection String @db.Uuid + remote_id String? + remote_was_deleted Boolean @default(false) + name String? + code String? + wms_inbound_shipments wms_inbound_shipments[] + wms_inventory_levels wms_inventory_levels[] + wms_inventory_locations wms_inventory_locations[] + wms_locations wms_locations[] + wms_lots wms_lots[] + wms_orders wms_orders[] + wms_returns_line_items wms_returns_line_items[] + wms_returns_shipments wms_returns_shipments[] + wms_shipments wms_shipments[] + wms_stock_movements wms_stock_movements[] + wms_warehouses_addresses wms_warehouses_addresses? + + @@index([code], map: "idx_wms_warehouses_code") +} + +model wms_warehouses_addresses { + id_wms_warehouse String @id @db.Uuid + id_wms_address String? @db.Uuid + wms_addresses wms_addresses? @relation(fields: [id_wms_address], references: [id_wms_address], onDelete: NoAction, onUpdate: NoAction) + wms_warehouses wms_warehouses @relation(fields: [id_wms_warehouse], references: [id_wms_warehouse], onDelete: NoAction, onUpdate: NoAction) +} diff --git a/packages/api/scripts/db/wms.sql b/packages/api/scripts/db/wms.sql new file mode 100644 index 000000000..27d8ab29d --- /dev/null +++ b/packages/api/scripts/db/wms.sql @@ -0,0 +1,523 @@ +/* +WMS Database Schema Overview + +This schema follows a unified structure with the following object groups: + +1. Core Objects (with id_connection, remote tracking, metadata): + - wms_warehouses + - wms_warehouse_customers + - wms_shipping_methods + - wms_products + - wms_inventory_items + - wms_orders + - wms_returns + - wms_inbound_shipments + +2. Address Related: + - wms_addresses + - wms_warehouses_addresses + - wms_orders_addresses + - wms_shipments_addresses + +3. Measurement Tables: + - wms_inventory_items_measurements + - wms_packages_measurements + - wms_returns_shipments_measurements + +4. Line Items: + - wms_orders_line_items + - wms_packages_line_items + - wms_returns_line_items + - wms_inbound_shipments_line_items + - wms_inbound_receipts_line_items + +5. Shipment Related: + - wms_shipments + - wms_returns_shipments + - wms_inbound_shipments + +6. Inventory Related: + - wms_inventory_items + - wms_inventory_levels + - wms_inventory_locations + - wms_inventory_substitutes + +7. User Management: + - wms_users + - wms_permissions + - wms_user_permissions + - wms_audit_log +*/ + +-- Core tables +CREATE TABLE wms_warehouses ( + id_wms_warehouse UUID PRIMARY KEY, + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + modified_at TIMESTAMP WITH TIME ZONE NOT NULL, + id_connection UUID NOT NULL, + remote_id TEXT, + remote_was_deleted BOOLEAN NOT NULL DEFAULT FALSE, + name TEXT, + code TEXT +); + +CREATE TABLE wms_addresses ( + id_wms_address UUID PRIMARY KEY, + full_name TEXT, + company TEXT, + address1 TEXT, + address2 TEXT, + address3 TEXT, + city TEXT, + state TEXT, + postal_code TEXT, + country TEXT +); + +CREATE TABLE wms_warehouses_addresses ( + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse), + id_wms_address UUID REFERENCES wms_addresses(id_wms_address), + PRIMARY KEY (id_wms_warehouse) +); + +CREATE TABLE wms_warehouse_customers ( + id_wms_warehouse_customer UUID PRIMARY KEY, + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + modified_at TIMESTAMP WITH TIME ZONE NOT NULL, + id_connection UUID NOT NULL, + remote_id TEXT, + remote_was_deleted BOOLEAN NOT NULL DEFAULT FALSE, + name TEXT, + email TEXT +); + +CREATE TABLE wms_shipping_methods ( + id_wms_shipping_method UUID PRIMARY KEY, + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + modified_at TIMESTAMP WITH TIME ZONE NOT NULL, + id_connection UUID NOT NULL, + remote_id TEXT, + remote_was_deleted BOOLEAN NOT NULL DEFAULT FALSE, + name TEXT, + carrier TEXT +); + +CREATE TABLE wms_channels ( + id_wms_channel UUID PRIMARY KEY, + name TEXT +); + +-- Products +CREATE TABLE wms_products ( + id_wms_product UUID PRIMARY KEY, + id_wms_warehouse_customer UUID REFERENCES wms_warehouse_customers(id_wms_warehouse_customer), + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + modified_at TIMESTAMP WITH TIME ZONE NOT NULL, + id_connection UUID NOT NULL, + remote_id TEXT, + remote_was_deleted BOOLEAN NOT NULL DEFAULT FALSE, + name TEXT, + sku TEXT, + gtin TEXT, + unit_price DECIMAL(10,2), + is_kit BOOLEAN, + active BOOLEAN, + supplier TEXT, + country_of_origin TEXT, + harmonized_code TEXT, + external_system_url TEXT +); + +CREATE TABLE wms_products_inventory_items ( + id_wms_product UUID REFERENCES wms_products(id_wms_product), + id_wms_inventory_item UUID, + sku TEXT, + unit_quantity INTEGER, + PRIMARY KEY (id_wms_product, id_wms_inventory_item) +); + +CREATE TABLE wms_products_supplier_items ( + id_wms_product UUID REFERENCES wms_products(id_wms_product), + id_wms_supplier UUID, + supplier_name TEXT, + external_id TEXT, + unit_cost DECIMAL(10,2), + PRIMARY KEY (id_wms_product, id_wms_supplier) +); + +-- Inventory +CREATE TABLE wms_inventory_items ( + id_wms_inventory_item UUID PRIMARY KEY, + id_wms_warehouse_customer UUID REFERENCES wms_warehouse_customers(id_wms_warehouse_customer), + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + modified_at TIMESTAMP WITH TIME ZONE NOT NULL, + id_connection UUID NOT NULL, + remote_id TEXT, + remote_was_deleted BOOLEAN NOT NULL DEFAULT FALSE, + name TEXT, + sku TEXT, + unit_cost DECIMAL(10,2), + active BOOLEAN, + external_system_url TEXT +); + +CREATE TABLE wms_inventory_items_measurements ( + id_wms_inventory_item UUID PRIMARY KEY REFERENCES wms_inventory_items(id_wms_inventory_item), + length DECIMAL(10,2), + width DECIMAL(10,2), + height DECIMAL(10,2), + unit TEXT, + weight DECIMAL(10,2), + weight_unit TEXT +); + +CREATE TABLE wms_inventory_levels ( + id_wms_inventory_item UUID REFERENCES wms_inventory_items(id_wms_inventory_item), + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse), + onhand INTEGER, + committed INTEGER, + unfulfillable INTEGER, + fulfillable INTEGER, + unsellable INTEGER, + sellable INTEGER, + awaiting INTEGER, + PRIMARY KEY (id_wms_inventory_item, id_wms_warehouse) +); + +CREATE TABLE wms_lots ( + id_wms_lot UUID PRIMARY KEY, + id_wms_inventory_item UUID REFERENCES wms_inventory_items(id_wms_inventory_item), + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse), + onhand INTEGER, + expiration_date TIMESTAMP WITH TIME ZONE +); + +CREATE TABLE wms_locations ( + id_wms_location UUID PRIMARY KEY, + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse) +); + +CREATE TABLE wms_inventory_locations ( + id_wms_inventory_item UUID REFERENCES wms_inventory_items(id_wms_inventory_item), + id_wms_location UUID REFERENCES wms_locations(id_wms_location), + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse), + quantity INTEGER, + PRIMARY KEY (id_wms_inventory_item, id_wms_location) +); + +CREATE TABLE wms_inventory_substitutes ( + id_wms_inventory_item UUID REFERENCES wms_inventory_items(id_wms_inventory_item), + substitute_sku TEXT, + PRIMARY KEY (id_wms_inventory_item, substitute_sku) +); + +-- Orders +CREATE TABLE wms_orders ( + id_wms_order UUID PRIMARY KEY, + id_wms_warehouse_customer UUID REFERENCES wms_warehouse_customers(id_wms_warehouse_customer), + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse), + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + modified_at TIMESTAMP WITH TIME ZONE NOT NULL, + id_connection UUID NOT NULL, + remote_id TEXT, + remote_was_deleted BOOLEAN NOT NULL DEFAULT FALSE, + reference_id TEXT, + order_number TEXT, + -- Status can be one of: + -- 'open' - Order has been placed + -- 'confirmed' - Order has been confirmed by the warehouse + -- 'processing' - Order is being processed and items are being picked + -- 'picked' - Items in order have been picked + -- 'packed' - Items in order have been packed + -- 'partially_fulfilled' - Order has been partially fulfilled + -- 'fulfilled' - Order has been fulfilled and shipped + -- 'backordered' - Order cannot be fulfilled because of a lack of available inventory + -- 'exception' - There is an issue with the order + -- 'cancelled' - Order has been cancelled by either the warehouse or the customer + -- 'other' - Status can't be determined. See raw_status field for more information + status TEXT, + -- Contains the original status from the external system when status is 'other' + raw_status TEXT, + id_wms_channel UUID REFERENCES wms_channels(id_wms_channel), + -- The type of order, such as d2c or b2b + -- Available options: + -- 'd2c' - Direct to Consumer order + -- 'b2b' - Business to Business order + -- 'dropship' - Dropship order + type TEXT, + trading_partner TEXT, + id_wms_shipping_method UUID REFERENCES wms_shipping_methods(id_wms_shipping_method), + is_third_party_freight BOOLEAN, + invoice_currency_code TEXT, + total_price DECIMAL(10,2), + total_tax DECIMAL(10,2), + total_discount DECIMAL(10,2), + total_shipping DECIMAL(10,2), + required_ship_date TIMESTAMP WITH TIME ZONE, + external_system_url TEXT +); + +CREATE TABLE wms_orders_addresses ( + id_wms_order UUID REFERENCES wms_orders(id_wms_order), + id_wms_address UUID REFERENCES wms_addresses(id_wms_address), + type TEXT, + PRIMARY KEY (id_wms_order, type) +); + +CREATE TABLE wms_orders_line_items ( + id_wms_order_line_item UUID PRIMARY KEY, + id_wms_order UUID REFERENCES wms_orders(id_wms_order), + id_wms_product UUID, + sku TEXT, + quantity INTEGER, + unit_price DECIMAL(10,2), + is_picked BOOLEAN, + discount_amount DECIMAL(10,2) +); + +-- Shipments +CREATE TABLE wms_shipments ( + id_wms_shipment UUID PRIMARY KEY, + id_wms_order UUID REFERENCES wms_orders(id_wms_order), + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse), + shipped_date TIMESTAMP WITH TIME ZONE, + raw_status TEXT, + status TEXT, + id_wms_shipping_method UUID REFERENCES wms_shipping_methods(id_wms_shipping_method) +); + +CREATE TABLE wms_shipments_addresses ( + id_wms_shipment UUID REFERENCES wms_shipments(id_wms_shipment), + id_wms_address UUID REFERENCES wms_addresses(id_wms_address), + type TEXT, + PRIMARY KEY (id_wms_shipment, type) +); + +-- Packages +CREATE TABLE wms_packages ( + id_wms_package UUID PRIMARY KEY, + id_wms_shipment UUID REFERENCES wms_shipments(id_wms_shipment), + package_name TEXT, + tracking_number TEXT, + tracking_url TEXT, + id_wms_shipping_method UUID REFERENCES wms_shipping_methods(id_wms_shipping_method), + carrier TEXT, + scac TEXT, + shipping_cost DECIMAL(10,2) +); + +CREATE TABLE wms_packages_measurements ( + id_wms_package UUID PRIMARY KEY REFERENCES wms_packages(id_wms_package), + length DECIMAL(10,2), + width DECIMAL(10,2), + height DECIMAL(10,2), + unit TEXT, + weight DECIMAL(10,2), + weight_unit TEXT +); + +CREATE TABLE wms_packages_line_items ( + id_wms_package_line_item UUID PRIMARY KEY, + id_wms_package UUID REFERENCES wms_packages(id_wms_package), + id_wms_inventory_item UUID, + sku TEXT, + quantity INTEGER, + id_wms_lot UUID, + expiration_date TIMESTAMP WITH TIME ZONE, + id_wms_parent_product UUID +); + +-- Returns +CREATE TABLE wms_returns ( + id_wms_return UUID PRIMARY KEY, + id_wms_warehouse_customer UUID REFERENCES wms_warehouse_customers(id_wms_warehouse_customer), + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + modified_at TIMESTAMP WITH TIME ZONE NOT NULL, + id_connection UUID NOT NULL, + remote_id TEXT, + remote_was_deleted BOOLEAN NOT NULL DEFAULT FALSE, + status TEXT, + raw_status TEXT, + id_wms_order UUID REFERENCES wms_orders(id_wms_order), + external_system_url TEXT +); + +CREATE TABLE wms_returns_notes ( + id_wms_return UUID REFERENCES wms_returns(id_wms_return), + note TEXT, + PRIMARY KEY (id_wms_return, note) +); + +CREATE TABLE wms_returns_line_items ( + id_wms_return_line_item UUID PRIMARY KEY, + id_wms_return UUID REFERENCES wms_returns(id_wms_return), + id_wms_inventory_item UUID, + sku TEXT, + expected_quantity INTEGER, + received_quantity INTEGER, + restocked_quantity INTEGER, + return_reason TEXT, + quantity INTEGER, + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse), + returned_date TIMESTAMP WITH TIME ZONE +); + +CREATE TABLE wms_returns_shipments ( + id_wms_return_shipment UUID PRIMARY KEY, + id_wms_return UUID REFERENCES wms_returns(id_wms_return), + tracking_number TEXT, + shipped_date TIMESTAMP WITH TIME ZONE, + arrived_date TIMESTAMP WITH TIME ZONE, + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse), + carrier TEXT, + shipping_cost DECIMAL(10,2) +); + +CREATE TABLE wms_returns_shipments_measurements ( + id_wms_return_shipment UUID PRIMARY KEY REFERENCES wms_returns_shipments(id_wms_return_shipment), + length DECIMAL(10,2), + width DECIMAL(10,2), + height DECIMAL(10,2), + unit TEXT, + weight DECIMAL(10,2), + weight_unit TEXT +); + +CREATE TABLE wms_returns_shipments_items ( + id_wms_return_shipment_item UUID PRIMARY KEY, + id_wms_return_shipment UUID REFERENCES wms_returns_shipments(id_wms_return_shipment), + id_wms_inventory_item UUID, + sku TEXT, + quantity INTEGER +); + +CREATE TABLE wms_returns_receiving_details ( + id_wms_return_shipment_item UUID REFERENCES wms_returns_shipments_items(id_wms_return_shipment_item), + quantity INTEGER, + condition TEXT, + disposition TEXT, + PRIMARY KEY (id_wms_return_shipment_item, condition, disposition) +); + +-- Inbound Shipments +CREATE TABLE wms_inbound_shipments ( + id_wms_inbound_shipment UUID PRIMARY KEY, + id_wms_warehouse_customer UUID REFERENCES wms_warehouse_customers(id_wms_warehouse_customer), + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + modified_at TIMESTAMP WITH TIME ZONE NOT NULL, + id_connection UUID NOT NULL, + remote_id TEXT, + remote_was_deleted BOOLEAN NOT NULL DEFAULT FALSE, + purchase_order_number TEXT, + status TEXT, + raw_status TEXT, + supplier TEXT, + expected_arrival_date TIMESTAMP WITH TIME ZONE, + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse), + external_system_url TEXT +); + +CREATE TABLE wms_inbound_shipments_line_items ( + id_wms_inbound_shipment_line_item UUID PRIMARY KEY, + id_wms_inbound_shipment UUID REFERENCES wms_inbound_shipments(id_wms_inbound_shipment), + id_wms_inventory_item UUID, + sku TEXT, + expected_quantity INTEGER, + received_quantity INTEGER, + unit_cost DECIMAL(10,2), + external_id TEXT +); + +CREATE TABLE wms_inbound_receipts ( + id_wms_inbound_receipt UUID PRIMARY KEY, + id_wms_inbound_shipment UUID REFERENCES wms_inbound_shipments(id_wms_inbound_shipment), + arrived_date TIMESTAMP WITH TIME ZONE +); + +CREATE TABLE wms_inbound_receipts_line_items ( + id_wms_inbound_receipt_line_item UUID PRIMARY KEY, + id_wms_inbound_receipt UUID REFERENCES wms_inbound_receipts(id_wms_inbound_receipt), + id_wms_inventory_item UUID, + sku TEXT, + quantity INTEGER +); + +CREATE TABLE wms_inbound_tracking_numbers ( + id_wms_inbound_shipment UUID REFERENCES wms_inbound_shipments(id_wms_inbound_shipment), + tracking_number TEXT, + PRIMARY KEY (id_wms_inbound_shipment, tracking_number) +); + +CREATE TABLE wms_inbound_notes ( + id_wms_inbound_shipment UUID REFERENCES wms_inbound_shipments(id_wms_inbound_shipment), + note TEXT, + PRIMARY KEY (id_wms_inbound_shipment, note) +); + +-- Stock Movements +CREATE TABLE wms_stock_movements ( + id_wms_stock_movement UUID PRIMARY KEY, + id_wms_inventory_item UUID, + id_wms_warehouse UUID REFERENCES wms_warehouses(id_wms_warehouse), + movement_type TEXT, + quantity INTEGER, + id_wms_from_location UUID REFERENCES wms_locations(id_wms_location), + id_wms_to_location UUID REFERENCES wms_locations(id_wms_location), + id_wms_reference UUID, + reference_type TEXT, + created_at TIMESTAMP WITH TIME ZONE NOT NULL, + id_wms_user UUID +); + +-- Users and Permissions +CREATE TABLE wms_users ( + id_wms_user UUID PRIMARY KEY, + email TEXT, + name TEXT, + role TEXT +); + +CREATE TABLE wms_permissions ( + id_wms_permission UUID PRIMARY KEY, + name TEXT, + description TEXT +); + +CREATE TABLE wms_user_permissions ( + id_wms_user UUID REFERENCES wms_users(id_wms_user), + id_wms_permission UUID REFERENCES wms_permissions(id_wms_permission), + PRIMARY KEY (id_wms_user, id_wms_permission) +); + +CREATE TABLE wms_audit_log ( + id_wms_audit_log UUID PRIMARY KEY, + id_wms_user UUID, + action TEXT, + entity_type TEXT, + entity_id UUID, + created_at TIMESTAMP WITH TIME ZONE NOT NULL +); + +-- Create metadata table +CREATE TABLE wms_metadata ( + id_wms_metadata UUID PRIMARY KEY, + entity_type TEXT NOT NULL, -- e.g., 'wms_order', 'wms_product', etc. + entity_id UUID NOT NULL, -- reference to the entity + key TEXT NOT NULL CHECK (length(key) <= 40), + value TEXT CHECK (value IS NULL OR length(value) <= 500), -- Allow NULL values + created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, + modified_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, + UNIQUE (entity_type, entity_id, key) +); + +-- Add indexes for efficient querying +CREATE INDEX idx_wms_metadata_entity ON wms_metadata(entity_type, entity_id); +CREATE INDEX idx_wms_metadata_key ON wms_metadata(key); + +-- Indexes +CREATE INDEX idx_wms_warehouses_code ON wms_warehouses(code); +CREATE INDEX idx_wms_warehouse_customers_email ON wms_warehouse_customers(email); +CREATE INDEX idx_wms_products_sku ON wms_products(sku); +CREATE INDEX idx_wms_inventory_items_sku ON wms_inventory_items(sku); +CREATE INDEX idx_wms_orders_number ON wms_orders(order_number); +CREATE INDEX idx_wms_orders_status ON wms_orders(status); \ No newline at end of file