refactor: move Bin queries to qb/orm (#28522)
This commit is contained in:
parent
7ff30a4b2b
commit
69a17b9e51
@ -4,6 +4,8 @@
|
|||||||
|
|
||||||
import frappe
|
import frappe
|
||||||
from frappe.model.document import Document
|
from frappe.model.document import Document
|
||||||
|
from frappe.query_builder import Case
|
||||||
|
from frappe.query_builder.functions import Coalesce, Sum
|
||||||
from frappe.utils import flt, nowdate
|
from frappe.utils import flt, nowdate
|
||||||
|
|
||||||
|
|
||||||
@ -19,34 +21,42 @@ class Bin(Document):
|
|||||||
- flt(self.reserved_qty_for_production) - flt(self.reserved_qty_for_sub_contract))
|
- flt(self.reserved_qty_for_production) - flt(self.reserved_qty_for_sub_contract))
|
||||||
|
|
||||||
def get_first_sle(self):
|
def get_first_sle(self):
|
||||||
sle = frappe.db.sql("""
|
sle = frappe.qb.DocType("Stock Ledger Entry")
|
||||||
select * from `tabStock Ledger Entry`
|
first_sle = (
|
||||||
where item_code = %s
|
frappe.qb.from_(sle)
|
||||||
and warehouse = %s
|
.select("*")
|
||||||
order by timestamp(posting_date, posting_time) asc, creation asc
|
.where((sle.item_code == self.item_code) & (sle.warehouse == self.warehouse))
|
||||||
limit 1
|
.orderby(sle.posting_date, sle.posting_time, sle.creation)
|
||||||
""", (self.item_code, self.warehouse), as_dict=1)
|
.limit(1)
|
||||||
return sle and sle[0] or None
|
).run(as_dict=True)
|
||||||
|
|
||||||
|
return first_sle and first_sle[0] or None
|
||||||
|
|
||||||
def update_reserved_qty_for_production(self):
|
def update_reserved_qty_for_production(self):
|
||||||
'''Update qty reserved for production from Production Item tables
|
'''Update qty reserved for production from Production Item tables
|
||||||
in open work orders'''
|
in open work orders'''
|
||||||
self.reserved_qty_for_production = frappe.db.sql('''
|
|
||||||
SELECT
|
wo = frappe.qb.DocType("Work Order")
|
||||||
CASE WHEN ifnull(skip_transfer, 0) = 0 THEN
|
wo_item = frappe.qb.DocType("Work Order Item")
|
||||||
SUM(item.required_qty - item.transferred_qty)
|
|
||||||
ELSE
|
self.reserved_qty_for_production = (
|
||||||
SUM(item.required_qty - item.consumed_qty)
|
frappe.qb
|
||||||
END
|
.from_(wo)
|
||||||
FROM `tabWork Order` pro, `tabWork Order Item` item
|
.from_(wo_item)
|
||||||
WHERE
|
.select(Case()
|
||||||
item.item_code = %s
|
.when(wo.skip_transfer == 0, Sum(wo_item.required_qty - wo_item.transferred_qty))
|
||||||
and item.parent = pro.name
|
.else_(Sum(wo_item.required_qty - wo_item.consumed_qty))
|
||||||
and pro.docstatus = 1
|
)
|
||||||
and item.source_warehouse = %s
|
.where(
|
||||||
and pro.status not in ("Stopped", "Completed")
|
(wo_item.item_code == self.item_code)
|
||||||
and (item.required_qty > item.transferred_qty or item.required_qty > item.consumed_qty)
|
& (wo_item.parent == wo.name)
|
||||||
''', (self.item_code, self.warehouse))[0][0]
|
& (wo.docstatus == 1)
|
||||||
|
& (wo_item.source_warehouse == self.warehouse)
|
||||||
|
& (wo.status.notin(["Stopped", "Completed"]))
|
||||||
|
& ((wo_item.required_qty > wo_item.transferred_qty)
|
||||||
|
| (wo_item.required_qty > wo_item.consumed_qty))
|
||||||
|
)
|
||||||
|
).run()[0][0] or 0.0
|
||||||
|
|
||||||
self.set_projected_qty()
|
self.set_projected_qty()
|
||||||
|
|
||||||
@ -55,36 +65,53 @@ class Bin(Document):
|
|||||||
|
|
||||||
def update_reserved_qty_for_sub_contracting(self):
|
def update_reserved_qty_for_sub_contracting(self):
|
||||||
#reserved qty
|
#reserved qty
|
||||||
reserved_qty_for_sub_contract = frappe.db.sql('''
|
|
||||||
select ifnull(sum(itemsup.required_qty),0)
|
|
||||||
from `tabPurchase Order` po, `tabPurchase Order Item Supplied` itemsup
|
|
||||||
where
|
|
||||||
itemsup.rm_item_code = %s
|
|
||||||
and itemsup.parent = po.name
|
|
||||||
and po.docstatus = 1
|
|
||||||
and po.is_subcontracted = 'Yes'
|
|
||||||
and po.status != 'Closed'
|
|
||||||
and po.per_received < 100
|
|
||||||
and itemsup.reserve_warehouse = %s''', (self.item_code, self.warehouse))[0][0]
|
|
||||||
|
|
||||||
#Get Transferred Entries
|
po = frappe.qb.DocType("Purchase Order")
|
||||||
materials_transferred = frappe.db.sql("""
|
supplied_item = frappe.qb.DocType("Purchase Order Item Supplied")
|
||||||
select
|
|
||||||
ifnull(sum(CASE WHEN se.is_return = 1 THEN (transfer_qty * -1) ELSE transfer_qty END),0)
|
reserved_qty_for_sub_contract = (
|
||||||
from
|
frappe.qb
|
||||||
`tabStock Entry` se, `tabStock Entry Detail` sed, `tabPurchase Order` po
|
.from_(po)
|
||||||
where
|
.from_(supplied_item)
|
||||||
se.docstatus=1
|
.select(Sum(Coalesce(supplied_item.required_qty, 0)))
|
||||||
and se.purpose='Send to Subcontractor'
|
.where(
|
||||||
and ifnull(se.purchase_order, '') !=''
|
(supplied_item.rm_item_code == self.item_code)
|
||||||
and (sed.item_code = %(item)s or sed.original_item = %(item)s)
|
& (po.name == supplied_item.parent)
|
||||||
and se.name = sed.parent
|
& (po.docstatus == 1)
|
||||||
and se.purchase_order = po.name
|
& (po.is_subcontracted == "Yes")
|
||||||
and po.docstatus = 1
|
& (po.status != "Closed")
|
||||||
and po.is_subcontracted = 'Yes'
|
& (po.per_received < 100)
|
||||||
and po.status != 'Closed'
|
& (supplied_item.reserve_warehouse == self.warehouse)
|
||||||
and po.per_received < 100
|
)
|
||||||
""", {'item': self.item_code})[0][0]
|
).run()[0][0] or 0.0
|
||||||
|
|
||||||
|
se = frappe.qb.DocType("Stock Entry")
|
||||||
|
se_item = frappe.qb.DocType("Stock Entry Detail")
|
||||||
|
|
||||||
|
materials_transferred = (
|
||||||
|
frappe.qb
|
||||||
|
.from_(se)
|
||||||
|
.from_(se_item)
|
||||||
|
.from_(po)
|
||||||
|
.select(Sum(
|
||||||
|
Case()
|
||||||
|
.when(se.is_return == 1, se_item.transfer_qty * -1)
|
||||||
|
.else_(se_item.transfer_qty)
|
||||||
|
))
|
||||||
|
.where(
|
||||||
|
(se.docstatus == 1)
|
||||||
|
& (se.purpose == "Send to Subcontractor")
|
||||||
|
& (Coalesce(se.purchase_order, "") != "")
|
||||||
|
& ((se_item.item_code == self.item_code)
|
||||||
|
| (se_item.original_item == self.item_code))
|
||||||
|
& (se.name == se_item.parent)
|
||||||
|
& (po.name == se.purchase_order)
|
||||||
|
& (po.docstatus == 1)
|
||||||
|
& (po.is_subcontracted == "Yes")
|
||||||
|
& (po.status != "Closed")
|
||||||
|
& (po.per_received < 100)
|
||||||
|
)
|
||||||
|
).run()[0][0] or 0.0
|
||||||
|
|
||||||
if reserved_qty_for_sub_contract > materials_transferred:
|
if reserved_qty_for_sub_contract > materials_transferred:
|
||||||
reserved_qty_for_sub_contract = reserved_qty_for_sub_contract - materials_transferred
|
reserved_qty_for_sub_contract = reserved_qty_for_sub_contract - materials_transferred
|
||||||
@ -160,4 +187,4 @@ def update_qty(bin_name, args):
|
|||||||
'indented_qty': indented_qty,
|
'indented_qty': indented_qty,
|
||||||
'planned_qty': planned_qty,
|
'planned_qty': planned_qty,
|
||||||
'projected_qty': projected_qty
|
'projected_qty': projected_qty
|
||||||
})
|
})
|
||||||
|
Loading…
x
Reference in New Issue
Block a user