Including pl/pgsql function

This commit is contained in:
vpj-cd 2008-10-25 17:28:50 +00:00
parent 75026b2c0a
commit f4c327a789
10 changed files with 695 additions and 648 deletions

View File

@ -1,69 +1,41 @@
/*
*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
*/
CREATE OR REPLACE FUNCTION acctBalance(p_Account_ID numeric, p_AmtDr numeric, p_AmtCr numeric) RETURNS numeric AS $body$
DECLARE
v_balance NUMERIC;
v_AccountType C_ElementValue.AccountType%TYPE;
v_AccountSign C_ElementValue.AccountSign%TYPE;
BEGIN
v_balance := p_AmtDr - p_AmtCr;
--
IF (p_Account_ID > 0) THEN
SELECT AccountType, AccountSign
INTO v_AccountType, v_AccountSign
FROM C_ElementValue
WHERE C_ElementValue_ID=p_Account_ID;
-- DBMS_OUTPUT.PUT_LINE('Type=' || v_AccountType || ' - Sign=' || v_AccountSign);
-- Natural Account Sign
IF (v_AccountSign='N') THEN
IF (v_AccountType IN ('A','E')) THEN
v_AccountSign := 'D';
ELSE
v_AccountSign := 'C';
END IF;
-- DBMS_OUTPUT.PUT_LINE('Type=' || v_AccountType || ' - Sign=' || v_AccountSign);
END IF;
-- Debit Balance
IF (v_AccountSign = 'C') THEN
v_balance := p_AmtCr - p_AmtDr;
END IF;
END IF;
--
RETURN v_balance;
EXCEPTION WHEN OTHERS THEN
-- In case Acct not found
RETURN p_AmtDr - p_AmtCr;
END;
$body$ LANGUAGE plpgsql;
/*
* Returns credit or debit balance based on account sign and type.
*
* Account types and account signs are defined in ad_ref_list table.
* In version 3.1.3 types and signs are defined in following way:
* value | name | description
*-------+----------------+------------------------------------------
* A | Asset | Asset (Balance Sheet) Account
* L | Liability | Liability (Balance Sheet) Account
* R | Revenue | Revenue (P&L) Account
* E | Expense | Expense (P&L) Account
* O | Owner's Equity | Owner's Equity (Balance Sheet) Account
* M | Memo | Memo (Non Balance Sheet nor P&L) Account
*
*
* N | Natural | Natural sign of the Account Type
* D | Debit | Debit Balance Account
* C | Credit | Credit Balance Account
*/
CREATE OR REPLACE FUNCTION acctBalance(
IN NUMERIC, -- $1 account id
IN NUMERIC, -- $2 amount debit
IN NUMERIC -- $3 amount credit
) RETURNS NUMERIC AS
$$
DECLARE
accType CHAR(1); --account type
accSign CHAR(1); --account sign
BEGIN
IF $1 != 0 THEN
SELECT t.AccountType, t.AccountSign
INTO accType, accSign
FROM C_ElementValue AS t WHERE t.C_ElementValue_ID = $1;
IF accSign = 'N' AND accType NOT IN ('A', 'E') THEN
--If account sign is natural and account type not asset or expense
--mark sign to be credit.
accSign := 'C';
END IF;
END IF;
IF accSign = 'C' THEN
RETURN $2 - $3;
ELSE
RETURN $3 - $2;
END IF;
END;
$$ LANGUAGE plpgsql STABLE STRICT;

View File

@ -1,50 +1,24 @@
/*
*This file is part of Adempiere ERP Bazaar
*http://www.adempiere.org
*
*Copyright (C) 2007 Gavin Dunse
*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
*/
CREATE OR REPLACE FUNCTION bpartnerRemitLocation(p_C_BPartner_ID C_BPartner.C_BPartner_ID%TYPE)
RETURNS numeric AS $body$
/*
* Return the first RemitTo C_Location_ID of a Business Partner
*/
DECLARE
v_C_Location_ID NUMERIC := NULL;
l RECORD;
BEGIN
FOR l IN
SELECT IsRemitTo, C_Location_ID
FROM C_BPartner_Location
WHERE C_BPartner_ID=p_C_BPartner_ID
ORDER BY IsRemitTo DESC
LOOP
IF (v_C_Location_ID IS NULL) THEN
v_C_Location_ID := l.C_Location_ID;
END IF;
END LOOP;
RETURN v_C_Location_ID;
END;
$body$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION bpartnerRemitLocation (
IN NUMERIC -- $1 C_BPartner_ID
) RETURNS NUMERIC AS
$$
DECLARE
clocationid NUMERIC;
BEGIN
SELECT t.C_Location_ID
INTO clocationid
FROM C_BPartner_Location
AS t
WHERE t.C_BPartner_ID=$1
AND t.C_Location_ID IS NOT NULL
ORDER BY t.IsRemitTo DESC;
/* Limit not needed as first row is only returned - LIMIT 1; */
IF FOUND THEN
RETURN clocationid;
ELSE
RETURN -1;
/* RAISE EXCEPTION 'Some error'*/
/* RETURN NULL */
END IF;
END;
$$ LANGUAGE plpgsql;

View File

@ -1,51 +1,62 @@
/*
*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
*/
CREATE OR REPLACE FUNCTION currencyConvert(
p_Amount NUMERIC,
p_CurFrom_ID NUMERIC,
p_CurTo_ID NUMERIC,
p_ConvDate timestamp with time zone,
p_ConversionType_ID IN NUMERIC,
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 (using IDs)
* Description:
* from CurrencyFrom_ID to CurrencyTo_ID
* Returns NULL, if conversion not found
* Standard Rounding
* Test:
* SELECT currencyConvert(100,116,100,null,null,null,null) FROM AD_System; => 64.72
************************************************************************/
DECLARE
v_Rate NUMERIC;
BEGIN
-- Return Amount
IF (p_Amount = 0 OR p_CurFrom_ID = p_CurTo_ID) THEN
RETURN p_Amount;
END IF;
-- Return NULL
IF (p_Amount IS NULL OR p_CurFrom_ID IS NULL OR p_CurTo_ID IS NULL) THEN
RETURN NULL;
END IF;
-- Get Rate
v_Rate := currencyRate (p_CurFrom_ID, p_CurTo_ID, p_ConvDate, p_ConversionType_ID, p_Client_ID, p_Org_ID);
IF (v_Rate IS NULL) THEN
RETURN NULL;
END IF;
-- Standard Precision
RETURN currencyRound(p_Amount * v_Rate, p_CurTo_ID, null);
END;
$body$ LANGUAGE plpgsql;
SET search_path = adempiere, pg_catalog;
CREATE OR REPLACE FUNCTION currencyconvert(
IN NUMERIC, -- $1 amount to convert
IN INTEGER, -- $2 from currency id
IN INTEGER, -- $3 to currency id
IN TIMESTAMP WITH TIME ZONE, -- $4 conversion date
IN INTEGER, -- $5 conversion type id
IN INTEGER, -- $6 client id
IN INTEGER -- $7 org id
) RETURNS numeric AS
$$
DECLARE
rate NUMERIC;
BEGIN
IF $1 IS NULL OR $2 IS NULL OR $3 IS NULL THEN
RETURN NULL;
END IF;
IF $1 = 0 OR $2 = $3 THEN
RETURN $1;
END IF;
rate := currencyrate($2,$3,$4,$5,$6,$7);
IF rate IS NULL THEN
RETURN NULL;
END IF;
RETURN currencyround((rate * $1), $3, FALSE);
END;
$$ LANGUAGE plpgsql;

View File

@ -1,64 +1,178 @@
/*
*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
*/
CREATE OR REPLACE FUNCTION currencyRate(
p_CurFrom_ID NUMERIC,
p_CurTo_ID NUMERIC,
p_ConvDate timestamp with time zone,
p_ConversionType_ID NUMERIC,
p_Client_ID NUMERIC,
p_Org_ID NUMERIC
)
SET search_path = adempiere, pg_catalog;
RETURNS numeric AS $body$
CREATE OR REPLACE FUNCTION currencyrate(
IN INTEGER, -- $1 currency from id
IN INTEGER, -- $2 currency to id
IN timestamp with time zone, -- $3 conversiondate
IN INTEGER, -- $4 conversiontype id
IN INTEGER, -- $5 client id
IN INTEGER -- $6 org id
) RETURNS NUMERIC AS
$$
DECLARE
conversion_type_id INTEGER;
conversion_date DATE;
rate NUMERIC;
BEGIN
IF $1 = $2 THEN
RETURN 1;
END IF;
conversion_type_id = COALESCE($4, 0);
conversion_date = CAST($3 AS DATE);
rate = NULL;
IF conversion_type_id = 0 THEN
SELECT C_ConversionType_ID
INTO conversion_type_id
FROM C_ConversionType
WHERE IsDefault = 'Y' AND AD_Client_ID IN (0, $5);
END IF;
SELECT t.MultiplyRate
INTO rate
FROM C_Conversion_Rate AS t
WHERE t.C_Currency_ID = $1
AND t.C_Currency_To = $2
AND date_trunc('day',t.ValidFrom) <= $3
AND date_trunc('day',t.ValidTo) >= $3
AND t.AD_Client_ID IN (0,$5)
AND t.AD_Org_ID IN (0, $6)
ORDER BY AD_Client_ID DESC, AD_Org_ID DESC, ValidFrom DESC
LIMIT 1;
return rate;
END;
$$ LANGUAGE plpgsql;
/*************************************************************************
* 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: Return Conversion Rate
* Description:
* from CurrencyFrom_ID to CurrencyTo_ID
* Returns NULL, if rate not found
* Test
* SELECT currencyrate(116, 100, null, null, null, null) FROM AD_System; => .647169
************************************************************************/
DECLARE
-- Currency From variables
cf_IsEuro CHAR(1);
cf_IsEMUMember CHAR(1);
cf_EMUEntryDate timestamp with time zone;
cf_EMURate NUMERIC;
-- Currency To variables
ct_IsEuro CHAR(1);
ct_IsEMUMember CHAR(1);
ct_EMUEntryDate DATE;
ct_EMURate NUMERIC;
-- Triangle
v_CurrencyFrom NUMERIC;
v_CurrencyTo NUMERIC;
v_CurrencyEuro NUMERIC;
--
v_ConvDate timestamp with time zone := now();
v_ConversionType_ID NUMERIC := 0;
v_Rate NUMERIC;
c RECORD;
BEGIN
-- No Conversion
IF (p_CurFrom_ID = p_CurTo_ID) THEN
RETURN 1;
END IF;
-- Default Date Parameter
IF (p_ConvDate IS NOT NULL) THEN
v_ConvDate := p_ConvDate; -- SysDate
END IF;
-- Default Conversion Type
IF (p_ConversionType_ID IS NULL OR p_ConversionType_ID = 0) THEN
BEGIN
SELECT C_ConversionType_ID
INTO v_ConversionType_ID
FROM C_ConversionType
WHERE IsDefault='Y'
AND AD_Client_ID IN (0,p_Client_ID)
AND ROWNUM=1
ORDER BY AD_Client_ID DESC;
EXCEPTION WHEN OTHERS THEN
RAISE NOTICE 'Conversion Type Not Found';
END;
ELSE
v_ConversionType_ID := p_ConversionType_ID;
END IF;
-- Get Currency Info
SELECT MAX(IsEuro), MAX(IsEMUMember), MAX(EMUEntryDate), MAX(EMURate)
INTO cf_IsEuro, cf_IsEMUMember, cf_EMUEntryDate, cf_EMURate
FROM C_Currency
WHERE C_Currency_ID = p_CurFrom_ID;
-- Not Found
IF (cf_IsEuro IS NULL) THEN
RAISE NOTICE 'From Currency Not Found';
RETURN NULL;
END IF;
SELECT MAX(IsEuro), MAX(IsEMUMember), MAX(EMUEntryDate), MAX(EMURate)
INTO ct_IsEuro, ct_IsEMUMember, ct_EMUEntryDate, ct_EMURate
FROM C_Currency
WHERE C_Currency_ID = p_CurTo_ID;
-- Not Found
IF (ct_IsEuro IS NULL) THEN
RAISE NOTICE 'To Currency Not Found';
RETURN NULL;
END IF;
-- Fixed - From Euro to EMU
IF (cf_IsEuro = 'Y' AND ct_IsEMUMember ='Y' AND v_ConvDate >= ct_EMUEntryDate) THEN
RETURN ct_EMURate;
END IF;
-- Fixed - From EMU to Euro
IF (ct_IsEuro = 'Y' AND cf_IsEMUMember ='Y' AND v_ConvDate >= cf_EMUEntryDate) THEN
RETURN 1 / cf_EMURate;
END IF;
-- Fixed - From EMU to EMU
IF (cf_IsEMUMember = 'Y' AND cf_IsEMUMember ='Y'
AND v_ConvDate >= cf_EMUEntryDate AND v_ConvDate >= ct_EMUEntryDate) THEN
RETURN ct_EMURate / cf_EMURate;
END IF;
-- Flexible Rates
v_CurrencyFrom := p_CurFrom_ID;
v_CurrencyTo := p_CurTo_ID;
-- if EMU Member involved, replace From/To Currency
IF ((cf_isEMUMember = 'Y' AND v_ConvDate >= cf_EMUEntryDate)
OR (ct_isEMUMember = 'Y' AND v_ConvDate >= ct_EMUEntryDate)) THEN
SELECT MAX(C_Currency_ID)
INTO v_CurrencyEuro
FROM C_Currency
WHERE IsEuro = 'Y';
-- Conversion Rate not Found
IF (v_CurrencyEuro IS NULL) THEN
RAISE NOTICE 'Euro Not Found';
RETURN NULL;
END IF;
IF (cf_isEMUMember = 'Y' AND v_ConvDate >= cf_EMUEntryDate) THEN
v_CurrencyFrom := v_CurrencyEuro;
ELSE
v_CurrencyTo := v_CurrencyEuro;
END IF;
END IF;
-- Get Rate
BEGIN
FOR c IN SELECT MultiplyRate
FROM C_Conversion_Rate
WHERE C_Currency_ID=v_CurrencyFrom AND C_Currency_ID_To=v_CurrencyTo
AND C_ConversionType_ID=v_ConversionType_ID
AND v_ConvDate BETWEEN ValidFrom AND ValidTo
AND AD_Client_ID IN (0,p_Client_ID) AND AD_Org_ID IN (0,p_Org_ID)
ORDER BY AD_Client_ID DESC, AD_Org_ID DESC, ValidFrom DESC
LOOP
v_Rate := c.MultiplyRate;
EXIT; -- only first
END LOOP;
END;
-- Not found
IF (v_Rate IS NULL) THEN
RAISE NOTICE 'Conversion Rate Not Found';
RETURN NULL;
END IF;
-- Currency From was EMU
IF (cf_isEMUMember = 'Y' AND v_ConvDate >= cf_EMUEntryDate) THEN
RETURN v_Rate / cf_EMURate;
END IF;
-- Currency To was EMU
IF (ct_isEMUMember = 'Y' AND v_ConvDate >= ct_EMUEntryDate) THEN
RETURN v_Rate * ct_EMURate;
END IF;
RETURN v_Rate;
EXCEPTION WHEN OTHERS THEN
RAISE NOTICE '%', SQLERRM;
RETURN NULL;
END;
$body$ LANGUAGE plpgsql;

View File

@ -1,51 +1,60 @@
/*
*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
*/
CREATE OR REPLACE FUNCTION currencyRound(
p_Amount NUMERIC,
p_CurTo_ID NUMERIC,
p_Costing VARCHAR -- Default 'N'
)
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: Round amount for Traget Currency
* Description:
* Round Amount using Costing or Standard Precision
* Returns unmodified amount if currency not found
* Test:
* SELECT currencyRound(currencyConvert(100,116,100,null,null),100,null) FROM AD_System => 64.72
************************************************************************/
DECLARE
v_StdPrecision NUMERIC;
v_CostPrecision NUMERIC;
BEGIN
-- Nothing to convert
IF (p_Amount IS NULL OR p_CurTo_ID IS NULL) THEN
RETURN p_Amount;
END IF;
-- Ger Precision
SELECT MAX(StdPrecision), MAX(CostingPrecision)
INTO v_StdPrecision, v_CostPrecision
FROM C_Currency
WHERE C_Currency_ID = p_CurTo_ID;
-- Currency Not Found
IF (v_StdPrecision IS NULL) THEN
RETURN p_Amount;
END IF;
IF (p_Costing = 'Y') THEN
RETURN ROUND (p_Amount, v_CostPrecision);
END IF;
RETURN ROUND (p_Amount, v_StdPrecision);
END;
$body$ LANGUAGE plpgsql;
SET search_path = adempiere, pg_catalog;
CREATE OR REPLACE FUNCTION currencyround (
IN NUMERIC, -- $1 amount
IN INTEGER, -- $2 Currency_ID
IN BOOLEAN -- $3 Costing
) RETURNS NUMERIC AS
$$
DECLARE
precision INTEGER;
BEGIN
IF $1 IS NULL OR $2 IS NULL THEN
RETURN $1;
END IF;
IF COALESCE($3,FALSE) THEN
SELECT t.CostingPrecision
INTO precision
FROM C_Currency AS t
WHERE C_Currency_ID = $2;
ELSE
SELECT t.stdprecision
INTO precision
FROM C_Currency AS t
WHERE C_Currency_ID = $2;
END IF;
RETURN ROUND($1, precision);
END;
$$ LANGUAGE plpgsql;

View File

@ -1,87 +0,0 @@
/*
*This file is part of Adempiere ERP Bazaar
*http://www.adempiere.org
*
*Copyright (C) 2007 Gavin Dunse
*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
*/
/*
* Calculate Payment Discount Amount
* - Calculate discountable amount (i.e. with or without tax)
* - Calculate and return payment discount
*/
CREATE OR REPLACE FUNCTION invoiceDiscount (
IN NUMERIC, -- $1 C_Invoice_ID
IN TIMESTAMP WITH TIME ZONE, -- $2 PayDate
IN NUMERIC -- $3 C_InvoicePaySchedule_ID
) RETURNS NUMERIC AS
$$
DECLARE
v_Amount NUMERIC;
v_IsDiscountLineAmt CHAR(1);
v_GrandTotal NUMERIC;
v_TotalLines NUMERIC;
v_C_PaymentTerm_ID NUMERIC;
v_DocDate TIMESTAMP WITH TIME ZONE;
v_PayDate TIMESTAMP WITH TIME ZONE;
v_IsPayScheduleValid CHAR(1);
BEGIN
SELECT CURRENT_DATE INTO v_PayDate;
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 AS ci, C_Invoice AS i
WHERE ci.AD_Client_ID=i.AD_Client_ID
AND i.C_Invoice_ID=p_C_Invoice_ID;
IF FOUND THEN
/* 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);
ELSE
RETURN -1;
/* RAISE EXCEPTION 'Some error'*/
/* RETURN NULL */
END IF;
END;
$$ LANGUAGE plpgsql;

View File

@ -1,101 +1,67 @@
/*
*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
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
Amount NUMERIC,
Currency_ID NUMERIC,
PaymentTerm_ID NUMERIC,
DocDate timestamp with time zone,
PayDate timestamp with time zone
)
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;
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 Discount
* Description:
* Calculate the allowable Discount Amount of the Payment Term
*
* Test: SELECT paymenttermDiscount(110, 103, 106, now(), now()) FROM TEST; => 2.20
************************************************************************/
IF $5 IS NULL THEN
payDate := current_date;
ELSE
payDate := CAST($5 AS DATE);
END IF;
DECLARE
Discount NUMERIC := 0;
Discount1Date timestamp with time zone;
Discount2Date timestamp with time zone;
Add1Date NUMERIC := 0;
Add2Date NUMERIC := 0;
p RECORD;
BEGIN
-- No Data - No Discount
IF (Amount IS NULL OR PaymentTerm_ID IS NULL OR DocDate IS NULL) THEN
RETURN 0;
END IF;
discount1date := CAST($4 AS Date);
discount2date := discount1date;
FOR p IN
SELECT *
FROM C_PaymentTerm
WHERE C_PaymentTerm_ID = PaymentTerm_ID
LOOP -- for convineance only
Discount1Date := TRUNC(DocDate + p.DiscountDays + p.GraceDays);
Discount2Date := TRUNC(DocDate + p.DiscountDays2 + p.GraceDays);
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;
-- Next Business Day
IF (p.IsNextBusinessDay='Y') THEN
Discount1Date := nextBusinessDay(Discount1Date, p.AD_Client_ID);
Discount2Date := nextBusinessDay(Discount2Date, p.AD_Client_ID);
END IF;
--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;
-- Discount 1
IF (Discount1Date >= TRUNC(PayDate)) THEN
Discount := Amount * p.Discount / 100;
-- Discount 2
ELSIF (Discount2Date >= TRUNC(PayDate)) THEN
Discount := Amount * p.Discount2 / 100;
END IF;
END LOOP;
--
RETURN ROUND(COALESCE(Discount,0), 2); -- fixed rounding
END;
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;
$body$ LANGUAGE plpgsql;

View File

@ -1,70 +1,55 @@
/*
*This file is part of Adempiere ERP Bazaar
*http://www.adempiere.org
create or replace FUNCTION paymenttermDueDate
(
PaymentTerm_ID IN NUMERIC,
DocDate IN timestamp with time zone
)
RETURNS timestamp with time zone 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.
*
*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
*/
* converted to postgreSQL by Karsten Thiemann (Schaeffer AG),
* kthiemann@adempiere.org
*************************************************************************
* Title: Get Due timestamp with time zone
* Description:
* Returns the due timestamp with time zone
* Test:
* select paymenttermDueDate(106, now()) from Test; => now()+30 days
************************************************************************/
DECLARE
Days NUMERIC := 0;
DueDate timestamp with time zone := TRUNC(DocDate);
--
FirstDay timestamp with time zone;
NoDays NUMERIC;
p RECORD;
BEGIN
FOR p IN
SELECT *
FROM C_PaymentTerm
WHERE C_PaymentTerm_ID = PaymentTerm_ID
LOOP -- for convineance only
-- Due 15th of following month
IF (p.IsDueFixed = 'Y') THEN
FirstDay := TRUNC(DocDate, 'MM');
NoDays := TRUNC(DocDate) - FirstDay;
DueDate := FirstDay + (p.FixMonthDay-1); -- starting on 1st
DueDate := ADD_MONTHS(DueDate, p.FixMonthOffset);
IF (NoDays > p.FixMonthCutoff) THEN
DueDate := ADD_MONTHS(DueDate, 1);
END IF;
ELSE
DueDate := TRUNC(DocDate) + p.NetDays;
END IF;
END LOOP;
SET search_path = adempiere, pg_catalog;
RETURN DueDate;
END;
$body$ LANGUAGE plpgsql;
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

@ -1,42 +1,122 @@
/*
*This file is part of Adempiere ERP Bazaar
*http://www.adempiere.org
create or replace FUNCTION paymenttermDueDays
(
PaymentTerm_ID IN NUMERIC,
DocDate IN timestamp with time zone,
PayDate IN timestamp with time zone
)
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-2001 Jorg Janke, ComPiere, Inc. All Rights Reserved.
*
*Copyright (C) 2006 Timo Kontro
*Copyright (C) 1999-2006 ComPiere, inc
* converted to postgreSQL by Karsten Thiemann (Schaeffer AG),
* kthiemann@adempiere.org
*************************************************************************
* Title: Get Due Days
* Description:
* Returns the days due (positive) or the days till due (negative)
* Grace days are not considered!
* If record is not found it assumes due immediately
*
*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.
* Test: SELECT paymenttermDueDays(103, now(), now());
*
*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
*/
* Contributor(s): Carlos Ruiz - globalqss - match with SQLJ version
************************************************************************/
DECLARE
Days NUMERIC := 0;
DueDate timestamp with time zone := NULL;
calDueDate timestamp with time zone;
FixMonthOffset C_PaymentTerm.FixMonthOffset%TYPE;
MaxDayCut NUMERIC;
MaxDay NUMERIC;
v_PayDate timestamp with time zone;
p RECORD;
--
FirstDay timestamp with time zone;
NoDays NUMERIC;
BEGIN
SET search_path = adempiere, pg_catalog;
IF PaymentTerm_ID = 0 OR DocDate IS NULL THEN
RETURN 0;
END IF;
v_PayDate := PayDate;
IF v_PayDate IS NULL THEN
v_PayDate := TRUNC(now());
END IF;
FOR p IN
SELECT *
FROM C_PaymentTerm
WHERE C_PaymentTerm_ID = PaymentTerm_ID
LOOP -- for convineance only
-- Due 15th of following month
IF (p.IsDueFixed = 'Y') THEN
FirstDay := TRUNC(DocDate, 'MM');
NoDays := extract (day from (TRUNC(DocDate) - FirstDay));
DueDate := FirstDay + (p.FixMonthDay-1); -- starting on 1st
DueDate := DueDate + (p.FixMonthOffset || ' month')::interval;
IF (NoDays > p.FixMonthCutoff) THEN
DueDate := DueDate + '1 month'::interval;
END IF;
-- raise notice 'FirstDay: %, NoDays: %, DueDate: %', FirstDay, NoDays, DueDate;
calDueDate := TRUNC(DocDate);
MaxDayCut := extract (day from (cast(date_trunc('month', calDueDate) + '1 month'::interval as date) - 1));
-- raise notice 'last day(MaxDayCut): %' , MaxDayCut;
IF p.FixMonthCutoff > MaxDayCut THEN
-- raise notice 'p.FixMonthCutoff > MaxDayCut';
calDueDate := cast(date_trunc('month', TRUNC(calDueDate)) + '1 month'::interval as date) - 1;
-- raise notice 'last day(calDueDate): %' , calDueDate;
ELSE
-- set day fixmonthcutoff on duedate
calDueDate := TRUNC(calDueDate, 'MM') + (((p.FixMonthCutoff-1)|| ' days')::interval);
-- raise notice 'calDueDate: %' , calDueDate;
END IF;
FixMonthOffset := p.FixMonthOffset;
IF DocDate > calDueDate THEN
FixMonthOffset := FixMonthOffset + 1;
raise notice 'FixMonthOffset: %' , FixMonthOffset;
END IF;
calDueDate := calDueDate + (FixMonthOffset || ' month')::interval;
-- raise notice 'calDueDate: %' , calDueDate;
MaxDay := extract (day from (cast(date_trunc('month', calDueDate) + '1 month'::interval as date) - 1));
IF (p.FixMonthDay > MaxDay) -- 32 -> 28
OR (p.FixMonthDay >= 30 AND MaxDay > p.FixMonthDay) THEN -- 30 -> 31
calDueDate := TRUNC(calDueDate, 'MM') + (((MaxDay-1)|| ' days')::interval);
-- raise notice 'calDueDate: %' , calDueDate;
ELSE
calDueDate := TRUNC(calDueDate, 'MM') + (((p.FixMonthDay-1)|| ' days')::interval);
-- raise notice 'calDueDate: %' , calDueDate;
END IF;
DueDate := calDueDate;
ELSE
DueDate := TRUNC(DocDate) + p.NetDays;
END IF;
END LOOP;
IF DueDate IS NULL THEN
RETURN 0;
END IF;
Days := EXTRACT(day from (TRUNC(v_PayDate) - DueDate));
RETURN Days;
END;
$body$ LANGUAGE plpgsql;
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;

View File

@ -1,67 +1,90 @@
/*
*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
*/
CREATE OR REPLACE FUNCTION ProductAttribute
(
p_M_AttributeSetInstance_ID NUMERIC
)
RETURNS VARCHAR AS $body$
SET search_path = adempiere, pg_catalog;
/*************************************************************************
* 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: Return Instance Attribute Info
* Description:
*
* Test:
SELECT ProductAttribute (M_AttributeSetInstance_ID)
FROM M_InOutLine WHERE M_AttributeSetInstance_ID > 0
--
SELECT p.Name
FROM C_InvoiceLine il LEFT OUTER JOIN M_Product p ON (il.M_Product_ID=p.M_Product_ID);
SELECT p.Name || ProductAttribute (il.M_AttributeSetInstance_ID)
FROM C_InvoiceLine il LEFT OUTER JOIN M_Product p ON (il.M_Product_ID=p.M_Product_ID);
CREATE OR REPLACE FUNCTION productattribute (
IN INTEGER -- $1 m_attributesetinstance_id
) RETURNS VARCHAR AS
$$
DECLARE
lot VARCHAR;
serno VARCHAR;
gdate TIMESTAMP WITH TIME ZONE;
result VARCHAR;
r RECORD;
************************************************************************/
BEGIN
IF COALESCE($1,0) = 0 THEN
RETURN '';
END IF;
SELECT t.lot, t.serno, t.guaranteedate
INTO lot, serno, gdate
FROM m_attributesetinstance t
WHERE t.m_attributesetinstance_id = $1;
result := '';
IF lot IS NOT NULL THEN
result := result || lot || ' ';
END IF;
IF serno IS NOT NULL THEN
result := result || '#' || serno || ' ';
END IF;
IF gdate IS NOT NULL THEN
result := result || date_trunc('minute', gdate) || ' ';
END IF;
FOR r IN SELECT ai.value, a.name FROM m_attributeinstance ai
INNER JOIN m_attribute a ON ai.m_attribute_id = a.m_attribute_id
WHERE a.IsIstanceAttribute = 'Y' AND ai.m_attributesetinstance_id = $1
LOOP
result := result || r.value;
result := result || ':' || r.name || ' ';
END LOOP;
IF CHAR_LENGTH(result) > 0 THEN
result := '"' || result || '"';
DECLARE
v_Name VARCHAR(2000) := '';
v_NameAdd VARCHAR(2000) := '';
--
v_Lot M_AttributeSetInstance.Lot%TYPE;
v_LotStart M_AttributeSet.LotCharSOverwrite%TYPE;
v_LotEnd M_AttributeSet.LotCharEOverwrite%TYPE;
v_SerNo M_AttributeSetInstance.SerNo%TYPE;
v_SerNoStart M_AttributeSet.SerNoCharSOverwrite%TYPE;
v_SerNoEnd M_AttributeSet.SerNoCharEOverwrite%TYPE;
v_GuaranteeDate M_AttributeSetInstance.GuaranteeDate%TYPE;
r RECORD;
--
BEGIN
-- Get Product Attribute Set Instance
IF (p_M_AttributeSetInstance_ID > 0) THEN
SELECT asi.Lot, asi.SerNo, asi.GuaranteeDate,
COALESCE(a.SerNoCharSOverwrite, '#'::CHAR(1)), COALESCE(a.SerNoCharEOverwrite, ''::CHAR(1)),
COALESCE(a.LotCharSOverwrite, '«'::CHAR(1)), COALESCE(a.LotCharEOverwrite, '»'::CHAR(1))
INTO v_Lot, v_SerNo, v_GuaranteeDate,
v_SerNoStart, v_SerNoEnd, v_LotStart, v_LotEnd
FROM M_AttributeSetInstance asi
INNER JOIN M_AttributeSet a ON (asi.M_AttributeSet_ID=a.M_AttributeSet_ID)
WHERE asi.M_AttributeSetInstance_ID=p_M_AttributeSetInstance_ID;
--
IF (v_SerNo IS NOT NULL) THEN
v_NameAdd := v_NameAdd || v_SerNoStart || v_SerNo || v_SerNoEnd || ' ';
END IF;
IF (v_Lot IS NOT NULL) THEN
v_NameAdd := v_NameAdd || v_LotStart || v_Lot || v_LotEnd || ' ';
END IF;
IF (v_GuaranteeDate IS NOT NULL) THEN
v_NameAdd := v_NameAdd || v_GuaranteeDate || ' ';
END IF;
--
FOR r IN
SELECT ai.Value, a.Name
FROM M_AttributeInstance ai
INNER JOIN M_Attribute a ON (ai.M_Attribute_ID=a.M_Attribute_ID AND a.IsInstanceAttribute='Y')
WHERE ai.M_AttributeSetInstance_ID=p_M_AttributeSetInstance_ID
LOOP
v_NameAdd := v_NameAdd || r.Name || ':' || r.Value || ' ';
END LOOP;
--
IF (LENGTH(v_NameAdd) > 0) THEN
v_Name := v_Name || ' (' || TRIM(v_NameAdd) || ')';
ELSE
v_Name := NULL;
END IF;
END IF;
RETURN result;
END;
$$ LANGUAGE plpgsql;
RETURN v_Name;
END;
$body$ LANGUAGE plpgsql;