Przeglądaj źródła

remove holdqty in trigger

production_process
cyril.tsui 2 miesięcy temu
rodzic
commit
fc0e858f6d
5 zmienionych plików z 252 dodań i 2 usunięć
  1. +1
    -1
      src/main/java/com/ffii/fpsms/modules/pickOrder/entity/projection/PickOrderInfo.kt
  2. +1
    -1
      src/main/java/com/ffii/fpsms/modules/stock/entity/projection/InventoryInfo.kt
  3. +7
    -0
      src/main/resources/db/changelog/changes/20250617_01_cyril/01_remove_inventory_lot_line_trigger.sql
  4. +120
    -0
      src/main/resources/db/changelog/changes/20250617_01_cyril/02_update_inventory_lot_line_trigger_for_insert.sql
  5. +123
    -0
      src/main/resources/db/changelog/changes/20250617_01_cyril/03_update_inventory_lot_line_trigger_for_update.sql

+ 1
- 1
src/main/java/com/ffii/fpsms/modules/pickOrder/entity/projection/PickOrderInfo.kt Wyświetl plik

@@ -17,7 +17,7 @@ interface PickOrderInfo {
val type: String?
val status: String?

@get:Value("#{target.releasedBy.name}")
@get:Value("#{target.releasedBy?.name}")
val releasedBy: String?
@get:Value("#{target.pickOrderLines?.size() > 0 ? target.pickOrderLines.![new com.ffii.fpsms.modules.pickOrder.entity.projection.PickOrderItemInfo(item.name, item.type)] : null}")
val items: List<PickOrderItemInfo?>?

+ 1
- 1
src/main/java/com/ffii/fpsms/modules/stock/entity/projection/InventoryInfo.kt Wyświetl plik

@@ -11,7 +11,7 @@ interface InventoryInfo{
val name: String?
@get:Value("#{target.item.type}")
val type: String?
@get:Value("#{target.qty / (target.item.itemUoms.^[stockUnit == true && deleted == false]?.ratioN / target.item.itemUoms.^[stockUnit == true && deleted == false]?.ratioD)}")
// @get:Value("#{target.qty / (target.item.itemUoms.^[stockUnit == true && deleted == false]?.ratioN / target.item.itemUoms.^[stockUnit == true && deleted == false]?.ratioD)}")
val qty: BigDecimal?
@get:Value("#{target.item.itemUoms.^[stockUnit == true && deleted == false]?.uom.code}")
val uomCode: String?


+ 7
- 0
src/main/resources/db/changelog/changes/20250617_01_cyril/01_remove_inventory_lot_line_trigger.sql Wyświetl plik

@@ -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`;

+ 120
- 0
src/main/resources/db/changelog/changes/20250617_01_cyril/02_update_inventory_lot_line_trigger_for_insert.sql Wyświetl plik

@@ -0,0 +1,120 @@
-- 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`
(
qty 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` (qty, currencyId, currencyName, uomId, itemId, price)
select coalesce(new.inQty, 0) - coalesce(new.outQty, 0) AS qty,
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, qty, price, currencyId, cpu, cpuUnit, cpm, cpmUnit, uomId, status)
select ti.itemId AS itemId,
ti.qty AS qty,
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.qty, 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.qty = (i.qty + ti.qty),
i.price = ti.price,
i.currencyId = ti.currencyId,
i.cpu = 0,
i.cpuUnit = ti.currencyName,
i.cpm = 0,
i.cpmUnit = ti.currencyName
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;

+ 123
- 0
src/main/resources/db/changelog/changes/20250617_01_cyril/03_update_inventory_lot_line_trigger_for_update.sql Wyświetl plik

@@ -0,0 +1,123 @@
-- 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
(
oldQty decimal(14, 2),
currentQty 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 (oldQty, currentQty, currencyId, currencyName, uomId, itemId, price)
select coalesce(coalesce(old.inQty, 0) - coalesce(old.outQty, 0), 0) as oldQty,
coalesce(coalesce(new.inQty, 0) - coalesce(new.outQty, 0), 0) as currentQty,
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, qty, price, currencyId, cpu, cpuUnit, cpm, cpmUnit, uomId, status)
select ti.itemId as itemId,
ti.currentQty as qty,
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.currentQty, 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.qty = (i.qty - (ti.oldQty - ti.currentQty)),
i.price = ti.price,
i.currencyId = ti.currencyId,
i.cpu = 0,
i.cpuUnit = ti.currencyName,
i.cpm = 0,
i.cpmUnit = ti.currencyName
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;

Ładowanie…
Anuluj
Zapisz