summaryrefslogtreecommitdiff
path: root/sql/modules/Payment.sql
blob: e5b02f3cefc8810b765db4b712805d20ada3a687 (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. entity_credit_account
  80. FROM ap
  81. UNION
  82. SELECT id, invnumber, transdate, amount, entity_id,
  83. 2 AS invoice_class, paid, curr,
  84. entity_credit_account
  85. FROM ar
  86. ) a
  87. JOIN entity_credit_account c ON (c.id = a.entity_credit_account
  88. OR (a.entity_credit_account IS NULL and
  89. a.entity_id = c.entity_id))
  90. WHERE a.invoice_class = in_account_class
  91. AND c.entity_class = in_account_class
  92. AND a.amount - a.paid <> 0
  93. AND a.curr = in_curr
  94. LOOP
  95. RETURN NEXT payment_inv;
  96. END LOOP;
  97. END;
  98. $$ LANGUAGE PLPGSQL;
  99. COMMENT ON FUNCTION payment_get_open_invoices(int, int, char(3)) IS
  100. $$ This function takes three arguments:
  101. Type: 1 for vendor, 2 for customer
  102. Entity_id: The entity_id of the customer or vendor
  103. Currency: 3 characters for currency ('USD' for example).
  104. Returns all open invoices for the entity in question. $$;
  105. CREATE TYPE payment_contact_invoice AS (
  106. contact_id int,
  107. contact_name text,
  108. account_number text,
  109. total_due numeric,
  110. invoices text[],
  111. has_vouchers int
  112. );
  113. CREATE OR REPLACE FUNCTION payment_get_all_contact_invoices
  114. (in_account_class int, in_business_id int, in_currency char(3),
  115. in_date_from date, in_date_to date, in_batch_id int,
  116. in_ar_ap_accno text)
  117. RETURNS SETOF payment_contact_invoice AS
  118. $$
  119. DECLARE payment_item payment_contact_invoice;
  120. BEGIN
  121. FOR payment_item IN
  122. SELECT c.id AS contact_id, e.name AS contact_name,
  123. c.meta_number AS account_number,
  124. sum(a.amount - a.paid) AS total_due,
  125. compound_array(ARRAY[[
  126. a.id::text, a.invnumber, a.transdate::text,
  127. a.amount::text, a.paid::text,
  128. (CASE WHEN c.discount_terms
  129. > extract('days' FROM age(a.transdate))
  130. THEN 0
  131. ELSE (a.amount - coalesce(a.paid, 0)) * coalesce(c.discount, 0) / 100
  132. END)::text,
  133. (a.amount - coalesce(a.paid, 0) -
  134. (CASE WHEN c.discount_terms
  135. > extract('days' FROM age(a.transdate))
  136. THEN 0
  137. ELSE (a.amount - coalesce(a.paid, 0)) * coalesce(c.discount, 0) / 100
  138. END))::text]]),
  139. sum(case when v.batch_id = in_batch_id then 1
  140. else 0 END),
  141. bool_and(lock_record(a.id, (select max(session_id) FROM "session" where users_id = (
  142. select id from users WHERE username =
  143. SESSION_USER))))
  144. FROM entity e
  145. JOIN entity_credit_account c ON (e.id = c.entity_id)
  146. JOIN (SELECT id, invnumber, transdate, amount, entity_id,
  147. paid, curr, 1 as invoice_class,
  148. entity_credit_account, on_hold
  149. FROM ap
  150. WHERE in_account_class = 1
  151. UNION
  152. SELECT id, invnumber, transdate, amount, entity_id,
  153. paid, curr, 2 as invoice_class,
  154. entity_credit_account, on_hold
  155. FROM ar
  156. WHERE in_account_class = 2
  157. ORDER BY transdate
  158. ) a USING (entity_id)
  159. JOIN transactions t ON (a.id = t.id)
  160. LEFT JOIN voucher v ON (v.trans_id = a.id)
  161. WHERE v.batch_id = in_batch_id
  162. OR (a.invoice_class = in_account_class
  163. AND c.business_id =
  164. coalesce(in_business_id, c.business_id)
  165. AND ((a.transdate >= COALESCE(in_date_from, a.transdate)
  166. AND a.transdate <= COALESCE(in_date_to, a.transdate)))
  167. AND c.entity_class = in_account_class
  168. AND a.curr = in_currency
  169. AND a.entity_credit_account = c.id
  170. AND a.amount - a.paid <> 0
  171. AND NOT a.on_hold
  172. AND NOT (t.locked_by IS NOT NULL AND t.locked_by IN
  173. (select "session_id" FROM "session"
  174. WHERE users_id IN
  175. (select id from users
  176. where username <> SESSION_USER)))
  177. AND EXISTS (select trans_id FROM acc_trans
  178. WHERE trans_id = a.id AND
  179. chart_id = (SELECT id frOM chart
  180. WHERE accno
  181. = in_ar_ap_accno)
  182. ))
  183. GROUP BY c.id, e.name, c.meta_number, c.threshold
  184. HAVING sum(a.amount - a.paid) > c.threshold
  185. OR sum(case when v.batch_id = in_batch_id then 1
  186. else 0 END) > 0
  187. LOOP
  188. RETURN NEXT payment_item;
  189. END LOOP;
  190. END;
  191. $$ LANGUAGE plpgsql;
  192. COMMENT ON FUNCTION payment_get_all_contact_invoices
  193. (in_account_class int, in_business_type int, in_currency char(3),
  194. in_date_from date, in_date_to date, in_batch_id int,
  195. in_ar_ap_accno text) IS
  196. $$
  197. This function takes the following arguments (all prefaced with in_ in the db):
  198. account_class: 1 for vendor, 2 for customer
  199. business_type: integer of business.id.
  200. currency: char(3) of currency (for example 'USD')
  201. date_from, date_to: These dates are inclusive.
  202. 1;3B
  203. batch_id: For payment batches, where fees are concerned.
  204. ar_ap_accno: The AR/AP account number.
  205. This then returns a set of contact information with a 2 dimensional array
  206. cnsisting of outstanding invoices.
  207. $$;
  208. CREATE OR REPLACE FUNCTION payment_bulk_queue
  209. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  210. in_ar_ap_accno text, in_cash_accno text,
  211. in_payment_date date, in_account_class int)
  212. returns int as
  213. $$
  214. BEGIN
  215. INSERT INTO payments_queue
  216. (transactions, batch_id, source, total, ar_ap_accno, cash_accno,
  217. payment_date, account_class)
  218. VALUES
  219. (in_transactions, in_batch_id, in_source, in_total, in_ar_ap_accno,
  220. in_cash_accno, in_payment_date, in_account_class);
  221. RETURN array_upper(in_transactions, 1) -
  222. array_lower(in_transactions, 1);
  223. END;
  224. $$ LANGUAGE PLPGSQL;
  225. CREATE OR REPLACE FUNCTION job__process_payment(in_job_id int)
  226. RETURNS bool AS $$
  227. DECLARE
  228. queue_record RECORD;
  229. t_auth_name text;
  230. t_counter int;
  231. BEGIN
  232. -- TODO: Move the set session authorization into a utility function
  233. SELECT entered_by INTO t_auth_name FROM pending_job
  234. WHERE id = in_job_id;
  235. EXECUTE 'SET SESSION AUTHORIZATION ' || quote_ident(t_auth_name);
  236. t_counter := 0;
  237. FOR queue_record IN
  238. SELECT *
  239. FROM payments_queue WHERE job_id = in_job_id
  240. LOOP
  241. PERFORM payment_bulk_post
  242. (queue_record.transactions, queue_record.batch_id,
  243. queue_record.source, queue_record.total,
  244. queue_record.ar_ap_accno,
  245. queue_record.cash_accno,
  246. queue_record.payment_date,
  247. queue_record.account_class);
  248. t_counter := t_counter + 1;
  249. RAISE NOTICE 'Processed record %, starting transaction %',
  250. t_counter, queue_record.transactions[1][1];
  251. END LOOP;
  252. DELETE FROM payments_queue WHERE job_id = in_job_id;
  253. UPDATE pending_job
  254. SET completed_at = timeofday()::timestamp,
  255. success = true
  256. WHERE id = in_job_id;
  257. RETURN TRUE;
  258. END;
  259. $$ language plpgsql;
  260. CREATE OR REPLACE FUNCTION job__create(in_batch_class int, in_batch_id int)
  261. RETURNS int AS
  262. $$
  263. BEGIN
  264. INSERT INTO pending_job (batch_class, batch_id)
  265. VALUES (coalesce(in_batch_class, 3), in_batch_id);
  266. RETURN currval('pending_job_id_seq');
  267. END;
  268. $$ LANGUAGE PLPGSQL;
  269. CREATE TYPE job__status AS (
  270. completed int, -- 1 for completed, 0 for no
  271. success int, -- 1 for success, 0 for no
  272. completed_at timestamp,
  273. error_condition text -- error if not successful
  274. );
  275. CREATE OR REPLACE FUNCTION job__status(in_job_id int) RETURNS job__status AS
  276. $$
  277. DECLARE out_row job__status;
  278. BEGIN
  279. SELECT (completed_at IS NULL)::INT, success::int, completed_at,
  280. error_condition
  281. INTO out_row
  282. FROM pending_job
  283. WHERE id = in_job_id;
  284. RETURN out_row;
  285. END;
  286. $$ language plpgsql;
  287. CREATE OR REPLACE FUNCTION payment_bulk_post
  288. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  289. in_ar_ap_accno text, in_cash_accno text,
  290. in_payment_date date, in_account_class int)
  291. RETURNS int AS
  292. $$
  293. DECLARE
  294. out_count int;
  295. t_voucher_id int;
  296. t_trans_id int;
  297. t_amount numeric;
  298. t_ar_ap_id int;
  299. t_cash_id int;
  300. BEGIN
  301. IF in_batch_id IS NULL THEN
  302. -- t_voucher_id := NULL;
  303. RAISE EXCEPTION 'Bulk Post Must be from Batch!';
  304. ELSE
  305. INSERT INTO voucher (batch_id, batch_class, trans_id)
  306. values (in_batch_id, 3, in_transactions[1][1]);
  307. t_voucher_id := currval('voucher_id_seq');
  308. END IF;
  309. select id into t_ar_ap_id from chart where accno = in_ar_ap_accno;
  310. select id into t_cash_id from chart where accno = in_cash_accno;
  311. FOR out_count IN
  312. array_lower(in_transactions, 1) ..
  313. array_upper(in_transactions, 1)
  314. LOOP
  315. INSERT INTO acc_trans
  316. (trans_id, chart_id, amount, approved, voucher_id,
  317. transdate, source)
  318. VALUES
  319. (in_transactions[out_count][1],
  320. case when in_account_class = 1 THEN t_cash_id
  321. WHEN in_account_class = 2 THEN t_ar_ap_id
  322. ELSE -1 END,
  323. in_transactions[out_count][2],
  324. CASE WHEN t_voucher_id IS NULL THEN true
  325. ELSE false END,
  326. t_voucher_id, in_payment_date, in_source),
  327. (in_transactions[out_count][1],
  328. case when in_account_class = 1 THEN t_ar_ap_id
  329. WHEN in_account_class = 2 THEN t_cash_id
  330. ELSE -1 END,
  331. in_transactions[out_count][2]* -1,
  332. CASE WHEN t_voucher_id IS NULL THEN true
  333. ELSE false END,
  334. t_voucher_id, in_payment_date, in_source);
  335. UPDATE ap
  336. set paid = paid +in_transactions[out_count][2]
  337. where id =in_transactions[out_count][1];
  338. END LOOP;
  339. return out_count;
  340. END;
  341. $$ language plpgsql;
  342. COMMENT ON FUNCTION payment_bulk_post
  343. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  344. in_ar_ap_accno text, in_cash_accno text,
  345. in_payment_date date, in_account_class int)
  346. IS
  347. $$ Note that in_transactions is a two-dimensional numeric array. Of each
  348. sub-array, the first element is the (integer) transaction id, and the second
  349. is the amount for that transaction. If the total of the amounts do not add up
  350. to in_total, then an error is generated. $$;
  351. CREATE OR REPLACE FUNCTION payment_post
  352. (in_payment_date date,
  353. in_account_class int,
  354. in_person_id int,
  355. in_currency char(3),
  356. in_notes text,
  357. in_department int,
  358. in_gl_description text,
  359. in_cash_accno int[],
  360. in_cash_amount int[],
  361. in_cash_approved bool[],
  362. in_cash_source text[],
  363. in_accno int[],
  364. in_amount int[],
  365. in_approved bool[],
  366. in_source text[],
  367. in_transaction_id int[],
  368. in_type int[],
  369. in_approved bool)
  370. RETURNS INT AS
  371. $$
  372. DECLARE var_payment_id int;
  373. DECLARE var_gl_id int;
  374. DECLARE var_entry_id int[];
  375. DECLARE out_count int;
  376. BEGIN
  377. -- FIRST WE HAVE TO INSERT THE PAYMENT
  378. -- THE ID IS GENERATED BY payment_id_seq
  379. --
  380. INSERT INTO payment (reference, payment_class, payment_date,
  381. person_id, currency, notes, department_id)
  382. VALUES ((CASE WHEN in_account_class = 1 THEN
  383. setting_increment('rcptnumber') -- I FOUND THIS ON sql/modules/Settings.sql
  384. ELSE -- and it is very usefull
  385. setting_increment('paynumber')
  386. END),
  387. in_account_class, in_payment_date, in_person_id,
  388. in_currency, in_notes, in_department);
  389. SELECT currval('payment_id_seq') INTO var_payment_id; -- WE'LL NEED THIS VALUE TO USE payment_link table
  390. -- SECOND WE HAVE TO MAKE THE GL TO HOLD THE TRANSACTIONS
  391. -- THE ID IS GENERATED BY gl_id_seq
  392. --
  393. INSERT INTO gl (reference, description, transdate,
  394. person_id, notes, approved, department_id)
  395. VALUES (setting_increment('glnumber'),
  396. in_gl_description, in_payment_date, in_person_id,
  397. in_notes, in_department, coalesce(in_approved, true));
  398. SELECT currval('id') INTO var_gl_id; -- WE'LL NEED THIS VALUE TO JOIN WITH PAYMENT
  399. -- NOW COMES THE HEAVY PART, STORING ALL THE POSSIBLE TRANSACTIONS...
  400. --
  401. -- FIRST WE SHOULD INSERT THE CASH ACCOUNTS
  402. --
  403. -- WE SHOULD HAVE THE DATA STORED AS (ACCNO, AMOUNT), SO
  404. FOR out_count IN
  405. array_lower(in_cash_accno, 1) ..
  406. array_upper(in_cash_accno, 1)
  407. LOOP
  408. INSERT INTO acc_trans (chart_id, amount,
  409. trans_id, transdate, approved, source)
  410. VALUES ((SELECT id FROM chart WHERE accno = in_cash_accno[out_count]),
  411. CASE WHEN in_account_class = 2 THEN in_cash_amount[out_count] * -1
  412. ELSE in_cash_amount[out_count]
  413. END,
  414. var_gl_id, in_payment_date, coalesce(in_cash_approved[1], true),
  415. in_cash_source[out_count]);
  416. --SELECT currval('acc_trans_entry_id_seq') INTO var_entry_id[out_count];--WE'LL NEED THIS FOR THE PAYMENT_LINK
  417. END LOOP;
  418. --
  419. -- NOW LETS HANDLE THE AR/AP/OVERPAYMENT ACCOUNT
  420. --
  421. FOR var_count IN
  422. array_lower(in_accno, 1) ..
  423. array_upper(in_accno, 1)
  424. LOOP
  425. INSERT INTO acc_trans (chart_id, amount,
  426. trans_id, transdate, approved, source)
  427. VALUES ((SELECT id FROM chart WHERE accno = in_accno[out_count]),
  428. CASE WHEN in_account_class = 2 THEN in_amount[out_count] * -1
  429. ELSE in_amount[out_count]
  430. END,
  431. var_gl_id, in_payment_date, coalesce(in_approved[1], true),
  432. in_source[out_count]);
  433. --
  434. -- WE WILL INSERT THE LINK INTO PAYMENT_LINKS NOW
  435. --
  436. INSERT INTO payment_links
  437. VALUES (var_payment_id, currval(acc_trans_entry_id_seq),
  438. in_transaction_id[out_count], in_type[var_count]);
  439. END LOOP;
  440. return 0;
  441. END;
  442. $$ LANGUAGE PLPGSQL;
  443. -- I HAVE TO MAKE A COMMENT ON THIS FUNCTION
  444. -- Move this to the projects module when we start on that. CT
  445. CREATE OR REPLACE FUNCTION project_list_open(in_date date)
  446. RETURNS SETOF project AS
  447. $$
  448. DECLARE out_project project%ROWTYPE;
  449. BEGIN
  450. FOR out_project IN
  451. SELECT * from project
  452. WHERE startdate <= in_date AND enddate >= in_date
  453. AND completed = 0
  454. LOOP
  455. return next out_project;
  456. END LOOP;
  457. END;
  458. $$ language plpgsql;
  459. comment on function project_list_open(in_date date) is
  460. $$ This function returns all projects that were open as on the date provided as
  461. the argument.$$;
  462. -- Move this to the projects module when we start on that. CT
  463. CREATE OR REPLACE FUNCTION department_list(in_role char)
  464. RETURNS SETOF department AS
  465. $$
  466. DECLARE out_department department%ROWTYPE;
  467. BEGIN
  468. FOR out_department IN
  469. SELECT * from department
  470. WHERE role = coalesce(in_role, role)
  471. LOOP
  472. return next out_department;
  473. END LOOP;
  474. END;
  475. $$ language plpgsql;
  476. -- Move this into another module.
  477. comment on function department_list(in_role char) is
  478. $$ This function returns all department that match the role provided as
  479. the argument.$$;
  480. CREATE OR REPLACE FUNCTION payments_get_open_currencies(in_account_class int)
  481. RETURNS SETOF char(3) AS
  482. $$
  483. DECLARE resultrow record;
  484. BEGIN
  485. FOR resultrow IN
  486. SELECT curr AS curr FROM ar
  487. WHERE amount <> paid
  488. OR paid IS NULL
  489. AND in_account_class=2
  490. UNION
  491. SELECT curr FROM ap
  492. WHERE amount <> paid
  493. OR paid IS NULL
  494. AND in_account_class=1
  495. ORDER BY curr
  496. LOOP
  497. return next resultrow.curr;
  498. END LOOP;
  499. END;
  500. $$ language plpgsql;
  501. CREATE OR REPLACE FUNCTION currency_get_exchangerate(in_currency char(3), in_date date, in_account_class int)
  502. RETURNS NUMERIC AS
  503. $$
  504. DECLARE
  505. out_exrate exchangerate.buy%TYPE;
  506. BEGIN
  507. IF in_account_class = 1 THEN
  508. SELECT INTO out_exrate buy
  509. FROM exchangerate
  510. WHERE transdate = in_date AND curr = in_currency;
  511. ELSE
  512. SELECT INTO out_exrate sell
  513. FROM exchangerate
  514. WHERE transdate = in_date AND curr = in_currency;
  515. END IF;
  516. RETURN out_exrate;
  517. END;
  518. $$ language plpgsql;
  519. COMMENT ON FUNCTION currency_get_exchangerate(in_currency char(3), in_date date, in_account_class int) IS
  520. $$ This function return the exchange rate of a given currency, date and exchange rate class (buy or sell). $$;
  521. CREATE OR REPLACE FUNCTION payment_get_vc_info(in_entity_id int)
  522. RETURNS SETOF entity AS
  523. $$
  524. DECLARE
  525. out_info entity%ROWTYPE;
  526. BEGIN
  527. FOR out_info IN
  528. SELECT e.id, e.name FROM entity e
  529. JOIN company c ON (e.id = c.entity_id)
  530. WHERE e.id = in_entity_id
  531. --SELECT e.id, c.legal_name, l.line_one, l.city_province, cy.name FROM entity e
  532. --JOIN company c ON (e.id = c.entity_id)
  533. --JOIN company_to_location cl ON (c.id = cl.company_id)
  534. --JOIN location l ON (l.id = cl.location_id)
  535. --JOIN country cy ON (cy.id = l.country_id)
  536. LOOP
  537. return next out_info;
  538. END LOOP;
  539. IF NOT FOUND THEN
  540. RAISE EXCEPTION 'ID % not found', in_entity_id;
  541. END IF;
  542. END;
  543. $$ language plpgsql;
  544. COMMENT ON FUNCTION payment_get_vc_info(in_entity_id int) IS
  545. $$ This function return vendor or customer info, its under construction $$;
  546. CREATE TYPE payment_record AS (
  547. amount numeric,
  548. meta_number text,
  549. credit_id int,
  550. company_paid text,
  551. accounts text[],
  552. source text,
  553. date_paid date
  554. );
  555. CREATE OR REPLACE FUNCTION payment__search
  556. (in_source text, in_date_from date, in_date_to date, in_credit_id int,
  557. in_cash_accno text, in_account_class int)
  558. RETURNS SETOF payment_record AS
  559. $$
  560. DECLARE
  561. out_row payment_record;
  562. BEGIN
  563. FOR out_row IN
  564. select sum(CASE WHEN c.entity_class = 1 then a.amount
  565. ELSE a.amount * -1 END), c.meta_number,
  566. c.id, co.legal_name,
  567. compound_array(ARRAY[ARRAY[ch.id::text, ch.accno,
  568. ch.description]]), a.source, a.transdate
  569. FROM entity_credit_account c
  570. JOIN ( select entity_credit_account, id
  571. FROM ar WHERE in_account_class = 2
  572. UNION
  573. SELECT entity_credit_account, id
  574. FROM ap WHERE in_account_class = 1
  575. ) arap ON (arap.entity_credit_account = c.id)
  576. JOIN acc_trans a ON (arap.id = a.trans_id)
  577. JOIN chart ch ON (ch.id = a.chart_id)
  578. JOIN company co ON (c.entity_id = co.entity_id)
  579. WHERE (ch.accno = in_cash_accno)
  580. AND (c.id = in_credit_id OR in_credit_id IS NULL)
  581. AND (a.transdate >= in_date_from
  582. OR in_date_from IS NULL)
  583. AND (a.transdate <= in_date_to OR in_date_to IS NULL)
  584. AND (source = in_source OR in_source IS NULL)
  585. GROUP BY c.meta_number, c.id, co.legal_name, a.transdate,
  586. a.source
  587. ORDER BY a.transdate, c.meta_number, a.source
  588. LOOP
  589. RETURN NEXT out_row;
  590. END LOOP;
  591. END;
  592. $$ language plpgsql;
  593. CREATE OR REPLACE FUNCTION payment__reverse
  594. (in_source text, in_date_paid date, in_credit_id int, in_cash_accno text,
  595. in_date_reversed date, in_account_class int, in_batch_id int)
  596. RETURNS INT
  597. AS $$
  598. DECLARE
  599. pay_row record;
  600. t_voucher_id int;
  601. t_voucher_inserted bool;
  602. BEGIN
  603. IF in_batch_id IS NOT NULL THEN
  604. t_voucher_id := nextval('voucher_id_seq');
  605. t_voucher_inserted := FALSE;
  606. END IF;
  607. FOR pay_row IN
  608. SELECT a.*, c.ar_ap_account_id
  609. FROM acc_trans a
  610. JOIN (select id, entity_credit_account
  611. FROM ar WHERE in_account_class = 2
  612. UNION
  613. SELECT id, entity_credit_account
  614. FROM ap WHERE in_account_class = 1
  615. ) arap ON (a.trans_id = arap.id)
  616. JOIN entity_credit_account c
  617. ON (arap.entity_credit_account = c.id)
  618. JOIN chart ch ON (a.chart_id = ch.id)
  619. WHERE coalesce(source, '') = coalesce(in_source, '')
  620. AND transdate = in_date_paid
  621. AND in_credit_id = c.id
  622. AND in_cash_accno = ch.accno
  623. LOOP
  624. IF in_batch_id IS NOT NULL
  625. AND t_voucher_inserted IS NOT TRUE
  626. THEN
  627. INSERT INTO voucher
  628. (id, trans_id, batch_id, batch_class)
  629. VALUES
  630. (t_voucher_id, pay_row.trans_id, in_batch_id,
  631. CASE WHEN in_account_class = 1 THEN 4
  632. WHEN in_account_class = 2 THEN 7
  633. END);
  634. t_voucher_inserted := TRUE;
  635. END IF;
  636. INSERT INTO acc_trans
  637. (trans_id, chart_id, amount, transdate, source, memo, approved,
  638. voucher_id)
  639. VALUES
  640. (pay_row.trans_id, pay_row.chart_id, pay_row.amount * -1,
  641. in_date_reversed, in_source, 'Reversing ' ||
  642. COALESCE(in_source, ''),
  643. case when in_batch_id is not null then false
  644. else true end, t_voucher_id),
  645. (pay_row.trans_id, pay_row.ar_ap_account_id, pay_row.amount,
  646. in_date_reversed, in_source, 'Reversing ' ||
  647. COALESCE(in_source, ''),
  648. case when in_batch_id is not null then false
  649. else true end, t_voucher_id);
  650. IF in_account_class = 1 THEN
  651. UPDATE ap SET paid = amount -
  652. (SELECT sum(a.amount)
  653. FROM acc_trans a
  654. JOIN chart c ON (a.chart_id = c.id)
  655. WHERE c.link = 'AP'
  656. AND trans_id = pay_row.trans_id
  657. )
  658. WHERE id = pay_row.trans_id;
  659. ELSIF in_account_class = 2 THEN
  660. update ar SET paid = amount -
  661. (SELECT sum(a.amount)
  662. FROM acc_trans a
  663. JOIN chart c ON (a.chart_id = c.id)
  664. WHERE c.link = 'AR'
  665. AND trans_id = pay_row.trans_id
  666. ) * -1
  667. WHERE id = pay_row.trans_id;
  668. ELSE
  669. RAISE EXCEPTION 'Unknown account class for payments %',
  670. in_account_class;
  671. END IF;
  672. END LOOP;
  673. RETURN 1;
  674. END;
  675. $$ LANGUAGE PLPGSQL;