summaryrefslogtreecommitdiff
path: root/sql/modules/Voucher.sql
blob: b6ac7be94797f107a0502866d0aa285ed0f082a7 (plain)
  1. CREATE OR REPLACE FUNCTION voucher_get_batch (in_batch_id integer)
  2. RETURNS batch AS
  3. $$
  4. DECLARE
  5. batch_out batch%ROWTYPE;
  6. BEGIN
  7. SELECT * INTO batch_out FROM batch b WHERE b.id = in_batch_id;
  8. RETURN batch_out;
  9. END;
  10. $$ language plpgsql;
  11. CREATE OR REPLACE FUNCTION batch_update (in_batch text, in_login varchar, in_entered date,
  12. in_batch_number text, in_description text, in_id integer)
  13. RETURNS integer AS
  14. $$
  15. BEGIN
  16. UPDATE batch
  17. SET batch_number = in_batch_number,
  18. description = in_description,
  19. entered = in_entered
  20. WHERE id = in_id;
  21. IF FOUND THEN
  22. RETURN in_id;
  23. END IF;
  24. INSERT INTO batch (batch, employee_id, batch_number, description,
  25. entered)
  26. VALUES (in_batch, (SELECT id FROM employees WHERE login = in_login),
  27. in_batch_number, description);
  28. RETURN currval('id');
  29. END;
  30. $$ LANGUAGE PLPGSQL;
  31. CREATE TYPE voucher_list AS (
  32. id int,
  33. reference text,
  34. description text,
  35. batch_id int,
  36. transaction_id integer,
  37. amount numeric,
  38. transaction_date date,
  39. batch_class text
  40. );
  41. CREATE OR REPLACE FUNCTION voucher_list (in_batch_id integer)
  42. RETURNS SETOF voucher_list AS
  43. $$
  44. declare voucher_item record;
  45. BEGIN
  46. FOR voucher_item IN
  47. SELECT v.id, a.invnumber, e.name,
  48. v.batch_id, v.trans_id,
  49. a.amount, a.transdate, 'Payable'
  50. FROM voucher v
  51. JOIN ap a ON (v.trans_id = a.id)
  52. JOIN entity_credit_account eca
  53. ON (eca.id = a.entity_credit_account)
  54. JOIN entity e ON (eca.entity_id = e.id)
  55. WHERE v.batch_id = in_batch_id
  56. AND v.batch_class = (select id from batch_class
  57. WHERE class = 'ap')
  58. UNION
  59. SELECT v.id, a.invnumber, e.name,
  60. v.batch_id, v.trans_id,
  61. a.amount, a.transdate, 'Receivable'
  62. FROM voucher v
  63. JOIN ar a ON (v.trans_id = a.id)
  64. JOIN entity_credit_account eca
  65. ON (eca.id = a.entity_credit_account)
  66. JOIN entity e ON (eca.entity_id = e.id)
  67. WHERE v.batch_id = in_batch_id
  68. AND v.batch_class = (select id from batch_class
  69. WHERE class = 'ar')
  70. UNION ALL
  71. -- TODO: Add the class labels to the class table.
  72. SELECT v.id, a.source,
  73. cr.meta_number || '--' || co.legal_name ,
  74. v.batch_id, v.trans_id,
  75. CASE WHEN bc.class LIKE 'payment%' THEN a.amount * -1
  76. ELSE a.amount END, a.transdate,
  77. CASE WHEN bc.class = 'payment' THEN 'Payment'
  78. WHEN bc.class = 'payment_reversal'
  79. THEN 'Payment Reversal'
  80. END
  81. FROM voucher v
  82. JOIN acc_trans a ON (v.id = a.voucher_id)
  83. JOIN batch_class bc ON (bc.id = v.batch_class)
  84. JOIN chart c ON (a.chart_id = c.id)
  85. JOIN ap ON (ap.id = a.trans_id)
  86. JOIN entity_credit_account cr
  87. ON (ap.entity_credit_account = cr.id)
  88. JOIN company co ON (cr.entity_id = co.entity_id)
  89. WHERE v.batch_id = in_batch_id
  90. AND a.voucher_id = v.id
  91. AND (bc.class like 'payment%' AND c.link = 'AP')
  92. UNION ALL
  93. SELECT v.id, a.source, a.memo,
  94. v.batch_id, v.trans_id,
  95. CASE WHEN bc.class LIKE 'receipt%' THEN a.amount * -1
  96. ELSE a.amount END, a.transdate,
  97. CASE WHEN bc.class = 'receipt' THEN 'Receipt'
  98. WHEN bc.class = 'receipt_reversal'
  99. THEN 'Receipt Reversal'
  100. END
  101. FROM voucher v
  102. JOIN acc_trans a ON (v.trans_id = a.trans_id)
  103. JOIN batch_class bc ON (bc.id = v.batch_class)
  104. JOIN chart c ON (a.chart_id = c.id)
  105. JOIN ar ON (ar.id = a.trans_id)
  106. JOIN entity_credit_account cr
  107. ON (ar.entity_credit_account = cr.id)
  108. JOIN company co ON (cr.entity_id = co.entity_id)
  109. WHERE v.batch_id = in_batch_id
  110. AND a.voucher_id = v.id
  111. AND (bc.class like 'receipt%' AND c.link = 'AR')
  112. UNION ALL
  113. SELECT v.id, g.reference, g.description,
  114. v.batch_id, v.trans_id,
  115. sum(a.amount), g.transdate, 'gl'
  116. FROM voucher v
  117. JOIN gl g ON (g.id = v.trans_id)
  118. JOIN acc_trans a ON (v.trans_id = a.trans_id)
  119. WHERE a.amount > 0
  120. AND v.batch_id = in_batch_id
  121. AND v.batch_class IN (select id from batch_class
  122. where class = 'gl')
  123. GROUP BY v.id, g.reference, g.description, v.batch_id,
  124. v.trans_id, g.transdate
  125. ORDER BY 7, 1
  126. LOOP
  127. RETURN NEXT voucher_item;
  128. END LOOP;
  129. END;
  130. $$ language plpgsql;
  131. CREATE TYPE batch_list_item AS (
  132. id integer,
  133. batch_class text,
  134. control_code text,
  135. description text,
  136. created_by text,
  137. created_on date,
  138. transaction_total numeric,
  139. payment_total numeric
  140. );
  141. CREATE OR REPLACE FUNCTION
  142. batch_search(in_class_id int, in_description text, in_created_by_eid int,
  143. in_amount_gt numeric,
  144. in_amount_lt numeric, in_approved bool)
  145. RETURNS SETOF batch_list_item AS
  146. $$
  147. DECLARE out_value batch_list_item;
  148. BEGIN
  149. FOR out_value IN
  150. SELECT b.id, c.class, b.control_code, b.description, u.username,
  151. b.created_on,
  152. sum(
  153. CASE WHEN vc.id = 5 AND al.amount < 0 -- GL
  154. THEN al.amount
  155. WHEN vc.id = 1
  156. THEN ap.amount
  157. WHEN vc.id = 2
  158. THEN ap.amount
  159. ELSE 0
  160. END) AS transaction_total,
  161. sum(
  162. CASE WHEN alc.link = 'AR' AND vc.id IN (6, 7)
  163. THEN al.amount
  164. WHEN alc.link = 'AP' AND vc.id IN (3, 4)
  165. THEN al.amount * -1
  166. ELSE 0
  167. END
  168. ) AS payment_total
  169. FROM batch b
  170. JOIN batch_class c ON (b.batch_class_id = c.id)
  171. LEFT JOIN users u ON (u.entity_id = b.created_by)
  172. JOIN voucher v ON (v.batch_id = b.id)
  173. JOIN batch_class vc ON (v.batch_class = vc.id)
  174. LEFT JOIN ar ON (vc.id = 2 AND v.trans_id = ar.id)
  175. LEFT JOIN ap ON (vc.id = 1 AND v.trans_id = ap.id)
  176. LEFT JOIN acc_trans al ON
  177. ((vc.id = 5 AND v.trans_id = al.trans_id) OR
  178. (vc.id IN (3, 4, 6, 7)
  179. AND al.voucher_id = v.id))
  180. LEFT JOIN chart alc ON (al.chart_id = alc.id)
  181. WHERE (c.id = in_class_id OR in_class_id IS NULL) AND
  182. (b.description LIKE
  183. '%' || in_description || '%' OR
  184. in_description IS NULL) AND
  185. (in_created_by_eid = b.created_by OR
  186. in_created_by_eid IS NULL) AND
  187. ((in_approved = false OR in_approved IS NULL AND
  188. approved_on IS NULL) OR
  189. (in_approved = true AND approved_on IS NOT NULL)
  190. )
  191. GROUP BY b.id, c.class, b.description, u.username, b.created_on,
  192. b.control_code
  193. HAVING
  194. (in_amount_gt IS NULL OR
  195. sum(coalesce(ar.amount - ar.paid, ap.amount - ap.paid,
  196. al.amount))
  197. >= in_amount_gt)
  198. AND
  199. (in_amount_lt IS NULL OR
  200. sum(coalesce(ar.amount - ar.paid, ap.amount - ap.paid,
  201. al.amount))
  202. <= in_amount_lt)
  203. LOOP
  204. RETURN NEXT out_value;
  205. END LOOP;
  206. END;
  207. $$ LANGUAGE PLPGSQL;
  208. CREATE OR REPLACE FUNCTION batch_get_class_id (in_type text) returns int AS
  209. $$
  210. SELECT id FROM batch_class WHERE class = $1;
  211. $$ language sql;
  212. CREATE OR REPLACE FUNCTION
  213. batch_search_mini
  214. (in_class_id int, in_description text, in_created_by_eid int, in_approved bool)
  215. RETURNS SETOF batch_list_item AS
  216. $$
  217. DECLARE out_value batch_list_item;
  218. BEGIN
  219. FOR out_value IN
  220. SELECT b.id, c.class, b.control_code, b.description, u.username,
  221. b.created_on, NULL
  222. FROM batch b
  223. JOIN batch_class c ON (b.batch_class_id = c.id)
  224. LEFT JOIN users u ON (u.entity_id = b.created_by)
  225. WHERE (c.id = in_class_id OR in_class_id IS NULL) AND
  226. (b.description LIKE
  227. '%' || in_description || '%' OR
  228. in_description IS NULL) AND
  229. (in_created_by_eid = b.created_by OR
  230. in_created_by_eid IS NULL) AND
  231. ((in_approved = false OR in_approved IS NULL AND
  232. approved_on IS NULL) OR
  233. (in_approved = true AND approved_on IS NOT NULL)
  234. )
  235. GROUP BY b.id, c.class, b.description, u.username, b.created_on,
  236. b.control_code
  237. LOOP
  238. RETURN NEXT out_value;
  239. END LOOP;
  240. END;
  241. $$ LANGUAGE PLPGSQL;
  242. CREATE OR REPLACE FUNCTION batch_post(in_batch_id INTEGER)
  243. returns date AS
  244. $$
  245. BEGIN
  246. UPDATE ar SET approved = true
  247. WHERE id IN (select trans_id FROM voucher
  248. WHERE batch_id = in_batch_id
  249. AND batch_class = 2);
  250. UPDATE ap SET approved = true
  251. WHERE id IN (select trans_id FROM voucher
  252. WHERE batch_id = in_batch_id
  253. AND batch_class = 1);
  254. UPDATE gl SET approved = true
  255. WHERE id IN (select trans_id FROM voucher
  256. WHERE batch_id = in_batch_id
  257. AND batch_class = 5);
  258. UPDATE acc_trans SET approved = true
  259. WHERE voucher_id IN (select id FROM voucher
  260. WHERE batch_id = in_batch_id
  261. AND batch_class IN (3, 4, 7, 8));
  262. UPDATE batch
  263. SET approved_on = now(),
  264. approved_by = (select entity_id FROM users
  265. WHERE username = SESSION_USER)
  266. WHERE id = in_batch_id;
  267. RETURN now()::date;
  268. END;
  269. $$ LANGUAGE PLPGSQL;
  270. CREATE OR REPLACE FUNCTION batch_list_classes() RETURNS SETOF batch_class AS
  271. $$
  272. DECLARE out_val record;
  273. BEGIN
  274. FOR out_val IN select * from batch_class
  275. LOOP
  276. return next out_val;
  277. END LOOP;
  278. END;
  279. $$ language plpgsql;
  280. CREATE OR REPLACE FUNCTION batch_get_users() RETURNS SETOF users AS
  281. $$
  282. DECLARE out_record users%ROWTYPE;
  283. BEGIN
  284. FOR out_record IN
  285. SELECT * from users WHERE entity_id IN (select created_by from batch)
  286. LOOP
  287. RETURN NEXT out_record;
  288. END LOOP;
  289. END;
  290. $$ LANGUAGE PLPGSQL;
  291. CREATE OR REPLACE FUNCTION batch_create(
  292. in_batch_number text, in_description text, in_batch_class text,
  293. in_batch_date date)
  294. RETURNS int AS
  295. $$
  296. BEGIN
  297. INSERT INTO
  298. batch (batch_class_id, default_date, description, control_code,
  299. created_by)
  300. VALUES ((SELECT id FROM batch_class WHERE class = in_batch_class),
  301. in_batch_date, in_description, in_batch_number,
  302. (select entity_id FROM users WHERE username = session_user));
  303. return currval('batch_id_seq');
  304. END;
  305. $$ LANGUAGE PLPGSQL;
  306. CREATE OR REPLACE FUNCTION batch_delete(in_batch_id int) RETURNS int AS
  307. $$
  308. DECLARE
  309. t_transaction_ids int[];
  310. BEGIN
  311. -- Adjust AR/AP tables for payment and payment reversal vouchers
  312. -- voucher_id is only set in acc_trans on payment/receipt vouchers and
  313. -- their reversals. -CT
  314. update ar set paid = amount +
  315. (select sum(amount) from acc_trans
  316. join chart ON (acc_trans.chart_id = chart.id)
  317. where link = 'AR' AND trans_id = ar.id
  318. AND (voucher_id IS NULL OR voucher_id NOT IN
  319. (select id from voucher
  320. WHERE batch_id = in_batch_id)))
  321. where id in (select trans_id from acc_trans where voucher_id IN
  322. (select id from voucher where batch_id = in_batch_id));
  323. update ap set paid = amount - (select sum(amount) from acc_trans
  324. join chart ON (acc_trans.chart_id = chart.id)
  325. where link = 'AP' AND trans_id = ap.id
  326. AND (voucher_id IS NULL OR voucher_id NOT IN
  327. (select id from voucher
  328. WHERE batch_id = in_batch_id)))
  329. where id in (select trans_id from acc_trans where voucher_id IN
  330. (select id from voucher where batch_id = in_batch_id));
  331. DELETE FROM acc_trans WHERE voucher_id IN
  332. (select id FROM voucher where batch_id = in_batch_id);
  333. -- The rest of this function involves the deletion of actual
  334. -- transactions, vouchers, and batches, and jobs which are in progress.
  335. -- -CT
  336. SELECT as_array(trans_id) INTO t_transaction_ids
  337. FROM voucher WHERE batch_id = in_batch_id AND batch_class IN (1, 2, 5);
  338. DELETE FROM acc_trans WHERE trans_id = ANY(t_transaction_ids);
  339. DELETE FROM ap WHERE id = ANY(t_transaction_ids);
  340. DELETE FROM gl WHERE id = ANY(t_transaction_ids);
  341. DELETE FROM voucher WHERE batch_id = in_batch_id;
  342. DELETE FROM payments_queue WHERE batch_id = in_batch_id;
  343. DELETE FROM pending_job WHERE batch_id = in_batch_id;
  344. DELETE FROM batch WHERE id = in_batch_id;
  345. DELETE FROM transactions WHERE id = ANY(t_transaction_ids);
  346. RETURN 1;
  347. END;
  348. $$ language plpgsql SECURITY DEFINER;
  349. REVOKE ALL ON FUNCTION batch_delete(int) FROM PUBLIC;
  350. CREATE OR REPLACE FUNCTION voucher__delete(in_voucher_id int)
  351. RETURNS int AS
  352. $$
  353. DECLARE
  354. voucher_row RECORD;
  355. BEGIN
  356. SELECT * INTO voucher_row FROM voucher WHERE id = in_voucher_id;
  357. IF voucher_row.batch_class IN (1, 2, 5) THEN
  358. DELETE from acc_trans WHERE trans_id = voucher_row.trans_id;
  359. DELETE FROM ar WHERE id = voucher_row.trans_id;
  360. DELETE FROM ap WHERE id = voucher_row.trans_id;
  361. DELETE FROM gl WHERE id = voucher_row.trans_id;
  362. DELETE FROM voucher WHERE id = voucher_row.id;
  363. DELETE FROM transactions WHERE id = voucher_row.trans_id;
  364. ELSE
  365. update ar set paid = amount +
  366. (select sum(amount) from acc_trans
  367. join chart ON (acc_trans.chart_id = chart.id)
  368. where link = 'AR' AND trans_id = ar.id
  369. AND (voucher_id IS NULL
  370. OR voucher_id <> voucher_row.id))
  371. where id in (select trans_id from acc_trans
  372. where voucher_id = voucher_row.id);
  373. update ap set paid = amount - (select sum(amount) from acc_trans
  374. join chart ON (acc_trans.chart_id = chart.id)
  375. where link = 'AP' AND trans_id = ap.id
  376. AND (voucher_id IS NULL
  377. OR voucher_id <> voucher_row.id))
  378. where id in (select trans_id from acc_trans
  379. where voucher_id = voucher_row.id);
  380. DELETE FROM acc_trans where voucher_id = voucher_row.id;
  381. END IF;
  382. RETURN 1;
  383. END;
  384. $$ LANGUAGE PLPGSQL SECURITY DEFINER;
  385. REVOKE ALL ON FUNCTION voucher__delete(int) FROM public;