Feature request: [ 1614574 ] Port sqlj functions to pl/pgsql

Functions from org.compiere.sql.PaymentTerm

Warning: Untested and badly documented.
This commit is contained in:
kontro 2006-12-23 21:10:10 +00:00
parent f7dcef1009
commit 8457f75c4f
3 changed files with 213 additions and 0 deletions

View File

@ -0,0 +1,101 @@
/*
*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 paymenttermdiscount
(
NUMERIC, --$1 amount
IN INTEGER, --$2 Currency ID
IN INTEGER, --$3 Payment term id
IN TIMESTAMP WITH TIME ZONE, --$4 document date
IN TIMESTAMP WITH TIME ZONE --$5 payment date
)
RETURNS NUMERIC AS $$
DECLARE
discount NUMERIC;
discount1 NUMERIC;
discount2 NUMERIC;
discount1date DATE;
discount2date DATE;
add1date NUMERIC;
add2date NUMERIC;
isnextbd BOOLEAN;
payDate DATE;
BEGIN
IF $1 IS NULL OR $2 IS NULL OR $4 IS NULL THEN
RETURN 0;
END IF;
IF $5 IS NULL THEN
payDate := current_date;
ELSE
payDate := CAST($5 AS DATE);
END IF;
discount1date := CAST($4 AS Date);
discount2date := discount1date;
SELECT
(discount1date + t.discountdays + t.gracedays),
(discount2date + t.discountdays2 + t.gracedays),
t.discount,
t.discount2,
(t.isnextbusinessday = 'Y')
INTO
discount1date,
discount2date,
discount1,
discount2,
isnextbd
FROM c_paymentterm AS t
WHERE c_paymentterm_id=p_C_PaymentTerm_ID;
--this checks only weekdays should check holidays too
IF isnextbd THEN
SELECT
CASE EXTRACT(DOW FROM discount1date)
WHEN 0 THEN (discount1date + 1) --sunday => monday
WHEN 6 THEN (discount1date + 2) --saturday => monday
ELSE discount1date
END
INTO discount1date;
SELECT
CASE extract(DOW FROM discount2date)
WHEN 0 THEN (discount2date + 1)
WHEN 6 THEN (discount2date + 2)
ELSE discount2date
END
INTO discount2date;
END IF;
IF payDate < discount1date THEN --Would <= be better than = ?
RETURN currencyround(((p_amount * discount1) / 100), $2, FALSE);
ELSIF payDate < discount2date THEN
RETURN currencyround(((p_amount * discount2) / 100), $2, FALSE);
ELSE
RETURN 0;
END IF;
END;
$$ LANGUAGE plpgsql;

View File

@ -0,0 +1,70 @@
/*
*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 paymenttermduedate(
IN INTEGER, -- $1 payment term id
IN TIMESTAMP WITH TIME ZONE -- $2 document date
) RETURNS TIMESTAMP WITH TIME ZONE AS
$$
DECLARE
due_date TIMESTAMP WITH TIME ZONE;
fixed BOOLEAN;
monthOffset INTEGER;
monthCutOff INTEGER;
netDays INTEGER;
monthDay INTEGER;
BEGIN
IF $1 IS NULL OR $2 IS NULL THEN
RETURN 0;
END IF;
SELECT (t.isDueFixed = 'Y'), t.fixMonthOffset, t.fixMonthCutoff,
t.netdays, t.FixMonthDay
INTO fixed, monthOffset, monthCutOff, netDays, monthDay
FROM C_PaymentTerm AS t WHERE t.C_PaymentTerm_ID = $1;
IF fixed THEN
--we check if montCutOff is bigger than number of days in month.
IF monthCutOff > 28 THEN -- if smaller than days in february no need for further checks.
-- montCutOff should not be greater than number of days in month.
monthCutOff := LEAST(
EXTRACT(DAY FROM (date_trunc('month', $2) + INTERVAL '1 month' - INTERVAL '1 day'))
,monthCutOff);
END IF;
IF monthCutOff < EXTRACT(DAY FROM $2) THEN
monthOffset := COALESCE(monthOffset,0) + 1;
END IF;
due_date := date_trunc('month', $2) + (INTERVAL '1 month' * monthOffset);
IF monthDay > 28 THEN
--monthDay should not be greater than number of days in month.
monthDay := LEAST(
EXTRACT(DAY FROM (due_date + INTERVAL '1 month' - INTERVAL '1 days'))
,monthDay);
END IF;
due_date := due_date + INTERVAL '1 day' * (monthDay -1);
ELSE
due_date := $2 + (INTERVAL '1 day' * netDays);
END IF;
RETURN due_date;
END;
$$ LANGUAGE plpgsql;

View File

@ -0,0 +1,42 @@
/*
*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 paymenttermduedays(
IN INTEGER, -- $1 payment term id
IN TIMESTAMP WITH TIME ZONE, -- $2 document date
IN TIMESTAMP WITH TIME ZONE -- $3 paydate
) RETURNS INTEGER AS
$$
DECLARE
due_date TIMESTAMP WITH TIME ZONE;
BEGIN
due_date := paymenttermduedate($1,$2);
IF due_date IS NULL THEN
RETURN 0;
END IF;
RETURN CAST(EXTRACT(DAY FROM (due_date - $3)) AS INTEGER);
END;
$$ LANGUAGE plpgsql;