最近用户有个看应收余额的需求,按照会计期间+客户+应收事务上的弹性域 维度出具。
第一版
刚开始想法比较简单,从应收模块穿透到子分类账去取,AR模块跟应收账款余额相关的有三部分
- 应收事务(含标准及贷项发票)
- 收款去核销收入
- 应收事务调整
于是就同通过下面的sql来进行取
SELECT
/*+ leading(l,h) use_hash(l,h) */
CT.ORG_ID,
ct.doc_sequence_value,
CT.BILL_TO_CUSTOMER_ID,
h.accounting_date gl_date,
h.period_name,
l.entered_dr,
l.entered_cr,
l.accounted_dr,
l.accounted_cr,
l.code_combination_id,
ct.attribute1,
ct.attribute2,
'TRANSACTIONS' entity_code,
h.ledger_id,
ct.customer_trx_id bill_id
FROM xla.xla_ae_headers h,
xla.xla_ae_lines l,
xla.xla_events e,
xla.xla_transaction_entities te,
ra_customer_trx_all ct
WHERE h.application_id = l.application_id
AND h.ae_header_id = l.ae_header_id
AND h.application_id = e.application_id
AND h.event_id = e.event_id
AND h.application_id = te.application_id
AND h.entity_id = te.entity_id
AND te.application_id = 222
AND te.entity_code = 'TRANSACTIONS'
AND nvl(te.source_id_int_1, (-99)) = ct.customer_trx_id
AND h.gl_transfer_status_code = 'Y'
UNION ALL
-- 收款、核销、杂项收款
SELECT
/*+ leading(l,h) use_hash(l,h) */
CR.ORG_ID,
cr.doc_sequence_value,
/* hca.cust_account_id,*/
cr.pay_from_customer,
h.accounting_date gl_date,
h.period_name,
l.entered_dr,
l.entered_cr,
l.accounted_dr,
l.accounted_cr,
l.code_combination_id,
cr.attribute1,
cr.attribute2,
'APP',
h.ledger_id,
cr.cash_receipt_id
FROM xla.xla_ae_headers h,
xla.xla_ae_lines l,
xla.xla_events e,
xla.xla_transaction_entities te,
ar_cash_receipts_all cr
WHERE h.application_id = l.application_id
AND h.ae_header_id = l.ae_header_id
AND h.application_id = e.application_id
AND h.event_id = e.event_id
AND h.application_id = te.application_id
AND h.entity_id = te.entity_id
AND te.application_id = 222
AND te.ledger_id = 2022
AND te.entity_code = 'RECEIPTS'
AND nvl(te.source_id_int_1, -99) = cr.cash_receipt_id
AND h.gl_transfer_status_code = 'Y'
UNION ALL
-- ADJUSTMENTS
SELECT /*+ leading(l,h) use_hash(l,h) */
ADJ.ORG_ID,
ct.doc_sequence_value,
ct.bill_to_customer_id,
h.accounting_date gl_date,
h.period_name,
l.entered_dr,
l.entered_cr,
l.accounted_dr,
l.accounted_cr,
l.code_combination_id,
ct.attribute1,
ct.attribute2,
'ADJUSTMENTS',
h.ledger_id,
ct.customer_trx_id
FROM xla.xla_ae_headers h,
xla.xla_ae_lines l,
xla.xla_events e,
xla.xla_transaction_entities te,
ar_adjustments_all adj,
ra_customer_trx_all ct
WHERE h.application_id = l.application_id
AND h.ae_header_id = l.ae_header_id
AND h.application_id = e.application_id
AND h.event_id = e.event_id
AND h.application_id = te.application_id
AND h.entity_id = te.entity_id
AND te.application_id = 222
AND te.entity_code = 'ADJUSTMENTS'
AND nvl(te.source_id_int_1, (-99)) = adj.adjustment_id
AND adj.customer_trx_id = ct.customer_trx_id
AND h.gl_transfer_status_code = 'Y'
初版测试后这个视图是能和总账余额表核对上的,但是用户想要以事务的弹性域维度进行统计,不想要收款上的弹性域,会产生干扰。那只能通过核销表去追溯事务了。
收款和收入的核销是多对多的关系。一笔收入可以被多个收款核销,一笔收款可以去核销多笔收入。
第二版
因为这个地方还需要统计指定期间范围内,借方发生多少,贷方发生多少,刚开始通过核销表上的event_id关联到子分类账的xla.xla_events,然后关联到子分类账上的凭证行,这样就能单独取到借方和贷方发生了,但是因为收款和事务的核销是多对多的关系,一笔收款去核销多个事务处理时,贷方应收账款分类上产生的是一个汇总的分录,关联后产生了重复,导致统计不准确。
只能舍弃子分类账层,从核销表取数了,核销表上status是’APP’表示是核销记录,其中amount_applied 字段是去冲减应收的,放到贷方,但是如果此字段是负数的话,不会产生一个贷方负数的分录,而是产生一个借方正数的分录,于是就加入了一个用case when判断来实现对借贷方赋值的操作,如下为完整sql
SELECT
/*+ leading(l,h) use_hash(l,h) */
CT.ORG_ID,
to_char(ct.doc_sequence_value) doc_sequence_value,
CT.BILL_TO_CUSTOMER_ID,
h.accounting_date gl_date,
h.period_name,
l.accounted_dr,
l.accounted_cr,
l.code_combination_id,
ct.attribute1,
ct.attribute2,
'TRANSACTIONS' ENTITY_CODE,
h.ledger_id,
ct.customer_trx_id
FROM xla.xla_ae_headers h,
xla.xla_ae_lines l,
xla.xla_events e,
xla.xla_transaction_entities te,
ra_customer_trx_all ct
WHERE h.application_id = l.application_id
AND h.ae_header_id = l.ae_header_id
AND h.application_id = e.application_id
AND h.event_id = e.event_id
AND h.application_id = te.application_id
AND h.entity_id = te.entity_id
AND te.application_id = 222
AND te.entity_code = 'TRANSACTIONS'
AND nvl(te.source_id_int_1, (-99)) = ct.customer_trx_id
AND h.gl_transfer_status_code = 'Y'
UNION ALL
-- 核销
SELECT a.org_id,
to_char(t.doc_sequence_value) doc_sequence_value,
t.bill_to_customer_id,
a.gl_date,
substr(to_char(a.gl_date, 'YYYY-MM-DD'), 1, 7) period_name,
CASE
WHEN a.amount_applied < 0 THEN
-a.amount_applied
WHEN a.amount_applied > 0 THEN
0
WHEN a.amount_applied = 0 THEN
0
END accounted_dr,
CASE
WHEN a.amount_applied < 0 THEN
0
WHEN a.amount_applied > 0 THEN
a.amount_applied
WHEN a.amount_applied = 0 THEN
0
END accounted_cr,
a.code_combination_id,
t.attribute1,
t.attribute2,
'APP_RECEIPT',
a.set_of_books_id,
t.customer_trx_id
FROM ar_receivable_applications_all a, ra_customer_trx_all t
WHERE a.applied_customer_trx_id = t.customer_trx_id
AND a.cash_receipt_id IS NOT NULL
AND a.status = 'APP'
UNION ALL
-- ADJUSTMENTS
SELECT /*+ leading(l,h) use_hash(l,h) */
ADJ.ORG_ID,
to_char(ct.doc_sequence_value) doc_sequence_value,
ct.bill_to_customer_id,
h.accounting_date gl_date,
h.period_name,
l.accounted_dr,
l.accounted_cr,
l.code_combination_id,
ct.attribute1,
ct.attribute2,
'ADJUSTMENTS',
h.ledger_id,
ct.customer_trx_id
FROM xla.xla_ae_headers h,
xla.xla_ae_lines l,
xla.xla_events e,
xla.xla_transaction_entities te,
ar_adjustments_all adj,
ra_customer_trx_all ct
WHERE h.application_id = l.application_id
AND h.ae_header_id = l.ae_header_id
AND h.application_id = e.application_id
AND h.event_id = e.event_id
AND h.application_id = te.application_id
AND h.entity_id = te.entity_id
AND te.application_id = 222
AND te.entity_code = 'ADJUSTMENTS'
AND nvl(te.source_id_int_1, (-99)) = adj.adjustment_id
AND adj.customer_trx_id = ct.customer_trx_id
AND h.gl_transfer_status_code = 'Y';
第三版
经过用户核对后,还发现2个问题:
- 贷项和标准发票核销的时候,第2版还是抽的贷项的弹性域,其实应该抽被核销发票的弹性域
- 付款核销用case when 判断会虚增借方和贷方的发生额,导致和实际业务有差异
找了几个单据,发现如下规律:核销表ar_receivable_applications_all中 amount_applied字段:对于贷项去核销标准发票,
则生成如下分录
借-应收账款 -amount_applied
贷-主营收入 --amount_applied
对于收款去核销标准发票则生成如下分类
借: 预付账款 amount_applied
贷: 应收账款 amount_applied
所以改造后sql如下:
SELECT
/*+ leading(l,h) use_hash(l,h) */
CT.ORG_ID,
to_char(ct.doc_sequence_value) doc_sequence_value,
CT.BILL_TO_CUSTOMER_ID,
h.accounting_date gl_date,
h.period_name,
l.accounted_dr,
l.accounted_cr,
l.code_combination_id,
ct.attribute1,
ct.attribute2,
'TRANSACTIONS' ENTITY_CODE,
h.ledger_id,
ct.customer_trx_id,
NULL cash_doc_sequence_value,
ct.attribute6 income_date
FROM xla.xla_ae_headers h,
xla.xla_ae_lines l,
xla.xla_events e,
xla.xla_transaction_entities te,
ra_customer_trx_all ct
WHERE h.application_id = l.application_id
AND h.ae_header_id = l.ae_header_id
AND h.application_id = e.application_id
AND h.event_id = e.event_id
AND h.application_id = te.application_id
AND h.entity_id = te.entity_id
AND te.application_id = 222
AND te.entity_code = 'TRANSACTIONS'
AND nvl(te.source_id_int_1, (-99)) = ct.customer_trx_id
AND h.gl_transfer_status_code = 'Y'
AND NOT EXISTS (SELECT 1
FROM ar_receivable_applications_all a
WHERE a.customer_trx_id = ct.customer_trx_id)
UNION ALL
--贷项
SELECT a.org_id,
to_char(t.doc_sequence_value) doc_sequence_value,
t.bill_to_customer_id,
a.gl_date,
substr(to_char(a.gl_date, 'YYYY-MM-DD'), 1, 7) period_name,
-a.amount_applied accounted_dr,
0 accounted_cr,
a.code_combination_id,
t.attribute1,
t.attribute2,
'APP_CM',
a.set_of_books_id,
t.customer_trx_id,
(SELECT to_char(cash.doc_sequence_value)
FROM ar_cash_receipts_all cash
WHERE cash.cash_receipt_id = a.cash_receipt_id),
t.attribute6 income_date
FROM ar_receivable_applications_all a, ra_customer_trx_all t
WHERE a.Applied_Customer_Trx_Id = t.customer_trx_id
AND a.cash_receipt_id IS NULL
AND A.CUSTOMER_TRX_ID IS NOT NULL
AND a.status = 'APP'
UNION ALL
-- 收款、核销、杂项收款
SELECT a.org_id,
to_char(t.doc_sequence_value) doc_sequence_value,
t.bill_to_customer_id,
a.gl_date,
substr(to_char(a.gl_date, 'YYYY-MM-DD'), 1, 7) period_name,
0 accounted_dr,
a.amount_applied accounted_cr,
a.code_combination_id,
t.attribute1,
t.attribute2,
'APP_RECEIPT',
a.set_of_books_id,
t.customer_trx_id,
(SELECT to_char(cash.doc_sequence_value)
FROM ar_cash_receipts_all cash
WHERE cash.cash_receipt_id = a.cash_receipt_id),
t.attribute6 income_date
FROM ar_receivable_applications_all a, ra_customer_trx_all t /*, ra_cust_trx_types_all ctt*/
WHERE a.applied_customer_trx_id = t.customer_trx_id
AND a.cash_receipt_id IS NOT NULL
AND A.CUSTOMER_TRX_ID IS NULL
AND a.status = 'APP'
UNION ALL
-- ADJUSTMENTS
SELECT /*+ leading(l,h) use_hash(l,h) */
ADJ.ORG_ID,
to_char(ct.doc_sequence_value) doc_sequence_value,
ct.bill_to_customer_id,
h.accounting_date gl_date,
h.period_name,
l.accounted_dr,
l.accounted_cr,
l.code_combination_id,
ct.attribute1,
ct.attribute2,
'ADJUSTMENTS',
h.ledger_id,
ct.customer_trx_id,
NULL,
ct.attribute6 income_date
FROM xla.xla_ae_headers h,
xla.xla_ae_lines l,
xla.xla_events e,
xla.xla_transaction_entities te,
ar_adjustments_all adj,
ra_customer_trx_all ct /*,
ra_cust_trx_types_all ctt*/
WHERE h.application_id = l.application_id
AND h.ae_header_id = l.ae_header_id
AND h.application_id = e.application_id
AND h.event_id = e.event_id
AND h.application_id = te.application_id
AND h.entity_id = te.entity_id
AND te.application_id = 222
AND te.entity_code = 'ADJUSTMENTS'
AND nvl(te.source_id_int_1, (-99)) = adj.adjustment_id
AND adj.customer_trx_id = ct.customer_trx_id
AND h.gl_transfer_status_code = 'Y'
/* AND ct.cust_trx_type_id = ctt.cust_trx_type_id*/
其他
如果不从比较细的粒度统计应收余额不关注借贷发生的话,还可以用如下sql去取:文章来源:https://www.toymoban.com/news/detail-595394.html
FUNCTION get_adjust_amount(p_customer_trx_id NUMBER) RETURN NUMBER IS
l_output NUMBER;
BEGIN
SELECT nvl(SUM(a.amount), 0)
INTO l_output
FROM (SELECT adj.amount
FROM ar_adjustments_all adj
WHERE adj.customer_trx_id = p_customer_trx_id
AND adj.gl_date <= g_end_date
UNION ALL
SELECT ara.amount_applied amount
FROM ar_receivable_applications_all ara
WHERE ara.customer_trx_id = p_customer_trx_id
AND ara.gl_date <= g_end_date
UNION ALL
SELECT -ara.amount_applied amount
FROM ar_receivable_applications_all ara
WHERE ara.applied_customer_trx_id = p_customer_trx_id
AND ara.gl_date <= g_end_date) a;
RETURN l_output;
EXCEPTION
WHEN OTHERS THEN
RETURN 0;
END get_adjust_amount;
通过应收事务上的customer_trx_id字段去关联付款计划ar_payment_schedules_all 表,然后用后者的amount_due_original加上上面函数的值就是应收事务的余额了。文章来源地址https://www.toymoban.com/news/detail-595394.html
到了这里,关于Oracle EBS AR 应收模块取应收余额及期间发生额(事务维度)的文章就介绍完了。如果您还想了解更多内容,请在右上角搜索TOY模板网以前的文章或继续浏览下面的相关文章,希望大家以后多多支持TOY模板网!