1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213
|
set client_min_messages = 'warning';
BEGIN;
CREATE OR REPLACE FUNCTION invoice__start_ap
(in_invnumber text, in_transdate date, in_taxincluded bool,
in_amount numeric, in_netamount numeric, in_paid numeric, in_datepaid date,
in_duedate date, in_invoice bool, in_curr char(3), person_id int,
in_till varchar(20), in_department_id int, in_approved bool,
in_entity_credit_account int, in_ar_accno text)
RETURNS int LANGUAGE SQL AS
$$
INSERT INTO ap
(invnumber, transdate, taxincluded,
amount, netamount, paid, datepaid,
duedate, invoice, curr, person_id,
till, department_id, approved, entity_credit_account)
VALUES ($1, $2, coalesce($3, 'f'),
$4,$5, $6, coalesce($7, 'today'),
coalesce($8, 'today'), $9, coalesce($10,
(select defaults_get_defaultcurrency from
defaults_get_defaultcurrency())),
coalesce($11, person__get_my_entity_id()),
$12, $13, coalesce($14, true), $15);
INSERT INTO acc_trans
(trans_id, transdate, chart_id, amount, approved)
SELECT currval('id')::int, $2, a.id, $4, true
FROM account a WHERE accno = $16;
SELECT currval('id')::int;
$$;
CREATE OR REPLACE FUNCTION invoice__start_ar
(in_invnumber text, in_transdate date, in_taxincluded bool,
in_amount numeric, in_netamount numeric, in_paid numeric, in_datepaid date,
in_duedate date, in_invoice bool, in_curr char(3), person_id int,
in_till varchar(20), in_department_id int, in_approved bool,
in_entity_credit_account int, in_ar_accno text)
RETURNS int LANGUAGE SQL AS
$$
INSERT INTO ar
(invnumber, transdate, taxincluded,
amount, netamount, paid, datepaid,
duedate, invoice, curr, person_id,
till, department_id, approved, entity_credit_account)
VALUES ($1, $2, coalesce($3, 'f'),
$4,$5, $6, coalesce($7, 'today'),
coalesce($8, 'today'), $9, coalesce($10,
(select defaults_get_defaultcurrency from
defaults_get_defaultcurrency())),
coalesce($11, person__get_my_entity_id()),
$12, $13, coalesce($14, true), $15);
INSERT INTO acc_trans
(trans_id, transdate, chart_id, amount, approved)
SELECT currval('id')::int, $2, a.id, $4 * -1, true
FROM account a WHERE accno = $16;
SELECT currval('id')::int;
$$;
COMMENT ON FUNCTION invoice__start_ar
(in_invnumber text, in_transdate date, in_taxincluded bool,
in_amount numeric, in_netamount numeric, in_paid numeric, in_datepaid date,
in_duedate date, in_invoice bool, in_curr char(3), person_id int,
in_till varchar(20), in_department_id int, in_approved bool,
in_entity_credit_account int, in_ar_accno text)
IS $$ Saves an ar transaction header. The following fields are optional:
1. in_tax_included, defaults to false
2. in_datepaid, defaults to 'today'
3. in_duedate defaults to 'today',
4. in_person_id defaults to the entity id of the current user.
5. in_curr defaults to the default currency.
All other fields are mandatory.
Returns true on success, raises exception on failure.
$$;
CREATE OR REPLACE FUNCTION invoice__add_item_ap
(in_id int, in_parts_id int, in_qty numeric, in_discount numeric,
in_unit text, in_sellprice numeric)
RETURNS BOOL LANGUAGE SQL AS
$$
INSERT INTO invoice(trans_id, parts_id, qty, discount, unit, allocated, sellprice)
SELECT $1, p.id, $3 * -1, $4, coalesce($5, p.unit), 0, $6
FROM parts p WHERE id = $2;
SELECT TRUE;
$$;
CREATE OR REPLACE FUNCTION invoice__add_item_ar
(in_id int, in_parts_id int, in_qty numeric, in_discount numeric,
in_unit text, in_sellprice numeric)
RETURNS BOOL LANGUAGE SQL AS
$$
INSERT INTO invoice(trans_id, parts_id, qty, discount, unit, allocated, sellprice)
SELECT $1, p.id, $3, $4, coalesce($5, p.unit), 0, $6
FROM parts p WHERE id = $2;
SELECT TRUE;
$$;
COMMENT ON FUNCTION invoice__add_item_ar
(in_id int, in_parts_id int, in_qty numeric, in_discount numeric,
in_unit text, in_sellprice numeric)
IS $$This adds an item to the invoice. This is not safe to use alone. If you
use it, you MUST also use invoice__finalize_ar. In particular this function does
not add income, inventory, or COGS calculations. $$;
CREATE OR REPLACE FUNCTION invoice__add_payment_ar
(in_id int, in_ar_accno text, in_cash_accno text, in_transdate date,
in_source text, in_memo text, in_amount numeric)
RETURNS BOOL LANGUAGE SQL AS
$$
INSERT INTO acc_trans (trans_id, chart_id, transdate, source, memo, amount,
approved)
VALUES ($1, (select id from account where accno = $2), coalesce($4, 'today'), $5,
$6, $7, true),
($1, (select id from account where accno = $3), coalesce($4, 'today'), $5,
$6, $7 * -1, true);
SELECT TRUE;
$$;
CREATE OR REPLACE FUNCTION invoice__add_payment_ap
(in_id int, in_ap_accno text, in_cash_accno text, in_transdate date,
in_source text, in_memo text, in_amount numeric)
RETURNS BOOL LANGUAGE SQL AS
$$
INSERT INTO acc_trans (trans_id, chart_id, transdate, source, memo, amount,
approved)
VALUES ($1, (select id from account where accno = $2), coalesce($4, 'today'), $5,
$6, $7 * -1, true),
($1, (select id from account where accno = $3), coalesce($4, 'today'), $5,
$6, $7, true);
SELECT TRUE;
$$;
CREATE OR REPLACE FUNCTION invoice__finalize_ap(in_id int)
returns bool language plpgsql as
$$
BEGIN
-- inventory
INSERT INTO acc_trans (trans_id, chart_id, transdate, amount, approved,
invoice_id)
SELECT in_id, p.income_accno_id, a.transdate, i.qty * i.sellprice * -1, true, i.id
FROM parts p
JOIN invoice i ON i.parts_id = p.id
JOIN ap a ON i.trans_id = a.id AND a.id = in_id;
-- transaction should now be balanced if this was done with invoice__begin_ap
-- add cogs
PERFORM cogs__add_for_ap(parts_id, qty, sellprice)
FROM invoice WHERE trans_id = in_id;
-- check if transaction is balanced, else raise exception
PERFORM trans_id FROM acc_trans
WHERE trans_id = in_id
GROUP BY trans_id
HAVING sum(amount) <> 0;
IF FOUND THEN
RAISE EXCEPTION 'Out of balance';
END IF;
RETURN TRUE;
END;
$$;
CREATE OR REPLACE FUNCTION invoice__finalize_ar(in_id int)
returns bool language plpgsql as
$$
DECLARE balance numeric;
BEGIN
-- income
INSERT INTO acc_trans (trans_id, chart_id, transdate, amount, approved,
invoice_id)
SELECT in_id, p.income_accno_id, a.transdate, i.qty * i.sellprice , true, i.id
FROM parts p
JOIN invoice i ON i.parts_id = p.id
JOIN ar a ON i.trans_id = a.id AND a.id = in_id;
-- transaction should now be balanced if this was done with invoice__begin_ar
-- add cogs
PERFORM cogs__add_for_ar(parts_id, qty)
FROM invoice WHERE trans_id = in_id;
-- check if transaction is balanced, else raise exception
SELECT sum(amount) INTO balance FROM acc_trans
WHERE trans_id = in_id
HAVING sum(amount) <> 0;
IF FOUND THEN
RAISE WARNING 'Balance: %', balance;
RAISE EXCEPTION 'Out of balance';
END IF;
RETURN TRUE;
END;
$$;
COMMIT;
|