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