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