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