Explorar el Código

Update Inventory

master
cyril.tsui hace 2 meses
padre
commit
2171d8b9d4
Se han modificado 10 ficheros con 363 adiciones y 12 borrados
  1. +10
    -3
      src/main/java/com/ffii/fpsms/modules/pickOrder/service/PickOrderService.kt
  2. +1
    -0
      src/main/java/com/ffii/fpsms/modules/pickOrder/web/PickOrderController.kt
  3. +10
    -5
      src/main/java/com/ffii/fpsms/modules/stock/entity/Inventory.kt
  4. +6
    -0
      src/main/java/com/ffii/fpsms/modules/stock/entity/InventoryRepository.kt
  5. +10
    -4
      src/main/java/com/ffii/fpsms/modules/stock/entity/projection/InventoryInfo.kt
  6. +8
    -0
      src/main/java/com/ffii/fpsms/modules/stock/service/InventoryService.kt
  7. +7
    -0
      src/main/resources/db/changelog/changes/20250624_01_cyril/01_update_inventory.sql
  8. +7
    -0
      src/main/resources/db/changelog/changes/20250624_01_cyril/02_remove_inventory_lot_line_trigger.sql
  9. +138
    -0
      src/main/resources/db/changelog/changes/20250624_01_cyril/03_update_inventory_lot_line_trigger_for_insert.sql
  10. +166
    -0
      src/main/resources/db/changelog/changes/20250624_01_cyril/04_update_inventory_lot_line_trigger_for_update.sql

+ 10
- 3
src/main/java/com/ffii/fpsms/modules/pickOrder/service/PickOrderService.kt Ver fichero

@@ -8,6 +8,7 @@ import com.ffii.fpsms.modules.pickOrder.enums.PickOrderStatus
import com.ffii.fpsms.modules.pickOrder.web.models.*
import com.ffii.fpsms.modules.stock.entity.InventoryLotLineRepository
import com.ffii.fpsms.modules.stock.entity.projection.CurrentInventoryItemInfo
import com.ffii.fpsms.modules.stock.service.InventoryService
import com.ffii.fpsms.modules.stock.service.StockOutLineService
import com.ffii.fpsms.modules.stock.service.SuggestedPickLotService
import com.ffii.fpsms.modules.stock.web.model.SuggestedPickLotForPoRequest
@@ -28,6 +29,7 @@ open class PickOrderService(
val stockOutLineService: StockOutLineService,
val suggestedPickLotService: SuggestedPickLotService,
val userService: UserService, private val inventoryLotLineRepository: InventoryLotLineRepository,
val inventoryService: InventoryService,
) {
open fun localDateTimeParse(dateTime: String?, pattern: String? = "YYYY-MM-DD hh:mm:ss"): LocalDateTime? {
try {
@@ -175,7 +177,11 @@ open class PickOrderService(

// Actual Pick Lots
// val actualPickLots = pol.stockOutLines
// val finalActu
// val finalActualPickLots = actualPickLots.map {
// ActualPickLotInConso(
//
// )
// }

// Return
PickOrderLineInConso(
@@ -259,9 +265,10 @@ open class PickOrderService(
}} // itemId - requiredQty

val itemIds = requiredItems.mapNotNull { it.first }
val inventories = inventoryLotLineRepository.findCurrentInventoryByItems(itemIds)
// val inventories = inventoryLotLineRepository.findCurrentInventoryByItems(itemIds)
val inventories = inventoryService.allInventoriesByItemIds(itemIds)
val currentInventoryInfos = requiredItems.map { item ->
val inventory = inventories.find { it.id == item.first }
val inventory = inventories.find { it.itemId == item.first }

item.second.let {
it.availableQty = inventory?.availableQty


+ 1
- 0
src/main/java/com/ffii/fpsms/modules/pickOrder/web/PickOrderController.kt Ver fichero

@@ -53,6 +53,7 @@ class PickOrderController(
return pickOrderService.consoPickOrderDetail(consoCode);
}

// Release Pick Order
@GetMapping("/releaseConso/{consoCode}")
fun releaseConsoPickOrderInfo(@PathVariable consoCode: String): ReleasePickOrderInfoResponse {
return pickOrderService.releaseConsoPickOrderInfo(consoCode);


+ 10
- 5
src/main/java/com/ffii/fpsms/modules/stock/entity/Inventory.kt Ver fichero

@@ -4,19 +4,24 @@ import com.ffii.core.entity.BaseEntity
import com.ffii.fpsms.modules.master.entity.Currency
import com.ffii.fpsms.modules.master.entity.Items
import com.ffii.fpsms.modules.master.entity.UomConversion
import com.ffii.fpsms.modules.master.entity.Warehouse
import jakarta.persistence.*
import jakarta.validation.constraints.NotNull
import jakarta.validation.constraints.Size
import java.math.BigDecimal
import java.time.LocalDate

@Entity
@Table(name = "inventory")
open class Inventory: BaseEntity<Long>(){
@NotNull
@Column(name = "qty")
open var qty: BigDecimal? = null
@Column(name = "onHandQty")
open var onHandQty: BigDecimal? = null

@NotNull
@Column(name = "onHoldQty")
open var onHoldQty: BigDecimal? = null

@NotNull
@Column(name = "unavailableQty")
open var unavailableQty: BigDecimal? = null

@NotNull
@Column(name = "price")


+ 6
- 0
src/main/java/com/ffii/fpsms/modules/stock/entity/InventoryRepository.kt Ver fichero

@@ -1,10 +1,16 @@
package com.ffii.fpsms.modules.stock.entity

import com.ffii.core.support.AbstractRepository
import com.ffii.fpsms.modules.master.entity.Items
import com.ffii.fpsms.modules.stock.entity.projection.InventoryInfo
import org.springframework.stereotype.Repository
import java.io.Serializable

@Repository
interface InventoryRepository: AbstractRepository<Inventory, Long> {
fun findInventoryInfoByDeletedIsFalse(): List<InventoryInfo>

fun findInventoryInfoByItemIdInAndDeletedIsFalse(itemIds: List<Serializable>): List<InventoryInfo>

fun findInventoryInfoByItemInAndDeletedIsFalse(items: List<Items>): List<InventoryInfo>
}

+ 10
- 4
src/main/java/com/ffii/fpsms/modules/stock/entity/projection/InventoryInfo.kt Ver fichero

@@ -5,14 +5,20 @@ import java.math.BigDecimal

interface InventoryInfo{
val id: Long?
@get:Value("#{target.item.id}")
val itemId: Long?
@get:Value("#{target.item.code}")
val code: String?
val itemCode: String?
@get:Value("#{target.item.name}")
val name: String?
val itemName: String?
@get:Value("#{target.item.type}")
val type: String?
val itemType: String?
// @get:Value("#{target.qty / (target.item.itemUoms.^[stockUnit == true && deleted == false]?.ratioN / target.item.itemUoms.^[stockUnit == true && deleted == false]?.ratioD)}")
val qty: BigDecimal?
val onHandQty: BigDecimal?
val onHoldQty: BigDecimal?
val unavailableQty: BigDecimal?
@get:Value("#{target.onHandQty - target.onHoldQty - target.unavailableQty}")
val availableQty: BigDecimal?
@get:Value("#{target.item.itemUoms.^[purchaseUnit == true && deleted == false]?.uom.code}")
val uomCode: String?
@get:Value("#{target.item.itemUoms.^[purchaseUnit == true && deleted == false]?.uom.udfudesc}")


+ 8
- 0
src/main/java/com/ffii/fpsms/modules/stock/service/InventoryService.kt Ver fichero

@@ -31,6 +31,14 @@ open class InventoryService(
return inventoryRepository.findInventoryInfoByDeletedIsFalse();
}

open fun allInventoriesByItems(items: List<Items>): List<InventoryInfo>{
return inventoryRepository.findInventoryInfoByItemInAndDeletedIsFalse(items);
}

open fun allInventoriesByItemIds(itemIds: List<Long>): List<InventoryInfo>{
return inventoryRepository.findInventoryInfoByItemIdInAndDeletedIsFalse(itemIds);
}

// @Throws(IOException::class)
// open fun updateInventory(request: SaveInventoryRequest): MessageResponse {
// // out need id


+ 7
- 0
src/main/resources/db/changelog/changes/20250624_01_cyril/01_update_inventory.sql Ver fichero

@@ -0,0 +1,7 @@
-- liquibase formatted sql
-- changeset cyril:update_inventory

ALTER TABLE `inventory`
ADD COLUMN `onHoldQty` DECIMAL(14,2) NOT NULL DEFAULT 0 AFTER `onHandQty`,
ADD COLUMN `unavailableQty` DECIMAL(14,2) NOT NULL DEFAULT 0 AFTER `onHoldQty`,
CHANGE COLUMN `qty` `onHandQty` DECIMAL(14,2) NOT NULL ;

+ 7
- 0
src/main/resources/db/changelog/changes/20250624_01_cyril/02_remove_inventory_lot_line_trigger.sql Ver fichero

@@ -0,0 +1,7 @@
-- liquibase formatted sql

-- changeset cyril:remove_inventory_lot_line_trigger

DROP TRIGGER IF EXISTS `inventory_lot_line_AFTER_INSERT`;

DROP TRIGGER IF EXISTS `inventory_lot_line_AFTER_UPDATE`;

+ 138
- 0
src/main/resources/db/changelog/changes/20250624_01_cyril/03_update_inventory_lot_line_trigger_for_insert.sql Ver fichero

@@ -0,0 +1,138 @@
-- liquibase formatted sql

-- changeset cyril:update_inventory_lot_line_trigger_after_insert splitStatements:false

create definer = current_user trigger `inventory_lot_line_AFTER_insert`
after insert
on `inventory_lot_line`
for each row
begin
declare inventoryId int default -1;

-- Global Error handling
declare error_msg TEXT default null;
declare continue handler for sqlexception, sqlwarning
begin
get diagnostics condition 1 error_msg = message_text;
set error_msg = coalesce(error_msg, 'Unknown error occurred');
-- Log the error (specific step logging is handled in each block)
end;

-- Set inventory id
select coalesce(
(select i.id
from `inventory` i
left join `inventory_lot` il on i.itemId = il.itemId
left join `item_uom` iu on iu.itemId = il.itemId and iu.baseUnit = true
left join `stock_in_line` sil on il.stockInLineId = sil.id
left join `purchase_order_line` pol on pol.id = sil.purchaseOrderLineId
where il.id = new.inventoryLotId
and i.uomId = iu.uomId
limit 1),
-1
)
into inventoryId;

-- Create temp table
drop temporary table if exists `temp_inventory`;

create temporary table `temp_inventory`
(
onHandQty decimal(14, 2),
onHoldQty decimal(14, 2),
unavailableQty decimal(14, 2),
currencyId int,
currencyName varchar(30),
uomId int,
itemId int,
price decimal(14, 2)
);

-- Step 1: Insert into temp table
insert into `temp_inventory` (onHandQty, onHoldQty, unavailableQty, currencyId, currencyName, uomId, itemId, price)
select coalesce(new.inQty, 0) - coalesce(new.outQty, 0) AS onHandQty,
coalesce(new.holdQty, 0) AS onHoldQty,
IF(
new.status = 'unavailable',
coalesce(new.inQty, 0) - coalesce(new.outQty, 0) - coalesce(new.holdQty, 0),
0
) AS unavailableQty,
c.id AS currencyId,
coalesce(c.name, 'HKD') AS currencyName,
iu.uomId AS uomId,
il.itemId AS itemId,
coalesce(pql.price, 0) AS price
from `inventory_lot` il
left join `item_uom` iu on iu.itemId = il.itemId and iu.baseUnit = true
left join `stock_in_line` sil on sil.id = il.stockInLineId
left join `stock_in` si on si.id = sil.stockInId
left join `purchase_order_line` pol on pol.id = sil.purchaseOrderLineId
left join `purchase_order` po on po.id = pol.purchaseOrderId
left join `purchase_quotation_line` pql on pql.itemId = il.itemId and pql.uomId = pol.uomId
left join `purchase_quotation` pq on pq.id = pql.purchaseQuotationId
left join `currency` c on c.id = pq.currencyId
where il.id = new.inventoryLotId;

-- Step 2: Insert / Update inventory table
begin
declare inventoryErrorMsg text default null;
declare continue handler for sqlexception, sqlwarning
begin
get diagnostics condition 1 inventoryErrorMsg = message_text;
set inventoryErrorMsg = coalesce(inventoryErrorMsg, 'Unknown error occurred');
end;

if inventoryId < 0 then
insert into `inventory` (itemId, onHandQty, onHoldQty, unavailableQty, price, currencyId, cpu, cpuUnit, cpm,
cpmUnit, uomId, status)
select ti.itemId AS itemId,
ti.onHandQty AS onHandQty,
ti.onHoldQty AS onHoldQty,
ti.unavailableQty AS unavailableQty,
ti.price AS price,
ti.currencyId AS currencyId,
0 AS cpu,
ti.currencyName AS cpuUnit,
0 AS cpm,
ti.currencyName AS cpmUnit,
ti.uomId AS uomId,
if(coalesce(ti.onHandQty - ti.onHoldQty - ti.unavailableQty, 0) > 0, 'available',
'unavailable') AS status
from `temp_inventory` ti;
else
update `inventory` i
join `temp_inventory` ti on i.itemId = ti.itemId and i.uomId = ti.uomId
set i.onHandQty = (i.onHandQty + ti.onHandQty),
i.onHoldQty = (i.onHoldQty + ti.onHoldQty),
i.unavailableQty = (i.unavailableQty + ti.unavailableQty),
i.price = ti.price,
i.currencyId = ti.currencyId,
i.cpu = 0,
i.cpuUnit = ti.currencyName,
i.cpm = 0,
i.cpmUnit = ti.currencyName,
i.uomId = ti.uomId,
i.status = if(coalesce((i.onHandQty + ti.onHandQty) - (i.onHoldQty + ti.onHoldQty) -
(i.unavailableQty + ti.unavailableQty), 0) > 0, 'available',
'unavailable')
where i.id = inventoryId;
end if;

if inventoryErrorMsg is null then
insert into `trigger_debug_log` (tableName, triggerName, description, status)
VALUES ('inventory_lot_line', 'after insert', 'Insert / Update Inventory Table', 'success');
ELSE
insert into `trigger_debug_log` (tableName, triggerName, description, errorMessages, status)
VALUES ('inventory_lot_line', 'after insert', 'Insert / Update Inventory Table', inventoryErrorMsg, 'fail');
end if;
end;

-- Clean up
drop temporary table if exists `temp_inventory`;

-- Log unhandled errors
if error_msg is NOT null then
insert into `trigger_debug_log` (tableName, triggerName, `description`, errorMessages, `status`)
VALUES ('inventory_lot_line', 'after insert', 'Unhandled error in trigger', error_msg, 'fail');
end if;
end;

+ 166
- 0
src/main/resources/db/changelog/changes/20250624_01_cyril/04_update_inventory_lot_line_trigger_for_update.sql Ver fichero

@@ -0,0 +1,166 @@
-- liquibase formatted sql

-- changeset cyril:update_inventory_lot_line_trigger_after_update splitStatements:false

create definer = current_user trigger `inventory_lot_line_AFTER_UPDATE`
after update
on `inventory_lot_line`
for each row
begin
declare inventoryId int default -1;

-- Global Error handling
declare error_msg text default null;
declare continue handler for sqlexception, sqlwarning
begin
get diagnostics condition 1 error_msg = message_text;
SET error_msg = coalesce(error_msg, 'Unknown error occurred');
-- Log the error (specific step logging is handled in each block)
end;

-- Set inventory id
select coalesce(
(select i.id
from `inventory` i
left join `inventory_lot` il on i.itemId = il.itemId
left join `item_uom` iu on iu.itemId = il.itemId and iu.baseUnit = true
left join `stock_in_line` sil on il.stockInLineId = sil.id
left join `purchase_order_line` pol on pol.id = sil.purchaseOrderLineId
where il.id = new.inventoryLotId
and i.uomId = iu.uomId
limit 1),
-1
)
into inventoryId;

-- Create temp table
drop temporary table if exists temp_inventory;

create temporary table temp_inventory
(
oldOnHandQty decimal(14, 2),
currentOnHandQty decimal(14, 2),
oldOnHoldQty decimal(14, 2),
currentOnHoldQty decimal(14, 2),
oldUnavailableQty decimal(14, 2),
currentUnavailableQty decimal(14, 2),
currencyId INT,
currencyName varchar(30),
uomId INT,
itemId INT,
price decimal(14, 2)
);

-- Step 1: Insert into temp table
insert into temp_inventory (oldOnHandQty, currentOnHandQty, oldOnHoldQty, currentOnHoldQty, oldUnavailableQty,
currentUnavailableQty, currencyId, currencyName, uomId, itemId, price)
select coalesce(coalesce(old.inQty, 0) - coalesce(old.outQty, 0), 0) as oldOnHandQty,
coalesce(coalesce(new.inQty, 0) - coalesce(new.outQty, 0), 0) as currentOnHandQty,
coalesce(old.holdQty, 0) as oldOnHoldQty,
coalesce(new.holdQty, 0) as currentOnHoldQty,
IF(
old.status = 'unavailable',
coalesce(old.inQty, 0) - coalesce(old.outQty, 0) - coalesce(old.holdQty, 0),
0
) as oldUnavailableQty,
IF(
new.status = 'unavailable',
coalesce(new.inQty, 0) - coalesce(new.outQty, 0) - coalesce(new.holdQty, 0),
0
) as currentUnavailableQty,
c.id as currencyId,
coalesce(c.name, 'HKD') as currencyName,
iu.uomId as uomId,
il.itemId as itemId,
coalesce(pql.price, 0) as price
from `inventory_lot` il
left join `item_uom` iu on iu.itemId = il.itemId and iu.baseUnit = true
left join `stock_in_line` sil on sil.id = il.stockInLineId
left join `stock_in` si on si.id = sil.stockInId
left join `purchase_order_line` pol on pol.id = sil.purchaseOrderLineId
left join `purchase_order` po on po.id = pol.purchaseOrderId
left join `purchase_quotation_line` pql on pql.itemId = il.itemId and pql.uomId = pol.uomId
left join `purchase_quotation` pq on pq.id = pql.purchaseQuotationId
left join `currency` c on c.id = pq.currencyId
where il.id = new.inventoryLotId;

-- Step 2: Insert / Update inventory table
begin
declare inventoryErrorMsg text default null;
declare continue handler for sqlexception, sqlwarning
begin
GET diagnostics condition 1 inventoryErrorMsg = message_text;
SET inventoryErrorMsg = coalesce(inventoryErrorMsg, 'Unknown error occurred');
end;

if inventoryId < 0 then
insert into `inventory` (itemId, onHandQty, onHoldQty, unavailableQty, price, currencyId, cpu, cpuUnit, cpm,
cpmUnit, uomId, status)
select ti.itemId as itemId,
ti.currentOnHandQty as onHandQty,
ti.currentOnHoldQty as onHoldQty,
ti.currentUnavailableQty as unavailableQty,
ti.price as price,
ti.currencyId as currencyId,
0 as cpu,
ti.currencyName as cpuUnit,
0 as cpm,
ti.currencyName as cpmUnit,
ti.uomId as uomId,
if(coalesce(ti.currentOnHandQty - ti.currentOnHoldQty - ti.currentUnavailableQty, 0) > 0,
'available', 'unavailable') as status
from `temp_inventory` ti;
else
update `inventory` i
join `temp_inventory` ti on i.itemId = ti.itemId and i.uomId = ti.uomId
set i.onHandQty = i.onHandQty - (ti.oldOnHandQty - ti.currentOnHandQty),
i.onHoldQty = i.onHoldQty - (ti.oldOnHoldQty - ti.currentOnHoldQty),
i.unavailableQty = case
when old.status = 'available' and new.status = 'unavailable'
then i.unavailableQty + ti.currentUnavailableQty
when old.status = 'unavailable' and new.status = 'available'
then i.unavailableQty - ti.oldUnavailableQty
when old.status = 'unavailable' and new.status = 'unavailable'
then i.unavailableQty + (ti.currentUnavailableQty - ti.oldUnavailableQty)
else i.unavailableQty
end,
i.price = ti.price,
i.currencyId = ti.currencyId,
i.cpu = 0,
i.cpuUnit = ti.currencyName,
i.cpm = 0,
i.cpmUnit = ti.currencyName,
i.status = if((i.onHandQty - (ti.oldOnHandQty - ti.currentOnHandQty)) - (i.onHoldQty -
(ti.oldOnHoldQty - ti.currentOnHoldQty))
- (case
when old.status = 'available' and new.status = 'unavailable'
then i.unavailableQty + ti.currentUnavailableQty
when old.status = 'unavailable' and new.status = 'available'
then i.unavailableQty - ti.oldUnavailableQty
when old.status = 'unavailable' and new.status = 'unavailable'
then i.unavailableQty + (ti.currentUnavailableQty - ti.oldUnavailableQty)
else i.unavailableQty
end) > 0,
'available', 'unavailable')
where i.id = inventoryId;
end if;

-- Check Error
if inventoryErrorMsg is null then
insert into `trigger_debug_log` (tableName, triggerName, description, status)
values ('inventory_lot_line', 'after insert', 'Insert / Update Inventory Table', 'success');
else
insert into `trigger_debug_log` (tableName, triggerName, description, errorMessages, status)
values ('inventory_lot_line', 'after insert', 'Insert / Update Inventory Table', inventoryErrorMsg, 'fail');
end if;
end;

-- clean up
drop temporary table if exists `temp_inventory`;

-- Log unhandled errors
if error_msg is NOT null then
insert into `trigger_debug_log` (tableName, triggerName, `description`, errorMessages, `status`)
VALUES ('inventory_lot_line', 'after insert', 'Unhandled error in trigger', error_msg, 'fail');
end if;
end;

Cargando…
Cancelar
Guardar