summaryrefslogtreecommitdiff
path: root/sql/modules/Payment.sql
blob: 56eb0e9ddeead512abff588787cce39136e70e1f (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. );
  110. CREATE OR REPLACE FUNCTION payment_get_all_contact_invoices
  111. (in_account_class int, in_business_id int, in_currency char(3),
  112. in_date_from date, in_date_to date, in_batch_id int,
  113. in_ar_ap_accno text)
  114. RETURNS SETOF payment_contact_invoice AS
  115. $$
  116. DECLARE payment_item payment_contact_invoice;
  117. BEGIN
  118. FOR payment_item IN
  119. SELECT c.id AS contact_id, e.name AS contact_name,
  120. c.meta_number AS account_number,
  121. sum(a.amount - a.paid) AS total_due,
  122. compound_array(ARRAY[[
  123. a.id::text, a.invnumber, a.transdate::text,
  124. a.amount::text, a.paid::text,
  125. (CASE WHEN c.discount_terms
  126. > extract('days' FROM age(a.transdate))
  127. THEN 0
  128. ELSE (a.amount - coalesce(a.paid, 0)) * coalesce(c.discount, 0) / 100
  129. END)::text,
  130. (a.amount - coalesce(a.paid, 0) -
  131. (CASE WHEN c.discount_terms
  132. > extract('days' FROM age(a.transdate))
  133. THEN 0
  134. ELSE (a.amount - coalesce(a.paid, 0)) * coalesce(c.discount, 0) / 100
  135. END))::text]]),
  136. bool_and(lock_record(a.id, (select max(session_id) FROM "session" where users_id = (
  137. select id from users WHERE username =
  138. SESSION_USER))))
  139. FROM entity e
  140. JOIN entity_credit_account c ON (e.id = c.entity_id)
  141. JOIN (SELECT id, invnumber, transdate, amount, entity_id,
  142. paid, curr, 1 as invoice_class,
  143. entity_credit_account, on_hold
  144. FROM ap
  145. UNION
  146. SELECT id, invnumber, transdate, amount, entity_id,
  147. paid, curr, 2 as invoice_class,
  148. entity_credit_account, on_hold
  149. FROM ar
  150. ORDER BY transdate
  151. ) a USING (entity_id)
  152. JOIN transactions t ON (a.id = t.id)
  153. WHERE a.id IN (select voucher.trans_id FROM voucher
  154. WHERE batch_id = in_batch_id)
  155. OR (a.invoice_class = in_account_class
  156. AND c.business_id =
  157. coalesce(in_business_id, c.business_id)
  158. AND ((a.transdate >= COALESCE(in_date_from, a.transdate)
  159. AND a.transdate <= COALESCE(in_date_to, a.transdate)))
  160. AND c.entity_class = in_account_class
  161. AND a.curr = in_currency
  162. AND a.entity_credit_account = c.id
  163. AND a.amount - a.paid <> 0
  164. AND NOT a.on_hold
  165. AND NOT (t.locked_by IS NOT NULL AND t.locked_by IN
  166. (select "session_id" FROM "session"
  167. WHERE users_id IN
  168. (select id from users
  169. where username <> SESSION_USER)))
  170. AND EXISTS (select trans_id FROM acc_trans
  171. WHERE trans_id = a.id AND
  172. chart_id = (SELECT id frOM chart
  173. WHERE accno
  174. = in_ar_ap_accno)
  175. ))
  176. GROUP BY c.id, e.name, c.meta_number, c.threshold
  177. HAVING sum(a.amount - a.paid) > c.threshold
  178. LOOP
  179. RETURN NEXT payment_item;
  180. END LOOP;
  181. END;
  182. $$ LANGUAGE plpgsql;
  183. COMMENT ON FUNCTION payment_get_all_contact_invoices
  184. (in_account_class int, in_business_type int, in_currency char(3),
  185. in_date_from date, in_date_to date, in_batch_id int,
  186. in_ar_ap_accno text) IS
  187. $$
  188. This function takes the following arguments (all prefaced with in_ in the db):
  189. account_class: 1 for vendor, 2 for customer
  190. business_type: integer of business.id.
  191. currency: char(3) of currency (for example 'USD')
  192. date_from, date_to: These dates are inclusive.
  193. 1;3B
  194. batch_id: For payment batches, where fees are concerned.
  195. ar_ap_accno: The AR/AP account number.
  196. This then returns a set of contact information with a 2 dimensional array
  197. cnsisting of outstanding invoices.
  198. $$;
  199. CREATE OR REPLACE FUNCTION payment_bulk_queue
  200. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  201. in_ar_ap_accno text, in_cash_accno text,
  202. in_payment_date date, in_account_class int)
  203. returns int as
  204. $$
  205. BEGIN
  206. INSERT INTO payments_queue
  207. (transactions, batch_id, source, total, ar_ap_accno, cash_accno,
  208. payment_date, account_class)
  209. VALUES
  210. (in_transactions, in_batch_id, in_source, in_total, in_ar_ap_accno,
  211. in_cash_accno, in_payment_date, in_account_class);
  212. RETURN array_upper(in_transactions, 1) -
  213. array_lower(in_transactions, 1);
  214. END;
  215. $$ LANGUAGE PLPGSQL;
  216. CREATE OR REPLACE FUNCTION job__process_payment(in_job_id int)
  217. RETURNS bool AS $$
  218. DECLARE
  219. queue_record RECORD;
  220. t_auth_name text;
  221. t_counter int;
  222. BEGIN
  223. -- TODO: Move the set session authorization into a utility function
  224. SELECT entered_by INTO t_auth_name FROM pending_job
  225. WHERE id = in_job_id;
  226. EXECUTE 'SET SESSION AUTHORIZATION ' || quote_ident(t_auth_name);
  227. t_counter := 0;
  228. FOR queue_record IN
  229. SELECT *
  230. FROM payments_queue WHERE job_id = in_job_id
  231. LOOP
  232. PERFORM payment_bulk_post
  233. (queue_record.transactions, queue_record.batch_id,
  234. queue_record.source, queue_record.total,
  235. queue_record.ar_ap_accno,
  236. queue_record.cash_accno,
  237. queue_record.payment_date,
  238. queue_record.account_class);
  239. t_counter := t_counter + 1;
  240. RAISE NOTICE 'Processed record %, starting transaction %',
  241. t_counter, queue_record.transactions[1][1];
  242. END LOOP;
  243. DELETE FROM payments_queue WHERE job_id = in_job_id;
  244. UPDATE pending_job
  245. SET completed_at = timeofday()::timestamp,
  246. success = true
  247. WHERE id = in_job_id;
  248. RETURN TRUE;
  249. END;
  250. $$ language plpgsql;
  251. CREATE OR REPLACE FUNCTION job__create(in_batch_class int, in_batch_id int)
  252. RETURNS int AS
  253. $$
  254. BEGIN
  255. INSERT INTO pending_job (batch_class, batch_id)
  256. VALUES (coalesce(in_batch_class, 3), in_batch_id);
  257. RETURN currval('pending_job_id_seq');
  258. END;
  259. $$ LANGUAGE PLPGSQL;
  260. CREATE TYPE job__status AS (
  261. completed int, -- 1 for completed, 0 for no
  262. success int, -- 1 for success, 0 for no
  263. completed_at timestamp,
  264. error_condition text -- error if not successful
  265. );
  266. CREATE OR REPLACE FUNCTION job__status(in_job_id int) RETURNS job__status AS
  267. $$
  268. DECLARE out_row job__status;
  269. BEGIN
  270. SELECT (completed_at IS NULL)::INT, success::int, completed_at,
  271. error_condition
  272. INTO out_row
  273. FROM pending_job
  274. WHERE id = in_job_id;
  275. RETURN out_row;
  276. END;
  277. $$ language plpgsql;
  278. CREATE OR REPLACE FUNCTION payment_bulk_post
  279. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  280. in_ar_ap_accno text, in_cash_accno text,
  281. in_payment_date date, in_account_class int)
  282. RETURNS int AS
  283. $$
  284. DECLARE
  285. payment_trans numeric[];
  286. out_count int;
  287. t_voucher_id int;
  288. t_trans_id int;
  289. t_amount numeric;
  290. BEGIN
  291. IF in_batch_id IS NULL THEN
  292. -- t_voucher_id := NULL;
  293. RAISE EXCEPTION 'Bulk Post Must be from Batch!';
  294. ELSE
  295. INSERT INTO voucher (batch_id, batch_class, trans_id)
  296. values (in_batch_id, 3, in_transactions[1][1]);
  297. t_voucher_id := currval('voucher_id_seq');
  298. END IF;
  299. FOR out_count IN
  300. array_lower(in_transactions, 1) ..
  301. array_upper(in_transactions, 1)
  302. LOOP
  303. INSERT INTO acc_trans
  304. (trans_id, chart_id, amount, approved, voucher_id,
  305. transdate)
  306. VALUES
  307. (in_transactions[out_count][1],
  308. case when in_account_class = 1 THEN
  309. (SELECT id FROM chart
  310. WHERE accno = in_cash_accno)
  311. WHEN in_account_class = 2 THEN
  312. (SELECT id FROM chart
  313. WHERE accno = in_ar_ap_accno)
  314. ELSE -1 END,
  315. in_transactions[out_count][2],
  316. CASE WHEN t_voucher_id IS NULL THEN true
  317. ELSE false END,
  318. t_voucher_id, in_payment_date),
  319. (in_transactions[out_count][1],
  320. case when in_account_class = 1 THEN
  321. (SELECT id FROM chart
  322. WHERE accno = in_ar_ap_accno)
  323. WHEN in_account_class = 2 THEN
  324. (SELECT id FROM chart
  325. WHERE accno = in_cash_accno)
  326. ELSE -1 END,
  327. in_transactions[out_count][2]* -1,
  328. CASE WHEN t_voucher_id IS NULL THEN true
  329. ELSE false END,
  330. t_voucher_id, in_payment_date);
  331. UPDATE ap
  332. set paid = paid +in_transactions[out_count][2]
  333. where id =in_transactions[out_count][1];
  334. END LOOP;
  335. return out_count;
  336. END;
  337. $$ language plpgsql;
  338. COMMENT ON FUNCTION payment_bulk_post
  339. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  340. in_ar_ap_accno text, in_cash_accno text,
  341. in_payment_date date, in_account_class int)
  342. IS
  343. $$ Note that in_transactions is a two-dimensional numeric array. Of each
  344. sub-array, the first element is the (integer) transaction id, and the second
  345. is the amount for that transaction. If the total of the amounts do not add up
  346. to in_total, then an error is generated. $$;
  347. CREATE OR REPLACE FUNCTION payment_post
  348. (in_trans_id int, in_batch_id int, in_source text, in_amount numeric,
  349. in_ar_ap_accno text, in_cash_accno text, in_approved bool,
  350. in_payment_date date, in_account_class int)
  351. RETURNS INT AS
  352. $$
  353. DECLARE out_entry_id int;
  354. BEGIN
  355. INSERT INTO acc_trans (chart_id, amount,
  356. trans_id, transdate, approved, source)
  357. VALUES ((SELECT id FROM chart WHERE accno = in_ar_ap_accno),
  358. CASE WHEN in_account_class = 1 THEN in_amount * -1
  359. ELSE amount
  360. END,
  361. in_trans_id, in_payment_date, in_approved, in_source);
  362. INSERT INTO acc_trans (chart_id, amount,
  363. trans_id, transdate, approved, source)
  364. VALUES ((SELECT id FROM chart WHERE accno = in_cash_accno),
  365. CASE WHEN in_account_class = 2 THEN in_amount * -1
  366. ELSE amount
  367. END,
  368. in_trans_id, in_payment_date, coalesce(in_approved, true),
  369. in_source);
  370. SELECT currval('acc_trans_entry_id_seq') INTO out_entry_id;
  371. RETURN out_entry_id;
  372. END;
  373. $$ LANGUAGE PLPGSQL;
  374. COMMENT ON FUNCTION payment_post
  375. (in_trans_id int, in_source text, in_amount numeric, in_ar_ap_accno text,
  376. in_cash_accno text, in_approved bool, in_payment_date date,
  377. in_account_class int)
  378. IS $$
  379. This function takes the following arguments (prefaced with in_ in the db):
  380. trans_id: Id for ar/ap transaction.
  381. source: text for source documnet identifier (for example, check number)
  382. amount: numeric for the amount of the transaction
  383. ar_ap_accno: AR/AP account number
  384. cash_accno: Cash Account number, i.e. the account where the payment will be
  385. held
  386. approved: False, for a voucher.
  387. This function posts the payment or saves the payment voucher.
  388. $$;
  389. -- Move this to the projects module when we start on that. CT
  390. CREATE OR REPLACE FUNCTION project_list_open(in_date date)
  391. RETURNS SETOF project AS
  392. $$
  393. DECLARE out_project project%ROWTYPE;
  394. BEGIN
  395. FOR out_project IN
  396. SELECT * from project
  397. WHERE startdate <= in_date AND enddate >= in_date
  398. AND completed = 0
  399. LOOP
  400. return next out_project;
  401. END LOOP;
  402. END;
  403. $$ language plpgsql;
  404. comment on function project_list_open(in_date date) is
  405. $$ This function returns all projects that were open as on the date provided as
  406. the argument.$$;
  407. -- Move this to the projects module when we start on that. CT
  408. CREATE OR REPLACE FUNCTION department_list(in_role char)
  409. RETURNS SETOF department AS
  410. $$
  411. DECLARE out_department department%ROWTYPE;
  412. BEGIN
  413. FOR out_department IN
  414. SELECT * from department
  415. WHERE role = coalesce(in_role, role)
  416. LOOP
  417. return next out_department;
  418. END LOOP;
  419. END;
  420. $$ language plpgsql;
  421. -- Move this into another module.
  422. comment on function department_list(in_role char) is
  423. $$ This function returns all department that match the role provided as
  424. the argument.$$;
  425. CREATE OR REPLACE FUNCTION payments_get_open_currencies(in_account_class int)
  426. RETURNS SETOF char(3) AS
  427. $$
  428. DECLARE resultrow record;
  429. BEGIN
  430. FOR resultrow IN
  431. SELECT curr AS curr FROM ar
  432. WHERE amount <> paid
  433. OR paid IS NULL
  434. AND in_account_class=2
  435. UNION
  436. SELECT curr FROM ap
  437. WHERE amount <> paid
  438. OR paid IS NULL
  439. AND in_account_class=1
  440. ORDER BY curr
  441. LOOP
  442. return next resultrow.curr;
  443. END LOOP;
  444. END;
  445. $$ language plpgsql;
  446. CREATE OR REPLACE FUNCTION currency_get_exchangerate(in_currency char(3), in_date date, in_account_class int)
  447. RETURNS NUMERIC AS
  448. $$
  449. DECLARE
  450. out_exrate exchangerate.buy%TYPE;
  451. BEGIN
  452. IF in_account_class = 1 THEN
  453. SELECT INTO out_exrate buy
  454. FROM exchangerate
  455. WHERE transdate = in_date AND curr = in_currency;
  456. ELSE
  457. SELECT INTO out_exrate sell
  458. FROM exchangerate
  459. WHERE transdate = in_date AND curr = in_currency;
  460. END IF;
  461. RETURN out_exrate;
  462. END;
  463. $$ language plpgsql;
  464. COMMENT ON FUNCTION currency_get_exchangerate(in_currency char(3), in_date date, in_account_class int) IS
  465. $$ This function return the exchange rate of a given currency, date and exchange rate class (buy or sell). $$;
  466. CREATE OR REPLACE FUNCTION payment_get_vc_info(in_entity_id int)
  467. RETURNS SETOF entity AS
  468. $$
  469. DECLARE
  470. out_info entity%ROWTYPE;
  471. BEGIN
  472. FOR out_info IN
  473. SELECT e.id, e.name FROM entity e
  474. JOIN company c ON (e.id = c.entity_id)
  475. WHERE e.id = in_entity_id
  476. --SELECT e.id, c.legal_name, l.line_one, l.city_province, cy.name FROM entity e
  477. --JOIN company c ON (e.id = c.entity_id)
  478. --JOIN company_to_location cl ON (c.id = cl.company_id)
  479. --JOIN location l ON (l.id = cl.location_id)
  480. --JOIN country cy ON (cy.id = l.country_id)
  481. LOOP
  482. return next out_info;
  483. END LOOP;
  484. IF NOT FOUND THEN
  485. RAISE EXCEPTION 'ID % not found', in_entity_id;
  486. END IF;
  487. END;
  488. $$ language plpgsql;
  489. COMMENT ON FUNCTION payment_get_vc_info(in_entity_id int) IS
  490. $$ This function return vendor or customer info, its under construction $$;
  491. CREATE TYPE payment_record AS (
  492. amount numeric,
  493. meta_number text,
  494. company_paid text,
  495. cash_account_id int,
  496. cash_accno text,
  497. cash_account_description text,
  498. ar_ap_account_id int,
  499. ar_ap_accno text,
  500. ar_ap_description text
  501. );
  502. CREATE OR REPLACE FUNCTION payment__retrieve
  503. (in_source text, in_meta_number text, in_account_class int, in_cash_accno text)
  504. RETURNS SETOF payment_record AS
  505. $$
  506. DECLARE out_row payment_record;
  507. BEGIN
  508. FOR out_row IN
  509. SELECT sum(case when at.amount > 0 then at.amount else 0 end)
  510. AS amount, ec.meta_number,
  511. c.legal_name, max(cc.id), max(cc.accno),
  512. max(cc.description), max(ac.id), max(ac.accno),
  513. max(ac.description)
  514. FROM acc_trans at
  515. JOIN entity_credit_account ec ON
  516. (at.trans_id IN
  517. (select id FROM ar
  518. WHERE in_account_class = 2
  519. AND entity_credit_account =
  520. (SELECT id
  521. FROM entity_credit_account
  522. WHERE meta_number
  523. = in_meta_number
  524. AND entity_class =
  525. in_account_class)
  526. UNION
  527. SELECT id FROM ap
  528. WHERE in_account_class = 1 AND
  529. entity_credit_account =
  530. (select id
  531. FROM entity_credit_account
  532. WHERE meta_number
  533. = in_meta_number
  534. AND entity_class =
  535. in_account_class)))
  536. JOIN company c ON (ec.entity_id = c.entity_id)
  537. LEFT JOIN chart cc ON (at.chart_id = cc.id AND
  538. cc.link LIKE '%paid%')
  539. JOIN chart ac ON (at.chart_id = ac.id AND
  540. ((in_account_class = 1 AND ac.link = 'AP') OR
  541. (in_account_class = 2 AND ac.link = 'AR')))
  542. WHERE source = in_source
  543. GROUP BY ec.meta_number, c.legal_name
  544. HAVING max(cc.accno) = in_cash_accno
  545. LOOP
  546. return next out_row;
  547. END LOOP;
  548. END;
  549. $$ LANGUAGE plpgsql;
  550. CREATE OR REPLACE FUNCTION payment__reverse
  551. (in_source text, in_date_paid date, in_credit_id int, in_cash_accno text)
  552. RETURNS INT
  553. AS $$
  554. DECLARE
  555. count int;
  556. BEGIN
  557. count := 0;
  558. FOR
  559. END;
  560. $$ LANGUAGE PLPGSQL;