You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

212 lines
7.0 KiB
Plaintext

SELECT prj.Company,
ifsapp.CURRENCY_CODE_API.Get_Currency_Code(prj.COMPANY) AS "Project Currency",
prj.Site,
prj.Project_id,
prj.Name AS "Project Name",
--prj.customer_id,
prj.Date_created AS "Project Date Created",
prj.Program_id,
prj.Category1_id AS "Project Category1",
prj.State AS "Project Status",
act.Activity_seq,
pco.proj_lu_name,
pco.control_category,
CASE
WHEN pol.ORDER_NO IS NOT NULL THEN
pol.ORDER_NO
WHEN invl.PO_REF_Number IS NOT NULL THEN
invl.PO_REF_Number
ELSE
NULL
END AS "Purchase Order",
pol.Line_no AS "Purchase Line",
wo.Wo_no AS "Work Order",
pco.used AS "Project Used",
pco.Actual AS "Project Actual",
pol.state AS State_Purchase,
poi.Receipt_no Purchase_Receipt_No,
poi.qty_invoiced * poi.unit_price_paid AS purchase_invoice_amount,
glq.CURRENCY_CREDIT_AMOUNT AS "GL Currency Credit Amount",
glq.CURRENCY_DEBET_AMOUNT AS "GL Currency Debit Amount",
CASE
WHEN inv.invoice_id IS NOT NULL THEN
inv.Invoice_id
WHEN ptr1.invoice_id IS NOT NULL THEN
ptr1.invoice_id
WHEN invl.invoice_id IS NOT NULL AND
glq.CURRENCY_CREDIT_AMOUNT IS NULL THEN
invl.invoice_id
ELSE
NULL
END AS "Invoice Id",
CASE
WHEN inv.Identity IS NOT NULL THEN
inv.Identity
WHEN invl.Identity IS NOT NULL AND
glq.CURRENCY_CREDIT_AMOUNT IS NULL THEN
invl.Identity
ELSE
NULL
END AS "Supplier Id",
CASE
WHEN inv.IDENTITY IS NOT NULL THEN
ifsapp.Supplier_Info_API.Get_Name(inv.IDENTITY)
WHEN invl.IDENTITY IS NOT NULL THEN
ifsapp.Supplier_Info_API.Get_Name(invl.IDENTITY)
ELSE
NULL
END AS "Supplier Name",
CASE
WHEN inv.Currency IS NOT NULL THEN
inv.CURRENCY
WHEN invl.Currency IS NOT NULL AND
glq.CURRENCY_CREDIT_AMOUNT IS NULL THEN
invl.CURRENCY
ELSE
NULL
END AS "Invoice Currency",
CASE
WHEN inv.STATE IS NOT NULL THEN
inv.STATE
WHEN invl.STATE IS NOT NULL AND glq.CURRENCY_CREDIT_AMOUNT IS NULL THEN
invl.STATE
ELSE
NULL
END AS "Invoice Status",
CASE
WHEN pay.DUE_DATE IS NOT NULL THEN
TO_CHAR(pay.DUE_DATE, 'YYYY-MM-DD')
WHEN payg.DUE_DATE IS NOT NULL AND
glq.CURRENCY_CREDIT_AMOUNT IS NULL then
TO_CHAR(payg.DUE_DATE, 'YYYY-MM-DD')
ELSE
NULL
END AS "Payment Due Date",
CASE
WHEN pay.Payment_date IS NOT NULL THEN
TO_CHAR(pay.Payment_date, 'YYYY-MM-DD')
WHEN payg.Payment_date IS NOT NULL AND
glq.CURRENCY_CREDIT_AMOUNT IS NULL THEN
TO_CHAR(payg.Payment_date, 'YYYY-MM-DD')
ELSE
NULL
END AS "Payment Date",
CASE
WHEN pay.STATE IS NOT NULL THEN
pay.STATE
WHEN payg.STATE IS NOT NULL AND glq.CURRENCY_CREDIT_AMOUNT IS NULL THEN
payg.STATE
ELSE
NULL
END AS "Payment Status",
ptr1.Emp_no AS "Employe Id",
CASE
WHEN inv.voucher_No_ref IS NOT NULL THEN
to_char(inv.voucher_No_ref)
WHEN invl.voucher_No_ref IS NOT NULL THEN
to_char(invl.voucher_No_ref)
ELSE
pco.KeyRef4
END AS "Voucher No",
CASE
WHEN inv.voucher_date_ref IS NOT NULL THEN
inv.voucher_date_ref
WHEN invl.voucher_date_ref IS NOT NULL THEN
invl.voucher_date_ref
ELSE
glq.Voucher_date
END AS "Voucher date",
CASE
WHEN inv.accounting_year_ref IS NOT NULL THEN
inv.accounting_year_ref
WHEN invl.accounting_year_ref IS NOT NULL THEN
invl.accounting_year_ref
ELSE
glq.Accounting_year
END AS "Accounting Year",
CASE
WHEN inv.Accounting_period_ref IS NOT NULL THEN
inv.Accounting_period_ref
WHEN invl.Accounting_period_ref IS NOT NULL THEN
invl.Accounting_period_ref
ELSE
glq.Accounting_period
END AS "Accounting Period1",
pco.keyRef2 AS "Voucher type",
vot.Description AS "Voucher Description",
glq.Accounting_period AS "Accounting Period",
pco.KeyRef1
--pco.KeyRef2,
--pco.KeyRef3,
--pco.KeyRef4,
--pco.KeyRef5
FROM ifsapp.project prj
LEFT JOIN ifsapp.sub_project spr
ON spr.project_id = prj.project_id
LEFT JOIN ifsapp.Activity act
ON act.project_id = spr.project_id
AND act.sub_project_id = spr.sub_project_id
LEFT JOIN ifsapp.PROJECT_CONNECTIONS_OVERVIEW pco
ON pco.project_id = act.project_id
AND pco.Activity_seq = act.ACTIVITY_SEQ
AND pco.activity_no = act.activity_no
LEFT JOIN ifsapp.purchase_order_line_all pol
ON pol.ORDER_NO = pco.keyref1
AND pol.Line_no = pco.keyref2
AND pol.Release_no = pco.keyref3
AND pol.company = prj.company
LEFT JOIN ifsapp.PURCHASE_ORDER_INVOICE poi
ON poi.order_no = pol.order_no
AND poi.line_no = pol.line_no
AND poi.Release_no = pol.Release_no
LEFT JOIN ifsapp.invoice inv
ON inv.Invoice_id = poi.INVOICE_ID
AND inv.company = poi.INVOICE_COMPANY
AND inv.PARTY_TYPE_DB = 'SUPPLIER'
LEFT JOIN ifsapp.GEN_LED_VOUCHER_ROW_UNION_QRY glq
ON to_char(glq.voucher_no) = pco.keyref4
AND glq.voucher_type = pco.KEYREF2
AND to_Char(glq.ACCOUNTING_YEAR) = pco.keyref3
AND glq.company = pco.keyref1
AND glq.row_no = pco.KEYREF5
LEFT JOIN ifsapp.Voucher_type vot
ON vot.Company = glq.Company
AND vot.Voucher_type = glq.Voucher_type
LEFT JOIN ifsapp.invoice invl
ON invl.voucher_no_ref = glq.VOUCHER_NO
AND invl.VOUCHER_TYPE_REF = glq.VOUCHER_TYPE
AND invl.Accounting_year_ref = glq.ACCOUNTING_YEAR
AND invl.ACCOUNTING_PERIOD_REF = glq.ACCOUNTING_PERIOD
AND invl.company = glq.COMPANY
AND invl.PARTY_TYPE_DB = 'SUPPLIER'
LEFT JOIN ifsapp.payment_plan payg
ON payg.company = invl.COMPANY
AND payg.INVOICE_ID = invl.INVOICE_ID
AND payg."IDENTITY" = invl."IDENTITY"
AND payg.PARTY_TYPE_DB = 'SUPPLIER'
LEFT JOIN ifsapp.payment_plan pay
ON pay.company = inv.COMPANY
AND pay.INVOICE_ID = inv.INVOICE_ID
AND pay."IDENTITY" = inv."IDENTITY"
AND pay.PARTY_TYPE_DB = 'SUPPLIER'
LEFT JOIN ifsapp.work_order wo
ON TO_CHAR(wo.wo_no) = pco.keyref1
AND wo.project_no = pco.project_id
AND wo.activity_seq = pco.activity_seq
LEFT JOIN ifsapp.project_transaction ptr1
ON to_char(ptr1.ACCOUNT_DATE, 'YYYYMMDD') = to_char(pco.keyref3)
AND ptr1.project_id = pco.PROJECT_ID
AND ptr1.activity_seq = pco.activity_seq
AND pco.proj_lu_name = 'PT'
WHERE prj.Company = '&Company' --'&[MC--L]Company'
AND prj.Project_id = '&Project_id'
/* AND (pco.used IS NOT NULL OR pco.Actual IS NOT NULL) */