131 lines
4.4 KiB
SQL
131 lines
4.4 KiB
SQL
--
|
|
-- [ 1721252 ] XE: paymentTermDiscount not using C_NonBusinessDay
|
|
-- http://sourceforge.net/tracker/?func=detail&atid=879332&aid=1721252&group_id=176962
|
|
--
|
|
-- Run *ONLY* if you are using Oracle XE
|
|
--
|
|
|
|
create or replace
|
|
function nextBusinessDay
|
|
(
|
|
p_Date in date,
|
|
p_AD_Client_ID in number
|
|
)
|
|
return date
|
|
/**
|
|
*This file is part of Adempiere ERP Bazaar
|
|
*http://www.adempiere.org
|
|
*
|
|
*Copyright (C) 2007 Teo Sarca
|
|
*
|
|
*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
|
|
*/
|
|
as
|
|
v_nextDate date := TRUNC(p_Date);
|
|
v_offset number := 0;
|
|
v_Saturday number := TO_CHAR(TO_DATE('2000-01-01', 'YYYY-MM-DD'), 'D');
|
|
v_Sunday number := (case when v_Saturday = 7 then 1 else v_Saturday + 1 end);
|
|
v_isHoliday boolean := true;
|
|
|
|
cursor nonBusinessDays(pp_Date date) is
|
|
select nbd.Date1 from C_NonBusinessDay nbd
|
|
where AD_Client_ID=p_AD_Client_ID and IsActive ='Y' and Date1>=pp_Date
|
|
order by Date1;
|
|
begin
|
|
v_isHoliday := true;
|
|
loop
|
|
SELECT DECODE(TO_CHAR(v_nextDate,'D'), v_Saturday, 2, v_Sunday, 1, 0) INTO v_offset FROM DUAL;
|
|
v_nextDate := TRUNC(v_nextDate + v_offset);
|
|
v_isHoliday := false;
|
|
for nbd in nonBusinessDays(v_nextDate) loop
|
|
exit when v_nextDate <> TRUNC(nbd.Date1);
|
|
v_nextDate := v_nextDate + 1;
|
|
v_isHoliday := true;
|
|
end loop;
|
|
exit when v_isHoliday=false;
|
|
end loop;
|
|
--
|
|
return v_nextDate;
|
|
end nextBusinessDay;
|
|
/
|
|
|
|
CREATE OR REPLACE FUNCTION paymentTermDiscount
|
|
(
|
|
Amount IN NUMBER,
|
|
Currency_ID IN NUMBER,
|
|
PaymentTerm_ID IN NUMBER,
|
|
DocDate IN DATE,
|
|
PayDate IN DATE
|
|
)
|
|
RETURN NUMBER
|
|
/*************************************************************************
|
|
* 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.
|
|
*************************************************************************
|
|
* $Id: C_PaymentTerm_Discount.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $
|
|
***
|
|
* Title: Calculate Discount
|
|
* Description:
|
|
* Calculate the allowable Discount Amount of the Payment Term
|
|
*
|
|
* Test: SELECT C_PaymentTerm_Discount(17777, 103, '10-DEC-1999') FROM DUAL
|
|
************************************************************************/
|
|
|
|
AS
|
|
Discount NUMBER := 0;
|
|
CURSOR Cur_PT IS
|
|
SELECT *
|
|
FROM C_PaymentTerm
|
|
WHERE C_PaymentTerm_ID = PaymentTerm_ID;
|
|
Discount1Date DATE;
|
|
Discount2Date DATE;
|
|
Add1Date NUMBER := 0;
|
|
Add2Date NUMBER := 0;
|
|
BEGIN
|
|
-- No Data - No Discount
|
|
IF (Amount IS NULL OR PaymentTerm_ID IS NULL OR DocDate IS NULL) THEN
|
|
RETURN 0;
|
|
END IF;
|
|
|
|
FOR p IN Cur_PT LOOP -- for convineance only
|
|
-- DBMS_OUTPUT.PUT_LINE(p.Name || ' - Doc = ' || TO_CHAR(DocDate));
|
|
Discount1Date := TRUNC(DocDate + p.DiscountDays + p.GraceDays);
|
|
Discount2Date := TRUNC(DocDate + p.DiscountDays2 + p.GraceDays);
|
|
|
|
-- Next Business Day
|
|
IF (p.IsNextBusinessDay='Y') THEN
|
|
Discount1Date := nextBusinessDay(Discount1Date, p.AD_Client_ID);
|
|
Discount2Date := nextBusinessDay(Discount2Date, p.AD_Client_ID);
|
|
END IF;
|
|
|
|
-- Discount 1
|
|
IF (Discount1Date >= TRUNC(PayDate)) THEN
|
|
-- DBMS_OUTPUT.PUT_LINE('Discount 1 ' || TO_CHAR(Discount1Date) || ' ' || p.Discount);
|
|
Discount := Amount * p.Discount / 100;
|
|
-- Discount 2
|
|
ELSIF (Discount2Date >= TRUNC(PayDate)) THEN
|
|
-- DBMS_OUTPUT.PUT_LINE('Discount 2 ' || TO_CHAR(Discount2Date) || ' ' || p.Discount2);
|
|
Discount := Amount * p.Discount2 / 100;
|
|
END IF;
|
|
END LOOP;
|
|
--
|
|
RETURN ROUND(NVL(Discount,0), 2); -- fixed rounding
|
|
END paymentTermDiscount;
|
|
/
|
|
|