Skip to content

Commit

Permalink
refactor: if() to CASE WHEN (#31360)
Browse files Browse the repository at this point in the history
* refactor: if() to CASE WHEN

* fix: remove duplicate order by

* fix: remove extraneous table

* style: reformat to black spec

Co-authored-by: Ankush Menat <ankush@frappe.io>
  • Loading branch information
Conor and ankush authored Jun 17, 2022
1 parent a0cab76 commit ea28ed1
Show file tree
Hide file tree
Showing 6 changed files with 28 additions and 28 deletions.
36 changes: 18 additions & 18 deletions erpnext/controllers/queries.py
Original file line number Diff line number Diff line change
Expand Up @@ -29,8 +29,8 @@ def employee_query(doctype, txt, searchfield, start, page_len, filters):
or employee_name like %(txt)s)
{fcond} {mcond}
order by
if(locate(%(_txt)s, name), locate(%(_txt)s, name), 99999),
if(locate(%(_txt)s, employee_name), locate(%(_txt)s, employee_name), 99999),
(case when locate(%(_txt)s, name) > 0 then locate(%(_txt)s, name) else 99999 end),
(case when locate(%(_txt)s, employee_name) > 0 then locate(%(_txt)s, employee_name) else 99999 end),
idx desc,
name, employee_name
limit %(page_len)s offset %(start)s""".format(
Expand Down Expand Up @@ -60,9 +60,9 @@ def lead_query(doctype, txt, searchfield, start, page_len, filters):
or company_name like %(txt)s)
{mcond}
order by
if(locate(%(_txt)s, name), locate(%(_txt)s, name), 99999),
if(locate(%(_txt)s, lead_name), locate(%(_txt)s, lead_name), 99999),
if(locate(%(_txt)s, company_name), locate(%(_txt)s, company_name), 99999),
(case when locate(%(_txt)s, name) > 0 then locate(%(_txt)s, name) else 99999 end),
(case when locate(%(_txt)s, lead_name) > 0 then locate(%(_txt)s, lead_name) else 99999 end),
(case when locate(%(_txt)s, company_name) > 0 then locate(%(_txt)s, company_name) else 99999 end),
idx desc,
name, lead_name
limit %(page_len)s offset %(start)s""".format(
Expand Down Expand Up @@ -96,8 +96,8 @@ def customer_query(doctype, txt, searchfield, start, page_len, filters):
and ({scond}) and disabled=0
{fcond} {mcond}
order by
if(locate(%(_txt)s, name), locate(%(_txt)s, name), 99999),
if(locate(%(_txt)s, customer_name), locate(%(_txt)s, customer_name), 99999),
(case when locate(%(_txt)s, name) > 0 then locate(%(_txt)s, name) else 99999 end),
(case when locate(%(_txt)s, customer_name) > 0 then locate(%(_txt)s, customer_name) else 99999 end),
idx desc,
name, customer_name
limit %(page_len)s offset %(start)s""".format(
Expand Down Expand Up @@ -130,11 +130,11 @@ def supplier_query(doctype, txt, searchfield, start, page_len, filters):
where docstatus < 2
and ({key} like %(txt)s
or supplier_name like %(txt)s) and disabled=0
and (on_hold = 0 or (on_hold = 1 and CURDATE() > release_date))
and (on_hold = 0 or (on_hold = 1 and CURRENT_DATE > release_date))
{mcond}
order by
if(locate(%(_txt)s, name), locate(%(_txt)s, name), 99999),
if(locate(%(_txt)s, supplier_name), locate(%(_txt)s, supplier_name), 99999),
(case when locate(%(_txt)s, name) > 0 then locate(%(_txt)s, name) else 99999 end),
(case when locate(%(_txt)s, supplier_name) > 0 then locate(%(_txt)s, supplier_name) else 99999 end),
idx desc,
name, supplier_name
limit %(page_len)s offset %(start)s""".format(
Expand Down Expand Up @@ -305,15 +305,15 @@ def bom(doctype, txt, searchfield, start, page_len, filters):

return frappe.db.sql(
"""select {fields}
from tabBOM
where tabBOM.docstatus=1
and tabBOM.is_active=1
and tabBOM.`{key}` like %(txt)s
from `tabBOM`
where `tabBOM`.docstatus=1
and `tabBOM`.is_active=1
and `tabBOM`.`{key}` like %(txt)s
{fcond} {mcond}
order by
if(locate(%(_txt)s, name), locate(%(_txt)s, name), 99999),
(case when locate(%(_txt)s, name) > 0 then locate(%(_txt)s, name) else 99999 end),
idx desc, name
limit %(start)s, %(page_len)s """.format(
limit %(page_len)s offset %(start)s""".format(
fields=", ".join(fields),
fcond=get_filters_cond(doctype, filters, conditions).replace("%", "%%"),
mcond=get_match_cond(doctype).replace("%", "%%"),
Expand Down Expand Up @@ -348,8 +348,8 @@ def get_project_name(doctype, txt, searchfield, start, page_len, filters):
`tabProject`.status not in ('Completed', 'Cancelled')
and {cond} {scond} {match_cond}
order by
if(locate(%(_txt)s, name), locate(%(_txt)s, name), 99999),
idx desc,
(case when locate(%(_txt)s, `tabProject`.name) > 0 then locate(%(_txt)s, `tabProject`.name) else 99999 end),
`tabProject`.idx desc,
`tabProject`.name asc
limit {page_len} offset {start}""".format(
fields=", ".join(["`tabProject`.{0}".format(f) for f in fields]),
Expand Down
8 changes: 4 additions & 4 deletions erpnext/controllers/status_updater.py
Original file line number Diff line number Diff line change
Expand Up @@ -443,7 +443,7 @@ def _update_percent_field(self, args, update_modified=True):
"""update `tab%(target_parent_dt)s`
set %(target_parent_field)s = round(
ifnull((select
ifnull(sum(if(abs(%(target_ref_field)s) > abs(%(target_field)s), abs(%(target_field)s), abs(%(target_ref_field)s))), 0)
ifnull(sum(case when abs(%(target_ref_field)s) > abs(%(target_field)s) then abs(%(target_field)s) else abs(%(target_ref_field)s) end), 0)
/ sum(abs(%(target_ref_field)s)) * 100
from `tab%(target_dt)s` where parent='%(name)s' having sum(abs(%(target_ref_field)s)) > 0), 0), 6)
%(update_modified)s
Expand All @@ -455,9 +455,9 @@ def _update_percent_field(self, args, update_modified=True):
if args.get("status_field"):
frappe.db.sql(
"""update `tab%(target_parent_dt)s`
set %(status_field)s = if(%(target_parent_field)s<0.001,
'Not %(keyword)s', if(%(target_parent_field)s>=99.999999,
'Fully %(keyword)s', 'Partly %(keyword)s'))
set %(status_field)s = (case when %(target_parent_field)s<0.001 then 'Not %(keyword)s'
else case when %(target_parent_field)s>=99.999999 then 'Fully %(keyword)s'
else 'Partly %(keyword)s' end end)
where name='%(name)s'"""
% args
)
Expand Down
4 changes: 2 additions & 2 deletions erpnext/payroll/doctype/payroll_entry/payroll_entry.py
Original file line number Diff line number Diff line change
Expand Up @@ -1035,8 +1035,8 @@ def employee_query(doctype, txt, searchfield, start, page_len, filters):
{emp_cond}
{fcond} {mcond}
order by
if(locate(%(_txt)s, name), locate(%(_txt)s, name), 99999),
if(locate(%(_txt)s, employee_name), locate(%(_txt)s, employee_name), 99999),
(case when locate(%(_txt)s, name) > 0 then locate(%(_txt)s, name) else 99999 end),
(case when locate(%(_txt)s, employee_name) > 0 then locate(%(_txt)s, employee_name) else 99999 end),
idx desc,
name, employee_name
limit %(page_len)s offset %(start)s""".format(
Expand Down
4 changes: 2 additions & 2 deletions erpnext/projects/doctype/project/project.py
Original file line number Diff line number Diff line change
Expand Up @@ -387,8 +387,8 @@ def get_users_for_project(doctype, txt, searchfield, start, page_len, filters):
or full_name like %(txt)s)
{fcond} {mcond}
order by
if(locate(%(_txt)s, name), locate(%(_txt)s, name), 99999),
if(locate(%(_txt)s, full_name), locate(%(_txt)s, full_name), 99999),
(case when locate(%(_txt)s, name) > 0 then locate(%(_txt)s, name) else 99999 end),
(case when locate(%(_txt)s, full_name) > 0 then locate(%(_txt)s, full_name) else 99999 end)
idx desc,
name, full_name
limit %(page_len)s offset %(start)s""".format(
Expand Down
2 changes: 1 addition & 1 deletion erpnext/stock/doctype/pick_list/pick_list.py
Original file line number Diff line number Diff line change
Expand Up @@ -699,7 +699,7 @@ def get_pending_work_orders(doctype, txt, searchfield, start, page_length, filte
AND `company` = %(company)s
AND `name` like %(txt)s
ORDER BY
if(locate(%(_txt)s, name), locate(%(_txt)s, name), 99999), name
(case when locate(%(_txt)s, name) > 0 then locate(%(_txt)s, name) else 99999 end) name
LIMIT
%(start)s, %(page_length)s""",
{
Expand Down
2 changes: 1 addition & 1 deletion erpnext/stock/utils.py
Original file line number Diff line number Diff line change
Expand Up @@ -499,7 +499,7 @@ def add_additional_uom_columns(columns, result, include_uom, conversion_factors)

def get_incoming_outgoing_rate_for_cancel(item_code, voucher_type, voucher_no, voucher_detail_no):
outgoing_rate = frappe.db.sql(
"""SELECT abs(stock_value_difference / actual_qty)
"""SELECT CASE WHEN actual_qty = 0 THEN 0 ELSE abs(stock_value_difference / actual_qty) END
FROM `tabStock Ledger Entry`
WHERE voucher_type = %s and voucher_no = %s
and item_code = %s and voucher_detail_no = %s
Expand Down

0 comments on commit ea28ed1

Please sign in to comment.