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