new function for pl/pgsql
This commit is contained in:
parent
f4c327a789
commit
3ff0f191db
|
@ -1,58 +0,0 @@
|
||||||
/*
|
|
||||||
*This file is part of Adempiere ERP Bazaar
|
|
||||||
*http://www.adempiere.org
|
|
||||||
*
|
|
||||||
*Copyright (C) 2006 Timo Kontro
|
|
||||||
*Copyright (C) 1999-2006 ComPiere, inc
|
|
||||||
*
|
|
||||||
*This program is free software; you can redistribute it and/or
|
|
||||||
*modify it under the terms of the GNU General Public License
|
|
||||||
*as published by the Free Software Foundation; either version 2
|
|
||||||
*of the License, or (at your option) any later version.
|
|
||||||
*
|
|
||||||
*This program is distributed in the hope that it will be useful,
|
|
||||||
*but WITHOUT ANY WARRANTY; without even the implied warranty of
|
|
||||||
*MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
|
|
||||||
*GNU General Public License for more details.
|
|
||||||
*
|
|
||||||
*You should have received a copy of the GNU General Public License
|
|
||||||
*along with this program; if not, write to the Free Software
|
|
||||||
*Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of
|
|
||||||
*/
|
|
||||||
|
|
||||||
SET search_path = adempiere, pg_catalog;
|
|
||||||
|
|
||||||
CREATE OR REPLACE FUNCTION currencybase(
|
|
||||||
IN NUMERIC, -- $1 p_Amount
|
|
||||||
IN INTEGER, -- $2 p_C_CurrencyFrom_ID
|
|
||||||
IN TIMESTAMP WITH TIME ZONE, -- $3 p_ConversionDate
|
|
||||||
IN INTEGER, -- $4 p_AD_Client_ID
|
|
||||||
IN INTEGER -- $5 p_AD_Org_ID
|
|
||||||
) RETURNS NUMERIC
|
|
||||||
AS $$
|
|
||||||
DECLARE
|
|
||||||
currency_to INTEGER;
|
|
||||||
BEGIN
|
|
||||||
IF $1 IS NULL OR $2 IS NULL THEN
|
|
||||||
RETURN NULL;
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
IF $1 = 0 THEN
|
|
||||||
RETURN 0;
|
|
||||||
END IF;
|
|
||||||
/*Finds out org's default currency*/
|
|
||||||
SELECT ac.C_Currency_ID
|
|
||||||
INTO currency_to
|
|
||||||
FROM AD_ClientInfo AS ci
|
|
||||||
INNER JOIN C_AcctSchema AS ac
|
|
||||||
ON (ci.C_AcctSchema1_ID = ac.C_AcctSchema_ID)
|
|
||||||
WHERE ci.AD_Client_ID = $4;
|
|
||||||
IF currency_to IS NULL THEN
|
|
||||||
RETURN NULL;
|
|
||||||
END IF;
|
|
||||||
IF $2 = currency_to THEN
|
|
||||||
RETURN $1;
|
|
||||||
END IF;
|
|
||||||
RETURN currencyconvert($1, $2, currency_to, $3,0,$4,$5);
|
|
||||||
END;
|
|
||||||
$$ LANGUAGE plpgsql;
|
|
|
@ -0,0 +1,51 @@
|
||||||
|
create or replace FUNCTION currencyBase
|
||||||
|
(
|
||||||
|
p_Amount NUMERIC,
|
||||||
|
p_CurFrom_ID NUMERIC,
|
||||||
|
p_ConvDate timestamp with time zone,
|
||||||
|
p_Client_ID NUMERIC,
|
||||||
|
p_Org_ID NUMERIC
|
||||||
|
)
|
||||||
|
RETURNS numeric AS $body$
|
||||||
|
/*************************************************************************
|
||||||
|
* The contents of this file are subject to the Compiere License. You may
|
||||||
|
* obtain a copy of the License at http://www.compiere.org/license.html
|
||||||
|
* Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either
|
||||||
|
* express or implied. See the License for details. Code: Compiere ERP+CRM
|
||||||
|
* Copyright (C) 1999-2001 Jorg Janke, ComPiere, Inc. All Rights Reserved.
|
||||||
|
*
|
||||||
|
* converted to postgreSQL by Karsten Thiemann (Schaeffer AG),
|
||||||
|
* kthiemann@adempiere.org
|
||||||
|
*************************************************************************
|
||||||
|
*
|
||||||
|
***
|
||||||
|
* Title: Convert Amount to Base Currency of Client
|
||||||
|
* Description:
|
||||||
|
* Get CurrencyTo from Client
|
||||||
|
* Returns NULL, if conversion not found
|
||||||
|
* Standard Rounding
|
||||||
|
* Test:
|
||||||
|
* SELECT currencyBase(100,116,null,11,null) FROM AD_System; => 64.72
|
||||||
|
************************************************************************/
|
||||||
|
DECLARE
|
||||||
|
v_CurTo_ID NUMERIC;
|
||||||
|
BEGIN
|
||||||
|
-- Get Currency
|
||||||
|
SELECT MAX(ac.C_Currency_ID)
|
||||||
|
INTO v_CurTo_ID
|
||||||
|
FROM AD_ClientInfo ci, C_AcctSchema ac
|
||||||
|
WHERE ci.C_AcctSchema1_ID=ac.C_AcctSchema_ID
|
||||||
|
AND ci.AD_Client_ID=p_Client_ID;
|
||||||
|
-- Same as Currency_Conversion - if currency/rate not found - return 0
|
||||||
|
IF (v_CurTo_ID IS NULL) THEN
|
||||||
|
RETURN NULL;
|
||||||
|
END IF;
|
||||||
|
-- Same currency
|
||||||
|
IF (p_CurFrom_ID = v_CurTo_ID) THEN
|
||||||
|
RETURN p_Amount;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
RETURN currencyConvert (p_Amount, p_CurFrom_ID, v_CurTo_ID, p_ConvDate, null, p_Client_ID, p_Org_ID);
|
||||||
|
END;
|
||||||
|
|
||||||
|
$body$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,82 @@
|
||||||
|
CREATE OR REPLACE FUNCTION invoiceDiscount
|
||||||
|
(
|
||||||
|
p_C_Invoice_ID NUMERIC,
|
||||||
|
p_paydate timestamp with time zone,
|
||||||
|
p_C_InvoicePaySchedule_ID NUMERIC
|
||||||
|
)
|
||||||
|
RETURNS numeric AS $body$
|
||||||
|
/*************************************************************************
|
||||||
|
* The contents of this file are subject to the Compiere License. You may
|
||||||
|
* obtain a copy of the License at http://www.compiere.org/license.html
|
||||||
|
* Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either
|
||||||
|
* express or implied. See the License for details. Code: Compiere ERP+CRM
|
||||||
|
* Copyright (C) 1999-2001 Jorg Janke, ComPiere, Inc. All Rights Reserved.
|
||||||
|
*
|
||||||
|
* converted to postgreSQL by Karsten Thiemann (Schaeffer AG),
|
||||||
|
* kthiemann@adempiere.org
|
||||||
|
*************************************************************************
|
||||||
|
***
|
||||||
|
* Title: Calculate Payment Discount Amount
|
||||||
|
* Description:
|
||||||
|
* - Calculate discountable amount (i.e. with or without tax)
|
||||||
|
* - Calculate and return payment discount
|
||||||
|
* Test:
|
||||||
|
* select invoiceDiscount(109, now(), 103) from ad_system; => 0
|
||||||
|
************************************************************************/
|
||||||
|
DECLARE
|
||||||
|
v_Amount NUMERIC;
|
||||||
|
v_IsDiscountLineAmt CHAR(1);
|
||||||
|
v_GrandTotal NUMERIC;
|
||||||
|
v_TotalLines NUMERIC;
|
||||||
|
v_C_PaymentTerm_ID NUMERIC(10);
|
||||||
|
v_DocDate timestamp with time zone;
|
||||||
|
v_PayDate timestamp with time zone := now();
|
||||||
|
v_IsPayScheduleValid CHAR(1);
|
||||||
|
|
||||||
|
BEGIN
|
||||||
|
SELECT ci.IsDiscountLineAmt, i.GrandTotal, i.TotalLines,
|
||||||
|
i.C_PaymentTerm_ID, i.DateInvoiced, i.IsPayScheduleValid
|
||||||
|
INTO v_IsDiscountLineAmt, v_GrandTotal, v_TotalLines,
|
||||||
|
v_C_PaymentTerm_ID, v_DocDate, v_IsPayScheduleValid
|
||||||
|
FROM AD_ClientInfo ci, C_Invoice i
|
||||||
|
WHERE ci.AD_Client_ID=i.AD_Client_ID
|
||||||
|
AND i.C_Invoice_ID=p_C_Invoice_ID;
|
||||||
|
|
||||||
|
-- What Amount is the Discount Base?
|
||||||
|
IF (v_IsDiscountLineAmt = 'Y') THEN
|
||||||
|
v_Amount := v_TotalLines;
|
||||||
|
ELSE
|
||||||
|
v_Amount := v_GrandTotal;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Anything to discount?
|
||||||
|
IF (v_Amount = 0) THEN
|
||||||
|
RETURN 0;
|
||||||
|
END IF;
|
||||||
|
IF (p_PayDate IS NOT NULL) THEN
|
||||||
|
v_PayDate := p_PayDate;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Valid Payment Schedule
|
||||||
|
IF (v_IsPayScheduleValid='Y' AND p_C_InvoicePaySchedule_ID > 0) THEN
|
||||||
|
SELECT COALESCE(MAX(DiscountAmt),0)
|
||||||
|
INTO v_Amount
|
||||||
|
FROM C_InvoicePaySchedule
|
||||||
|
WHERE C_InvoicePaySchedule_ID=p_C_InvoicePaySchedule_ID
|
||||||
|
AND DiscountDate <= v_PayDate;
|
||||||
|
--
|
||||||
|
RETURN v_Amount;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- return discount amount
|
||||||
|
RETURN paymentTermDiscount (v_Amount, 0, v_C_PaymentTerm_ID, v_DocDate, p_PayDate);
|
||||||
|
|
||||||
|
-- Most likely if invoice not found
|
||||||
|
EXCEPTION
|
||||||
|
WHEN OTHERS THEN
|
||||||
|
RETURN NULL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
$body$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
|
|
@ -0,0 +1,119 @@
|
||||||
|
CREATE OR REPLACE FUNCTION invoiceOpen
|
||||||
|
(
|
||||||
|
p_C_Invoice_ID IN NUMERIC,
|
||||||
|
p_C_InvoicePaySchedule_ID IN NUMERIC
|
||||||
|
)
|
||||||
|
RETURNS numeric AS $body$
|
||||||
|
/*************************************************************************
|
||||||
|
* The contents of this file are subject to the Compiere License. You may
|
||||||
|
* obtain a copy of the License at http://www.compiere.org/license.html
|
||||||
|
* Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either
|
||||||
|
* express or implied. See the License for details. Code: Compiere ERP+CRM
|
||||||
|
* Copyright (C) 1999-2001 Jorg Janke, ComPiere, Inc. All Rights Reserved.
|
||||||
|
*
|
||||||
|
* converted to postgreSQL by Karsten Thiemann (Schaeffer AG),
|
||||||
|
* kthiemann@adempiere.org
|
||||||
|
*************************************************************************
|
||||||
|
***
|
||||||
|
* Title: Calculate Open Item Amount in Invoice Currency
|
||||||
|
* Description:
|
||||||
|
* Add up total amount open for C_Invoice_ID if no split payment.
|
||||||
|
* Grand Total minus Sum of Allocations in Invoice Currency
|
||||||
|
*
|
||||||
|
* For Split Payments:
|
||||||
|
* Allocate Payments starting from first schedule.
|
||||||
|
* Cannot be used for IsPaid as mutating
|
||||||
|
*
|
||||||
|
* Test:
|
||||||
|
* SELECT C_InvoicePaySchedule_ID, DueAmt FROM C_InvoicePaySchedule WHERE C_Invoice_ID=109 ORDER BY DueDate;
|
||||||
|
* SELECT invoiceOpen (109, null) FROM AD_System; - converted to default client currency
|
||||||
|
* SELECT invoiceOpen (109, 11) FROM AD_System; - converted to default client currency
|
||||||
|
* SELECT invoiceOpen (109, 102) FROM AD_System;
|
||||||
|
* SELECT invoiceOpen (109, 103) FROM AD_System;
|
||||||
|
************************************************************************/
|
||||||
|
DECLARE
|
||||||
|
v_Currency_ID NUMERIC(10);
|
||||||
|
v_TotalOpenAmt NUMERIC := 0;
|
||||||
|
v_PaidAmt NUMERIC := 0;
|
||||||
|
v_Remaining NUMERIC := 0;
|
||||||
|
v_MultiplierAP NUMERIC := 0;
|
||||||
|
v_MultiplierCM NUMERIC := 0;
|
||||||
|
v_Temp NUMERIC := 0;
|
||||||
|
ar RECORD;
|
||||||
|
s RECORD;
|
||||||
|
|
||||||
|
BEGIN
|
||||||
|
-- Get Currency
|
||||||
|
BEGIN
|
||||||
|
SELECT MAX(C_Currency_ID), SUM(GrandTotal), MAX(MultiplierAP), MAX(Multiplier)
|
||||||
|
INTO v_Currency_ID, v_TotalOpenAmt, v_MultiplierAP, v_MultiplierCM
|
||||||
|
FROM C_Invoice_v -- corrected for CM / Split Payment
|
||||||
|
WHERE C_Invoice_ID = p_C_Invoice_ID;
|
||||||
|
EXCEPTION -- Invoice in draft form
|
||||||
|
WHEN OTHERS THEN
|
||||||
|
RAISE NOTICE 'InvoiceOpen - %', SQLERRM;
|
||||||
|
RETURN NULL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
-- Calculate Allocated Amount
|
||||||
|
FOR ar IN
|
||||||
|
SELECT a.AD_Client_ID, a.AD_Org_ID,
|
||||||
|
al.Amount, al.DiscountAmt, al.WriteOffAmt,
|
||||||
|
a.C_Currency_ID, a.DateTrx
|
||||||
|
FROM C_AllocationLine al
|
||||||
|
INNER JOIN C_AllocationHdr a ON (al.C_AllocationHdr_ID=a.C_AllocationHdr_ID)
|
||||||
|
WHERE al.C_Invoice_ID = p_C_Invoice_ID
|
||||||
|
AND a.IsActive='Y'
|
||||||
|
LOOP
|
||||||
|
v_Temp := ar.Amount + ar.DisCountAmt + ar.WriteOffAmt;
|
||||||
|
v_PaidAmt := v_PaidAmt
|
||||||
|
-- Allocation
|
||||||
|
+ currencyConvert(v_Temp * v_MultiplierAP,
|
||||||
|
ar.C_Currency_ID, v_Currency_ID, ar.DateTrx, null, ar.AD_Client_ID, ar.AD_Org_ID);
|
||||||
|
RAISE NOTICE ' PaidAmt=% , Allocation= % * %', v_PaidAmt, v_Temp, v_MultiplierAP;
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
-- Do we have a Payment Schedule ?
|
||||||
|
IF (p_C_InvoicePaySchedule_ID > 0) THEN -- if not valid = lists invoice amount
|
||||||
|
v_Remaining := v_PaidAmt;
|
||||||
|
FOR s IN
|
||||||
|
SELECT C_InvoicePaySchedule_ID, DueAmt
|
||||||
|
FROM C_InvoicePaySchedule
|
||||||
|
WHERE C_Invoice_ID = p_C_Invoice_ID
|
||||||
|
AND IsValid='Y'
|
||||||
|
ORDER BY DueDate
|
||||||
|
LOOP
|
||||||
|
IF (s.C_InvoicePaySchedule_ID = p_C_InvoicePaySchedule_ID) THEN
|
||||||
|
v_TotalOpenAmt := (s.DueAmt*v_MultiplierCM) - v_Remaining;
|
||||||
|
IF (s.DueAmt - v_Remaining < 0) THEN
|
||||||
|
v_TotalOpenAmt := 0;
|
||||||
|
END IF;
|
||||||
|
ELSE -- calculate amount, which can be allocated to next schedule
|
||||||
|
v_Remaining := v_Remaining - s.DueAmt;
|
||||||
|
IF (v_Remaining < 0) THEN
|
||||||
|
v_Remaining := 0;
|
||||||
|
END IF;
|
||||||
|
END IF;
|
||||||
|
END LOOP;
|
||||||
|
ELSE
|
||||||
|
v_TotalOpenAmt := v_TotalOpenAmt - v_PaidAmt;
|
||||||
|
END IF;
|
||||||
|
-- RAISE NOTICE '== Total=' || v_TotalOpenAmt;
|
||||||
|
|
||||||
|
-- Ignore Rounding
|
||||||
|
IF (v_TotalOpenAmt BETWEEN -0.00999 AND 0.00999) THEN
|
||||||
|
v_TotalOpenAmt := 0;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Round to penny
|
||||||
|
v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), 2);
|
||||||
|
RETURN v_TotalOpenAmt;
|
||||||
|
END;
|
||||||
|
|
||||||
|
$body$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -0,0 +1,64 @@
|
||||||
|
CREATE OR REPLACE FUNCTION invoicePaid
|
||||||
|
(
|
||||||
|
p_C_Invoice_ID NUMERIC,
|
||||||
|
p_C_Currency_ID NUMERIC,
|
||||||
|
p_MultiplierAP NUMERIC -- DEFAULT 1
|
||||||
|
)
|
||||||
|
RETURNS numeric AS $body$
|
||||||
|
/*************************************************************************
|
||||||
|
* The contents of this file are subject to the Compiere License. You may
|
||||||
|
* obtain a copy of the License at http://www.compiere.org/license.html
|
||||||
|
* Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either
|
||||||
|
* express or implied. See the License for details. Code: Compiere ERP+CRM
|
||||||
|
* Copyright (C) 1999-2001 Jorg Janke, ComPiere, Inc. All Rights Reserved.
|
||||||
|
*
|
||||||
|
* converted to postgreSQL by Karsten Thiemann (Schaeffer AG),
|
||||||
|
* kthiemann@adempiere.org
|
||||||
|
*************************************************************************
|
||||||
|
***
|
||||||
|
* Title: Calculate Paid/Allocated amount in Currency
|
||||||
|
* Description:
|
||||||
|
* Add up total amount paid for for C_Invoice_ID.
|
||||||
|
* Split Payments are ignored.
|
||||||
|
* all allocation amounts converted to invoice C_Currency_ID
|
||||||
|
* round it to the nearest cent
|
||||||
|
* and adjust for CreditMemos by using C_Invoice_v
|
||||||
|
* and for Payments with the multiplierAP (-1, 1)
|
||||||
|
*
|
||||||
|
*
|
||||||
|
* Test:
|
||||||
|
SELECT C_Invoice_ID, IsPaid, IsSOTrx, GrandTotal,
|
||||||
|
invoicePaid (C_Invoice_ID, C_Currency_ID, MultiplierAP)
|
||||||
|
FROM C_Invoice_v;
|
||||||
|
*
|
||||||
|
************************************************************************/
|
||||||
|
DECLARE
|
||||||
|
v_MultiplierAP NUMERIC := 1;
|
||||||
|
v_PaymentAmt NUMERIC := 0;
|
||||||
|
ar RECORD;
|
||||||
|
|
||||||
|
BEGIN
|
||||||
|
-- Default
|
||||||
|
IF (p_MultiplierAP IS NOT NULL) THEN
|
||||||
|
v_MultiplierAP := p_MultiplierAP;
|
||||||
|
END IF;
|
||||||
|
-- Calculate Allocated Amount
|
||||||
|
FOR ar IN
|
||||||
|
SELECT a.AD_Client_ID, a.AD_Org_ID,
|
||||||
|
al.Amount, al.DiscountAmt, al.WriteOffAmt,
|
||||||
|
a.C_Currency_ID, a.DateTrx
|
||||||
|
FROM C_AllocationLine al
|
||||||
|
INNER JOIN C_AllocationHdr a ON (al.C_AllocationHdr_ID=a.C_AllocationHdr_ID)
|
||||||
|
WHERE al.C_Invoice_ID = p_C_Invoice_ID
|
||||||
|
AND a.IsActive='Y'
|
||||||
|
LOOP
|
||||||
|
v_PaymentAmt := v_PaymentAmt
|
||||||
|
+ currencyConvert(ar.Amount + ar.DisCountAmt + ar.WriteOffAmt,
|
||||||
|
ar.C_Currency_ID, p_C_Currency_ID, ar.DateTrx, null, ar.AD_Client_ID, ar.AD_Org_ID);
|
||||||
|
END LOOP;
|
||||||
|
--
|
||||||
|
RETURN ROUND(COALESCE(v_PaymentAmt,0), 2) * v_MultiplierAP;
|
||||||
|
END;
|
||||||
|
|
||||||
|
$body$ LANGUAGE plpgsql;
|
||||||
|
|
|
@ -0,0 +1,63 @@
|
||||||
|
|
||||||
|
create or replace FUNCTION paymentAllocated
|
||||||
|
(
|
||||||
|
p_C_Payment_ID IN NUMERIC,
|
||||||
|
p_C_Currency_ID IN NUMERIC
|
||||||
|
)
|
||||||
|
RETURNS NUMERIC AS $body$
|
||||||
|
/*************************************************************************
|
||||||
|
* The contents of this file are subject to the Compiere License. You may
|
||||||
|
* obtain a copy of the License at http://www.compiere.org/license.html
|
||||||
|
* Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either
|
||||||
|
* express or implied. See the License for details. Code: Compiere ERP+CRM
|
||||||
|
* Copyright (C) 1999-2001 Jorg Janke, ComPiere, Inc. All Rights Reserved.
|
||||||
|
*
|
||||||
|
* converted to postgreSQL by Karsten Thiemann (Schaeffer AG),
|
||||||
|
* kthiemann@adempiere.org
|
||||||
|
*************************************************************************
|
||||||
|
* Title: Calculate Allocated Payment Amount in Payment Currency
|
||||||
|
* Description:
|
||||||
|
--
|
||||||
|
SELECT paymentAllocated(C_Payment_ID,C_Currency_ID), PayAmt, IsAllocated
|
||||||
|
FROM C_Payment_v
|
||||||
|
WHERE C_Payment_ID<1000000;
|
||||||
|
--
|
||||||
|
UPDATE C_Payment_v
|
||||||
|
SET IsAllocated=CASE WHEN paymentAllocated(C_Payment_ID, C_Currency_ID)=PayAmt THEN 'Y' ELSE 'N' END
|
||||||
|
WHERE C_Payment_ID>=1000000;
|
||||||
|
|
||||||
|
************************************************************************/
|
||||||
|
DECLARE
|
||||||
|
v_AllocatedAmt NUMERIC := 0;
|
||||||
|
v_PayAmt NUMERIC;
|
||||||
|
r RECORD;
|
||||||
|
BEGIN
|
||||||
|
-- Charge - nothing available
|
||||||
|
SELECT
|
||||||
|
INTO v_PayAmt MAX(PayAmt)
|
||||||
|
FROM C_Payment
|
||||||
|
WHERE C_Payment_ID=p_C_Payment_ID AND C_Charge_ID > 0;
|
||||||
|
|
||||||
|
IF (v_PayAmt IS NOT NULL) THEN
|
||||||
|
RETURN 0;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Calculate Allocated Amount
|
||||||
|
FOR r IN
|
||||||
|
SELECT a.AD_Client_ID, a.AD_Org_ID, al.Amount, a.C_Currency_ID, a.DateTrx
|
||||||
|
FROM C_AllocationLine al
|
||||||
|
INNER JOIN C_AllocationHdr a ON (al.C_AllocationHdr_ID=a.C_AllocationHdr_ID)
|
||||||
|
WHERE al.C_Payment_ID = p_C_Payment_ID
|
||||||
|
AND a.IsActive='Y'
|
||||||
|
LOOP
|
||||||
|
v_AllocatedAmt := v_AllocatedAmt
|
||||||
|
+ currencyConvert(r.Amount, r.C_Currency_ID, p_C_Currency_ID, r.DateTrx, null, r.AD_Client_ID, r.AD_Org_ID);
|
||||||
|
END LOOP;
|
||||||
|
-- Round to penny
|
||||||
|
v_AllocatedAmt := ROUND(COALESCE(v_AllocatedAmt,0), 2);
|
||||||
|
RETURN v_AllocatedAmt;
|
||||||
|
END;
|
||||||
|
|
||||||
|
$body$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
|
|
@ -0,0 +1,66 @@
|
||||||
|
create or replace FUNCTION paymentAvailable
|
||||||
|
(
|
||||||
|
p_C_Payment_ID IN NUMERIC
|
||||||
|
)
|
||||||
|
RETURNS NUMERIC AS $body$
|
||||||
|
/*************************************************************************
|
||||||
|
* The contents of this file are subject to the Compiere License. You may
|
||||||
|
* obtain a copy of the License at http://www.compiere.org/license.html
|
||||||
|
* Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either
|
||||||
|
* express or implied. See the License for details. Code: Compiere ERP+CRM
|
||||||
|
* Copyright (C) 1999-2001 Jorg Janke, ComPiere, Inc. All Rights Reserved.
|
||||||
|
*
|
||||||
|
* converted to postgreSQL by Karsten Thiemann (Schaeffer AG),
|
||||||
|
* kthiemann@adempiere.org
|
||||||
|
*************************************************************************
|
||||||
|
* Title: Calculate Available Payment Amount in Payment Currency
|
||||||
|
* Description:
|
||||||
|
* similar to C_Invoice_Open
|
||||||
|
************************************************************************/
|
||||||
|
DECLARE
|
||||||
|
v_Currency_ID NUMERIC(10);
|
||||||
|
v_AvailableAmt NUMERIC := 0;
|
||||||
|
v_IsReceipt C_Payment.IsReceipt%TYPE;
|
||||||
|
v_Amt NUMERIC := 0;
|
||||||
|
r RECORD;
|
||||||
|
|
||||||
|
BEGIN
|
||||||
|
-- Charge - fully allocated
|
||||||
|
SELECT MAX(PayAmt)
|
||||||
|
INTO v_Amt
|
||||||
|
FROM C_Payment
|
||||||
|
WHERE C_Payment_ID=p_C_Payment_ID AND C_Charge_ID > 0;
|
||||||
|
IF (v_Amt IS NOT NULL) THEN
|
||||||
|
RETURN v_Amt;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Get Currency
|
||||||
|
SELECT C_Currency_ID, PayAmt, IsReceipt
|
||||||
|
INTO v_Currency_ID, v_AvailableAmt, v_IsReceipt
|
||||||
|
FROM C_Payment_v -- corrected for AP/AR
|
||||||
|
WHERE C_Payment_ID = p_C_Payment_ID;
|
||||||
|
-- DBMS_OUTPUT.PUT_LINE('== C_Payment_ID=' || p_C_Payment_ID || ', PayAmt=' || v_AvailableAmt || ', Receipt=' || v_IsReceipt);
|
||||||
|
|
||||||
|
-- Calculate Allocated Amount
|
||||||
|
FOR r IN
|
||||||
|
SELECT a.AD_Client_ID, a.AD_Org_ID, al.Amount, a.C_Currency_ID, a.DateTrx
|
||||||
|
FROM C_AllocationLine al
|
||||||
|
INNER JOIN C_AllocationHdr a ON (al.C_AllocationHdr_ID=a.C_AllocationHdr_ID)
|
||||||
|
WHERE al.C_Payment_ID = p_C_Payment_ID
|
||||||
|
AND a.IsActive='Y'
|
||||||
|
LOOP
|
||||||
|
v_Amt := currencyConvert(r.Amount, r.C_Currency_ID, v_Currency_ID, r.DateTrx, null, r.AD_Client_ID, r.AD_Org_ID);
|
||||||
|
v_AvailableAmt := v_AvailableAmt - v_Amt;
|
||||||
|
-- DBMS_OUTPUT.PUT_LINE(' Allocation=' || a.Amount || ' - Available=' || v_AvailableAmt);
|
||||||
|
END LOOP;
|
||||||
|
-- Ignore Rounding
|
||||||
|
IF (v_AvailableAmt BETWEEN -0.00999 AND 0.00999) THEN
|
||||||
|
v_AvailableAmt := 0;
|
||||||
|
END IF;
|
||||||
|
-- Round to penny
|
||||||
|
v_AvailableAmt := ROUND(COALESCE(v_AvailableAmt,0), 2);
|
||||||
|
RETURN v_AvailableAmt;
|
||||||
|
END;
|
||||||
|
|
||||||
|
$body$ LANGUAGE plpgsql;
|
||||||
|
|
|
@ -0,0 +1,55 @@
|
||||||
|
CREATE OR REPLACE FUNCTION nextid(
|
||||||
|
p_AD_Sequence_ID IN INTEGER,
|
||||||
|
p_System IN VARCHAR,
|
||||||
|
o_NextID OUT INTEGER
|
||||||
|
)
|
||||||
|
RETURNS INTEGER AS $body$
|
||||||
|
/*************************************************************************
|
||||||
|
* The contents of this file are subject to the Compiere License. You may
|
||||||
|
* obtain a copy of the License at http://www.compiere.org/license.html
|
||||||
|
* Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either
|
||||||
|
* express or implied. See the License for details. Code: Compiere ERP+CRM
|
||||||
|
* Copyright (C) 1999-2005 Jorg Janke, ComPiere, Inc. All Rights Reserved.
|
||||||
|
*
|
||||||
|
* converted to postgreSQL by Karsten Thiemann (Schaeffer AG),
|
||||||
|
* kthiemann@adempiere.org
|
||||||
|
*************************************************************************
|
||||||
|
***
|
||||||
|
* Title: Get Next ID - no Commit
|
||||||
|
* Description: Returns the next id of the sequence.
|
||||||
|
* Test:
|
||||||
|
* select * from nextid((select ad_sequence_id from ad_sequence where name = 'Test')::Integer, 'Y'::Varchar);
|
||||||
|
*
|
||||||
|
************************************************************************/
|
||||||
|
|
||||||
|
BEGIN
|
||||||
|
IF (p_System = 'Y') THEN
|
||||||
|
RAISE NOTICE 'system';
|
||||||
|
SELECT CurrentNextSys
|
||||||
|
INTO o_NextID
|
||||||
|
FROM AD_Sequence
|
||||||
|
WHERE AD_Sequence_ID=p_AD_Sequence_ID;
|
||||||
|
--
|
||||||
|
UPDATE AD_Sequence
|
||||||
|
SET CurrentNextSys = CurrentNextSys + IncrementNo
|
||||||
|
WHERE AD_Sequence_ID=p_AD_Sequence_ID;
|
||||||
|
ELSE
|
||||||
|
SELECT CurrentNext
|
||||||
|
INTO o_NextID
|
||||||
|
FROM AD_Sequence
|
||||||
|
WHERE AD_Sequence_ID=p_AD_Sequence_ID;
|
||||||
|
--
|
||||||
|
UPDATE AD_Sequence
|
||||||
|
SET CurrentNext = CurrentNext + IncrementNo
|
||||||
|
WHERE AD_Sequence_ID=p_AD_Sequence_ID;
|
||||||
|
END IF;
|
||||||
|
--
|
||||||
|
EXCEPTION
|
||||||
|
WHEN OTHERS THEN
|
||||||
|
RAISE NOTICE '%',SQLERRM;
|
||||||
|
END;
|
||||||
|
|
||||||
|
$body$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
|
||||||
|
|
Loading…
Reference in New Issue