summaryrefslogtreecommitdiff
path: root/sql/modules/Payment.sql
blob: f898528bd2babc27ae4e81f458f59da99a5fbdbb (plain)
  1. -- payment_get_open_accounts and the option to get all accounts need to be
  2. -- refactored and redesigned. -- CT
  3. CREATE OR REPLACE FUNCTION payment_get_open_accounts(in_account_class int)
  4. returns SETOF entity AS
  5. $$
  6. DECLARE out_entity entity%ROWTYPE;
  7. BEGIN
  8. FOR out_entity IN
  9. SELECT ec.id, e.name, e.entity_class, e.created
  10. FROM entity e
  11. JOIN entity_credit_account ec ON (ec.entity_id = e.id)
  12. WHERE ec.entity_class = in_account_class
  13. AND CASE WHEN in_account_class = 1 THEN
  14. id IN (SELECT entity_id FROM ap
  15. WHERE amount <> paid
  16. GROUP BY entity_id)
  17. WHEN in_account_class = 2 THEN
  18. id IN (SELECT entity_id FROM ar
  19. WHERE amount <> paid
  20. GROUP BY entity_id)
  21. END
  22. LOOP
  23. RETURN NEXT out_entity;
  24. END LOOP;
  25. END;
  26. $$ LANGUAGE PLPGSQL;
  27. COMMENT ON FUNCTION payment_get_open_accounts(int) IS
  28. $$ This function takes a single argument (1 for vendor, 2 for customer as
  29. always) and returns all entities with open accounts of the appropriate type. $$;
  30. CREATE OR REPLACE FUNCTION payment_get_all_accounts(in_account_class int)
  31. RETURNS SETOF entity AS
  32. $$
  33. DECLARE out_entity entity%ROWTYPE;
  34. BEGIN
  35. FOR out_entity IN
  36. SELECT ec.id,
  37. e.name, e.entity_class, e.created
  38. FROM entity e
  39. JOIN entity_credit_account ec ON (ec.entity_id = e.id)
  40. WHERE e.entity_class = in_account_class
  41. LOOP
  42. RETURN NEXT out_entity;
  43. END LOOP;
  44. END;
  45. $$ LANGUAGE PLPGSQL;
  46. COMMENT ON FUNCTION payment_get_open_accounts(int) IS
  47. $$ This function takes a single argument (1 for vendor, 2 for customer as
  48. always) and returns all entities with accounts of the appropriate type. $$;
  49. CREATE TYPE payment_invoice AS (
  50. invoice_id int,
  51. invnumber text,
  52. invoice_date date,
  53. amount numeric,
  54. discount numeric,
  55. due numeric
  56. );
  57. CREATE OR REPLACE FUNCTION payment_get_open_invoices
  58. (in_account_class int, in_entity_credit_id int, in_curr char(3))
  59. RETURNS SETOF payment_invoice AS
  60. $$
  61. DECLARE payment_inv payment_invoice;
  62. BEGIN
  63. FOR payment_inv IN
  64. SELECT a.id AS invoice_id, a.invnumber,
  65. a.transdate AS invoice_date, a.amount,
  66. CASE WHEN discount_terms
  67. > extract('days' FROM age(a.transdate))
  68. THEN 0
  69. ELSE (a.amount - a.paid) * c.discount / 100
  70. END AS discount,
  71. a.amount - a.paid -
  72. CASE WHEN discount_terms
  73. > extract('days' FROM age(a.transdate))
  74. THEN 0
  75. ELSE (a.amount - a.paid) * c.discount / 100
  76. END AS due
  77. FROM (SELECT id, invnumber, transdate, amount, entity_id,
  78. 1 as invoice_class, paid, curr
  79. FROM ap
  80. UNION
  81. SELECT id, invnumber, transdate, amount, entity_id,
  82. 2 AS invoice_class, paid, curr
  83. FROM ar
  84. ) a
  85. JOIN entity_credit_account c USING (entity_id)
  86. WHERE a.invoice_class = in_account_class
  87. AND c.entity_class = in_account_class
  88. AND a.amount - a.paid <> 0
  89. AND a.curr = in_curr
  90. AND a.credit_account = coalesce(in_entity_credit_id,
  91. a.credit_account)
  92. LOOP
  93. RETURN NEXT payment_inv;
  94. END LOOP;
  95. END;
  96. $$ LANGUAGE PLPGSQL;
  97. COMMENT ON FUNCTION payment_get_open_invoices(int, int, char(3)) IS
  98. $$ This function takes three arguments:
  99. Type: 1 for vendor, 2 for customer
  100. Entity_id: The entity_id of the customer or vendor
  101. Currency: 3 characters for currency ('USD' for example).
  102. Returns all open invoices for the entity in question. $$;
  103. CREATE TYPE payment_contact_invoice AS (
  104. contact_id int,
  105. contact_name text,
  106. account_number text,
  107. total_due numeric,
  108. invoices text[],
  109. has_vouchers int
  110. );
  111. CREATE OR REPLACE FUNCTION payment_get_all_contact_invoices
  112. (in_account_class int, in_business_id int, in_currency char(3),
  113. in_date_from date, in_date_to date, in_batch_id int,
  114. in_ar_ap_accno text)
  115. RETURNS SETOF payment_contact_invoice AS
  116. $$
  117. DECLARE payment_item payment_contact_invoice;
  118. BEGIN
  119. FOR payment_item IN
  120. SELECT c.id AS contact_id, e.name AS contact_name,
  121. c.meta_number AS account_number,
  122. sum(a.amount - a.paid) AS total_due,
  123. compound_array(ARRAY[[
  124. a.id::text, a.invnumber, a.transdate::text,
  125. a.amount::text, a.paid::text,
  126. (CASE WHEN c.discount_terms
  127. > extract('days' FROM age(a.transdate))
  128. THEN 0
  129. ELSE (a.amount - coalesce(a.paid, 0)) * coalesce(c.discount, 0) / 100
  130. END)::text,
  131. (a.amount - coalesce(a.paid, 0) -
  132. (CASE WHEN c.discount_terms
  133. > extract('days' FROM age(a.transdate))
  134. THEN 0
  135. ELSE (a.amount - coalesce(a.paid, 0)) * coalesce(c.discount, 0) / 100
  136. END))::text]]),
  137. sum(case when v.batch_id = in_batch_id then 1
  138. else 0 END),
  139. bool_and(lock_record(a.id, (select max(session_id) FROM "session" where users_id = (
  140. select id from users WHERE username =
  141. SESSION_USER))))
  142. FROM entity e
  143. JOIN entity_credit_account c ON (e.id = c.entity_id)
  144. JOIN (SELECT id, invnumber, transdate, amount, entity_id,
  145. paid, curr, 1 as invoice_class,
  146. entity_credit_account, on_hold
  147. FROM ap
  148. WHERE in_account_class = 1
  149. UNION
  150. SELECT id, invnumber, transdate, amount, entity_id,
  151. paid, curr, 2 as invoice_class,
  152. entity_credit_account, on_hold
  153. FROM ar
  154. WHERE in_account_class = 2
  155. ORDER BY transdate
  156. ) a USING (entity_id)
  157. JOIN transactions t ON (a.id = t.id)
  158. LEFT JOIN voucher v ON (v.trans_id = a.id)
  159. WHERE v.batch_id = in_batch_id
  160. OR (a.invoice_class = in_account_class
  161. AND c.business_id =
  162. coalesce(in_business_id, c.business_id)
  163. AND ((a.transdate >= COALESCE(in_date_from, a.transdate)
  164. AND a.transdate <= COALESCE(in_date_to, a.transdate)))
  165. AND c.entity_class = in_account_class
  166. AND a.curr = in_currency
  167. AND a.entity_credit_account = c.id
  168. AND a.amount - a.paid <> 0
  169. AND NOT a.on_hold
  170. AND NOT (t.locked_by IS NOT NULL AND t.locked_by IN
  171. (select "session_id" FROM "session"
  172. WHERE users_id IN
  173. (select id from users
  174. where username <> SESSION_USER)))
  175. AND EXISTS (select trans_id FROM acc_trans
  176. WHERE trans_id = a.id AND
  177. chart_id = (SELECT id frOM chart
  178. WHERE accno
  179. = in_ar_ap_accno)
  180. ))
  181. GROUP BY c.id, e.name, c.meta_number, c.threshold
  182. HAVING sum(a.amount - a.paid) > c.threshold
  183. OR sum(case when v.batch_id = in_batch_id then 1
  184. else 0 END) > 0
  185. LOOP
  186. RETURN NEXT payment_item;
  187. END LOOP;
  188. END;
  189. $$ LANGUAGE plpgsql;
  190. COMMENT ON FUNCTION payment_get_all_contact_invoices
  191. (in_account_class int, in_business_type int, in_currency char(3),
  192. in_date_from date, in_date_to date, in_batch_id int,
  193. in_ar_ap_accno text) IS
  194. $$
  195. This function takes the following arguments (all prefaced with in_ in the db):
  196. account_class: 1 for vendor, 2 for customer
  197. business_type: integer of business.id.
  198. currency: char(3) of currency (for example 'USD')
  199. date_from, date_to: These dates are inclusive.
  200. 1;3B
  201. batch_id: For payment batches, where fees are concerned.
  202. ar_ap_accno: The AR/AP account number.
  203. This then returns a set of contact information with a 2 dimensional array
  204. cnsisting of outstanding invoices.
  205. $$;
  206. CREATE OR REPLACE FUNCTION payment_bulk_queue
  207. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  208. in_ar_ap_accno text, in_cash_accno text,
  209. in_payment_date date, in_account_class int)
  210. returns int as
  211. $$
  212. BEGIN
  213. INSERT INTO payments_queue
  214. (transactions, batch_id, source, total, ar_ap_accno, cash_accno,
  215. payment_date, account_class)
  216. VALUES
  217. (in_transactions, in_batch_id, in_source, in_total, in_ar_ap_accno,
  218. in_cash_accno, in_payment_date, in_account_class);
  219. RETURN array_upper(in_transactions, 1) -
  220. array_lower(in_transactions, 1);
  221. END;
  222. $$ LANGUAGE PLPGSQL;
  223. CREATE OR REPLACE FUNCTION job__process_payment(in_job_id int)
  224. RETURNS bool AS $$
  225. DECLARE
  226. queue_record RECORD;
  227. t_auth_name text;
  228. t_counter int;
  229. BEGIN
  230. -- TODO: Move the set session authorization into a utility function
  231. SELECT entered_by INTO t_auth_name FROM pending_job
  232. WHERE id = in_job_id;
  233. EXECUTE 'SET SESSION AUTHORIZATION ' || quote_ident(t_auth_name);
  234. t_counter := 0;
  235. FOR queue_record IN
  236. SELECT *
  237. FROM payments_queue WHERE job_id = in_job_id
  238. LOOP
  239. PERFORM payment_bulk_post
  240. (queue_record.transactions, queue_record.batch_id,
  241. queue_record.source, queue_record.total,
  242. queue_record.ar_ap_accno,
  243. queue_record.cash_accno,
  244. queue_record.payment_date,
  245. queue_record.account_class);
  246. t_counter := t_counter + 1;
  247. RAISE NOTICE 'Processed record %, starting transaction %',
  248. t_counter, queue_record.transactions[1][1];
  249. END LOOP;
  250. DELETE FROM payments_queue WHERE job_id = in_job_id;
  251. UPDATE pending_job
  252. SET completed_at = timeofday()::timestamp,
  253. success = true
  254. WHERE id = in_job_id;
  255. RETURN TRUE;
  256. END;
  257. $$ language plpgsql;
  258. CREATE OR REPLACE FUNCTION job__create(in_batch_class int, in_batch_id int)
  259. RETURNS int AS
  260. $$
  261. BEGIN
  262. INSERT INTO pending_job (batch_class, batch_id)
  263. VALUES (coalesce(in_batch_class, 3), in_batch_id);
  264. RETURN currval('pending_job_id_seq');
  265. END;
  266. $$ LANGUAGE PLPGSQL;
  267. CREATE TYPE job__status AS (
  268. completed int, -- 1 for completed, 0 for no
  269. success int, -- 1 for success, 0 for no
  270. completed_at timestamp,
  271. error_condition text -- error if not successful
  272. );
  273. CREATE OR REPLACE FUNCTION job__status(in_job_id int) RETURNS job__status AS
  274. $$
  275. DECLARE out_row job__status;
  276. BEGIN
  277. SELECT (completed_at IS NULL)::INT, success::int, completed_at,
  278. error_condition
  279. INTO out_row
  280. FROM pending_job
  281. WHERE id = in_job_id;
  282. RETURN out_row;
  283. END;
  284. $$ language plpgsql;
  285. CREATE OR REPLACE FUNCTION payment_bulk_post
  286. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  287. in_ar_ap_accno text, in_cash_accno text,
  288. in_payment_date date, in_account_class int)
  289. RETURNS int AS
  290. $$
  291. DECLARE
  292. payment_trans numeric[];
  293. out_count int;
  294. t_voucher_id int;
  295. t_trans_id int;
  296. t_amount numeric;
  297. t_ar_ap_id int;
  298. t_cash_id int;
  299. BEGIN
  300. IF in_batch_id IS NULL THEN
  301. -- t_voucher_id := NULL;
  302. RAISE EXCEPTION 'Bulk Post Must be from Batch!';
  303. ELSE
  304. INSERT INTO voucher (batch_id, batch_class, trans_id)
  305. values (in_batch_id, 3, in_transactions[1][1]);
  306. t_voucher_id := currval('voucher_id_seq');
  307. END IF;
  308. select id into t_ar_ap_id from chart where accno = in_ar_ap_accno;
  309. select id into t_cash_id from chart where accno = in_cash_accno;
  310. FOR out_count IN
  311. array_lower(in_transactions, 1) ..
  312. array_upper(in_transactions, 1)
  313. LOOP
  314. INSERT INTO acc_trans
  315. (trans_id, chart_id, amount, approved, voucher_id,
  316. transdate, source)
  317. VALUES
  318. (in_transactions[out_count][1],
  319. case when in_account_class = 1 THEN t_cash_id
  320. WHEN in_account_class = 2 THEN t_ar_ap_id
  321. ELSE -1 END,
  322. in_transactions[out_count][2],
  323. CASE WHEN t_voucher_id IS NULL THEN true
  324. ELSE false END,
  325. t_voucher_id, in_payment_date, in_source),
  326. (in_transactions[out_count][1],
  327. case when in_account_class = 1 THEN t_ar_ap_id
  328. WHEN in_account_class = 2 THEN t_cash_id
  329. ELSE -1 END,
  330. in_transactions[out_count][2]* -1,
  331. CASE WHEN t_voucher_id IS NULL THEN true
  332. ELSE false END,
  333. t_voucher_id, in_payment_date, in_source);
  334. UPDATE ap
  335. set paid = paid +in_transactions[out_count][2]
  336. where id =in_transactions[out_count][1];
  337. END LOOP;
  338. return out_count;
  339. END;
  340. $$ language plpgsql;
  341. COMMENT ON FUNCTION payment_bulk_post
  342. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  343. in_ar_ap_accno text, in_cash_accno text,
  344. in_payment_date date, in_account_class int)
  345. IS
  346. $$ Note that in_transactions is a two-dimensional numeric array. Of each
  347. sub-array, the first element is the (integer) transaction id, and the second
  348. is the amount for that transaction. If the total of the amounts do not add up
  349. to in_total, then an error is generated. $$;
  350. CREATE OR REPLACE FUNCTION payment_post
  351. (in_trans_id int, in_batch_id int, in_source text, in_amount numeric,
  352. in_ar_ap_accno text, in_cash_accno text, in_approved bool,
  353. in_payment_date date, in_account_class int)
  354. RETURNS INT AS
  355. $$
  356. DECLARE out_entry_id int;
  357. BEGIN
  358. INSERT INTO acc_trans (chart_id, amount,
  359. trans_id, transdate, approved, source)
  360. VALUES ((SELECT id FROM chart WHERE accno = in_ar_ap_accno),
  361. CASE WHEN in_account_class = 1 THEN in_amount * -1
  362. ELSE amount
  363. END,
  364. in_trans_id, in_payment_date, in_approved, in_source);
  365. INSERT INTO acc_trans (chart_id, amount,
  366. trans_id, transdate, approved, source)
  367. VALUES ((SELECT id FROM chart WHERE accno = in_cash_accno),
  368. CASE WHEN in_account_class = 2 THEN in_amount * -1
  369. ELSE amount
  370. END,
  371. in_trans_id, in_payment_date, coalesce(in_approved, true),
  372. in_source);
  373. SELECT currval('acc_trans_entry_id_seq') INTO out_entry_id;
  374. RETURN out_entry_id;
  375. END;
  376. $$ LANGUAGE PLPGSQL;
  377. COMMENT ON FUNCTION payment_post
  378. (in_trans_id int, in_source text, in_amount numeric, in_ar_ap_accno text,
  379. in_cash_accno text, in_approved bool, in_payment_date date,
  380. in_account_class int)
  381. IS $$
  382. This function takes the following arguments (prefaced with in_ in the db):
  383. trans_id: Id for ar/ap transaction.
  384. source: text for source documnet identifier (for example, check number)
  385. amount: numeric for the amount of the transaction
  386. ar_ap_accno: AR/AP account number
  387. cash_accno: Cash Account number, i.e. the account where the payment will be
  388. held
  389. approved: False, for a voucher.
  390. This function posts the payment or saves the payment voucher.
  391. $$;
  392. -- Move this to the projects module when we start on that. CT
  393. CREATE OR REPLACE FUNCTION project_list_open(in_date date)
  394. RETURNS SETOF project AS
  395. $$
  396. DECLARE out_project project%ROWTYPE;
  397. BEGIN
  398. FOR out_project IN
  399. SELECT * from project
  400. WHERE startdate <= in_date AND enddate >= in_date
  401. AND completed = 0
  402. LOOP
  403. return next out_project;
  404. END LOOP;
  405. END;
  406. $$ language plpgsql;
  407. comment on function project_list_open(in_date date) is
  408. $$ This function returns all projects that were open as on the date provided as
  409. the argument.$$;
  410. -- Move this to the projects module when we start on that. CT
  411. CREATE OR REPLACE FUNCTION department_list(in_role char)
  412. RETURNS SETOF department AS
  413. $$
  414. DECLARE out_department department%ROWTYPE;
  415. BEGIN
  416. FOR out_department IN
  417. SELECT * from department
  418. WHERE role = coalesce(in_role, role)
  419. LOOP
  420. return next out_department;
  421. END LOOP;
  422. END;
  423. $$ language plpgsql;
  424. -- Move this into another module.
  425. comment on function department_list(in_role char) is
  426. $$ This function returns all department that match the role provided as
  427. the argument.$$;
  428. CREATE OR REPLACE FUNCTION payments_get_open_currencies(in_account_class int)
  429. RETURNS SETOF char(3) AS
  430. $$
  431. DECLARE resultrow record;
  432. BEGIN
  433. FOR resultrow IN
  434. SELECT curr AS curr FROM ar
  435. WHERE amount <> paid
  436. OR paid IS NULL
  437. AND in_account_class=2
  438. UNION
  439. SELECT curr FROM ap
  440. WHERE amount <> paid
  441. OR paid IS NULL
  442. AND in_account_class=1
  443. ORDER BY curr
  444. LOOP
  445. return next resultrow.curr;
  446. END LOOP;
  447. END;
  448. $$ language plpgsql;
  449. CREATE OR REPLACE FUNCTION currency_get_exchangerate(in_currency char(3), in_date date, in_account_class int)
  450. RETURNS NUMERIC AS
  451. $$
  452. DECLARE
  453. out_exrate exchangerate.buy%TYPE;
  454. BEGIN
  455. IF in_account_class = 1 THEN
  456. SELECT INTO out_exrate buy
  457. FROM exchangerate
  458. WHERE transdate = in_date AND curr = in_currency;
  459. ELSE
  460. SELECT INTO out_exrate sell
  461. FROM exchangerate
  462. WHERE transdate = in_date AND curr = in_currency;
  463. END IF;
  464. RETURN out_exrate;
  465. END;
  466. $$ language plpgsql;
  467. COMMENT ON FUNCTION currency_get_exchangerate(in_currency char(3), in_date date, in_account_class int) IS
  468. $$ This function return the exchange rate of a given currency, date and exchange rate class (buy or sell). $$;
  469. CREATE OR REPLACE FUNCTION payment_get_vc_info(in_entity_id int)
  470. RETURNS SETOF entity AS
  471. $$
  472. DECLARE
  473. out_info entity%ROWTYPE;
  474. BEGIN
  475. FOR out_info IN
  476. SELECT e.id, e.name FROM entity e
  477. JOIN company c ON (e.id = c.entity_id)
  478. WHERE e.id = in_entity_id
  479. --SELECT e.id, c.legal_name, l.line_one, l.city_province, cy.name FROM entity e
  480. --JOIN company c ON (e.id = c.entity_id)
  481. --JOIN company_to_location cl ON (c.id = cl.company_id)
  482. --JOIN location l ON (l.id = cl.location_id)
  483. --JOIN country cy ON (cy.id = l.country_id)
  484. LOOP
  485. return next out_info;
  486. END LOOP;
  487. IF NOT FOUND THEN
  488. RAISE EXCEPTION 'ID % not found', in_entity_id;
  489. END IF;
  490. END;
  491. $$ language plpgsql;
  492. COMMENT ON FUNCTION payment_get_vc_info(in_entity_id int) IS
  493. $$ This function return vendor or customer info, its under construction $$;
  494. CREATE TYPE payment_record AS (
  495. amount numeric,
  496. meta_number text,
  497. credit_id int,
  498. company_paid text,
  499. accounts text[],
  500. source text,
  501. date_paid date
  502. );
  503. CREATE OR REPLACE FUNCTION payment__search
  504. (in_source text, in_date_from date, in_date_to date, in_credit_id int,
  505. in_cash_accno text, in_account_class int)
  506. RETURNS SETOF payment_record AS
  507. $$
  508. DECLARE
  509. out_row payment_record;
  510. BEGIN
  511. FOR out_row IN
  512. select sum(CASE WHEN c.entity_class = 1 then a.amount
  513. ELSE a.amount * -1 END), c.meta_number,
  514. c.id, co.legal_name,
  515. compound_array(ARRAY[ARRAY[ch.id::text, ch.accno,
  516. ch.description]]), a.source, a.transdate
  517. FROM entity_credit_account c
  518. JOIN ( select entity_credit_account, id
  519. FROM ar WHERE in_account_class = 2
  520. UNION
  521. SELECT entity_credit_account, id
  522. FROM ap WHERE in_account_class = 1
  523. ) arap ON (arap.entity_credit_account = c.id)
  524. JOIN acc_trans a ON (arap.id = a.trans_id)
  525. JOIN chart ch ON (ch.id = a.chart_id)
  526. JOIN company co ON (c.entity_id = co.entity_id)
  527. WHERE (ch.accno = in_cash_accno)
  528. AND (c.id = in_credit_id OR in_credit_id IS NULL)
  529. AND (a.transdate >= in_date_from
  530. OR in_date_from IS NULL)
  531. AND (a.transdate <= in_date_to OR in_date_to IS NULL)
  532. AND (source = in_source OR in_source IS NULL)
  533. GROUP BY c.meta_number, c.id, co.legal_name, a.transdate,
  534. a.source
  535. ORDER BY a.transdate, c.meta_number, a.source
  536. LOOP
  537. RETURN NEXT out_row;
  538. END LOOP;
  539. END;
  540. $$ language plpgsql;
  541. CREATE OR REPLACE FUNCTION payment__reverse
  542. (in_source text, in_date_paid date, in_credit_id int, in_cash_accno text,
  543. in_date_reversed date, in_account_class int, in_batch_id int)
  544. RETURNS INT
  545. AS $$
  546. DECLARE
  547. pay_row record;
  548. t_voucher_id int;
  549. t_voucher_inserted bool;
  550. BEGIN
  551. IF in_batch_id IS NOT NULL THEN
  552. t_voucher_id := nextval('voucher_id_seq');
  553. t_voucher_inserted := FALSE;
  554. END IF;
  555. FOR pay_row IN
  556. SELECT a.*, c.ar_ap_account_id
  557. FROM acc_trans a
  558. JOIN (select id, entity_credit_account
  559. FROM ar WHERE in_account_class = 2
  560. UNION
  561. SELECT id, entity_credit_account
  562. FROM ap WHERE in_account_class = 1
  563. ) arap ON (a.trans_id = arap.id)
  564. JOIN entity_credit_account c
  565. ON (arap.entity_credit_account = c.id)
  566. JOIN chart ch ON (a.chart_id = ch.id)
  567. WHERE coalesce(source, '') = coalesce(in_source, '')
  568. AND transdate = in_date_paid
  569. AND in_credit_id = c.id
  570. AND in_cash_accno = ch.accno
  571. LOOP
  572. IF in_batch_id IS NOT NULL
  573. AND t_voucher_inserted IS NOT TRUE
  574. THEN
  575. INSERT INTO voucher
  576. (id, trans_id, batch_id, batch_class)
  577. VALUES
  578. (t_voucher_id, pay_row.trans_id, in_batch_id,
  579. CASE WHEN in_account_class = 1 THEN 4
  580. WHEN in_account_class = 2 THEN 7
  581. END);
  582. t_voucher_inserted := TRUE;
  583. END IF;
  584. INSERT INTO acc_trans
  585. (trans_id, chart_id, amount, transdate, source, memo, approved,
  586. voucher_id)
  587. VALUES
  588. (pay_row.trans_id, pay_row.chart_id, pay_row.amount * -1,
  589. in_date_reversed, in_source, 'Reversing ' ||
  590. COALESCE(in_source, ''),
  591. case when in_batch_id is not null then false
  592. else true end, t_voucher_id),
  593. (pay_row.trans_id, pay_row.ar_ap_account_id, pay_row.amount,
  594. in_date_reversed, in_source, 'Reversing ' ||
  595. COALESCE(in_source, ''),
  596. case when in_batch_id is not null then false
  597. else true end, t_voucher_id);
  598. IF in_account_class = 1 THEN
  599. UPDATE ap SET paid = amount -
  600. (SELECT sum(a.amount)
  601. FROM acc_trans a
  602. JOIN chart c ON (a.chart_id = c.id)
  603. WHERE c.link = 'AP'
  604. AND trans_id = pay_row.trans_id
  605. )
  606. WHERE id = pay_row.trans_id;
  607. ELSIF in_account_class = 2 THEN
  608. update ar SET paid = amount -
  609. (SELECT sum(a.amount)
  610. FROM acc_trans a
  611. JOIN chart c ON (a.chart_id = c.id)
  612. WHERE c.link = 'AR'
  613. AND trans_id = pay_row.trans_id
  614. ) * -1
  615. WHERE id = pay_row.trans_id;
  616. ELSE
  617. RAISE EXCEPTION 'Unknown account class for payments %',
  618. in_account_class;
  619. END IF;
  620. END LOOP;
  621. RETURN 1;
  622. END;
  623. $$ LANGUAGE PLPGSQL;