summaryrefslogtreecommitdiff
path: root/sql/modules/Voucher.sql
blob: 2bfc6fcb5220a61e5177e6c95034817653fc2d38 (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_post (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, v.batch_id, v.trans_id,
  48. a.amount - a.paid, a.transdate, 'Payable'
  49. FROM voucher v
  50. JOIN ap a ON (v.trans_id = a.id)
  51. JOIN entity e ON (a.entity_id = e.id)
  52. WHERE v.batch_id = in_batch_id
  53. AND v.batch_class = (select id from batch_class
  54. WHERE class = 'payable')
  55. UNION
  56. SELECT v.id, a.invnumber, e.name, v.batch_id, v.trans_id,
  57. a.amount - a.paid, a.transdate, 'Receivable'
  58. FROM voucher v
  59. JOIN ar a ON (v.trans_id = a.id)
  60. JOIN entity e ON (a.entity_id = e.id)
  61. WHERE v.batch_id = in_batch_id
  62. AND v.batch_class = (select id from batch_class
  63. WHERE class = 'receivable')
  64. UNION
  65. SELECT v.id, a.source, a.memo, v.batch_id, v.trans_id,
  66. a.amount, a.transdate, bc.class
  67. FROM voucher v
  68. JOIN acc_trans a ON (v.trans_id = a.trans_id)
  69. JOIN batch_class bc ON (bc.id = v.batch_class)
  70. WHERE v.batch_id = in_batch_id
  71. AND a.voucher_id = v.id
  72. AND bc.class like 'payment%'
  73. OR bc.class like 'receipt%'
  74. UNION
  75. SELECT v.id, g.reference, g.description, v.batch_id, v.trans_id,
  76. sum(a.amount), g.transdate, 'gl'
  77. FROM voucher v
  78. JOIN gl g ON (g.id = v.trans_id)
  79. JOIN acc_trans a ON (v.trans_id = a.trans_id)
  80. WHERE a.amount > 0
  81. AND v.batch_id = in_batch_id
  82. AND v.batch_class IN (select id from batch_class
  83. where class = 'gl')
  84. GROUP BY v.id, g.reference, g.description, v.batch_id,
  85. v.trans_id, g.transdate
  86. ORDER BY 7, 1
  87. LOOP
  88. RETURN NEXT voucher_item;
  89. END LOOP;
  90. END;
  91. $$ language plpgsql;
  92. CREATE TYPE batch_list_item AS (
  93. id integer,
  94. batch_class text,
  95. control_code text,
  96. description text,
  97. created_by text,
  98. created_on date,
  99. transaction_total numeric,
  100. payment_total numeric
  101. );
  102. CREATE OR REPLACE FUNCTION
  103. batch_search(in_class_id int, in_description text, in_created_by_eid int,
  104. in_amount_gt numeric,
  105. in_amount_lt numeric, in_approved bool)
  106. RETURNS SETOF batch_list_item AS
  107. $$
  108. DECLARE out_value batch_list_item;
  109. BEGIN
  110. FOR out_value IN
  111. SELECT b.id, c.class, b.control_code, b.description, u.username,
  112. b.created_on,
  113. sum(
  114. CASE WHEN vc.id = 5 AND al.amount > 0
  115. THEN al.amount
  116. WHEN vc.id NOT IN (3, 4, 6, 7)
  117. THEN coalesce(ar.amount, ap.amount, 0)
  118. ELSE 0
  119. END) AS transaction_total,
  120. sum(
  121. CASE WHEN alc.link = 'AR' AND vc.id IN (3,4,6,7)
  122. THEN al.amount
  123. WHEN alc.link = 'AP' AND vc.id IN (3,4,6,7)
  124. THEN al.amount * -1
  125. ELSE 0
  126. END
  127. ) AS payment_total
  128. FROM batch b
  129. JOIN batch_class c ON (b.batch_class_id = c.id)
  130. JOIN users u ON (u.entity_id = b.created_by)
  131. JOIN voucher v ON (v.batch_id = b.id)
  132. JOIN batch_class vc ON (v.batch_class = c.id)
  133. LEFT JOIN ar ON (vc.id = 2 AND v.trans_id = ar.id)
  134. LEFT JOIN ap ON (vc.id = 1 AND v.trans_id = ap.id)
  135. LEFT JOIN acc_trans al ON
  136. ((vc.id = 5 AND v.trans_id = al.trans_id) OR
  137. (vc.id IN (3, 4, 6, 7) AND al.voucher_id = v.id)
  138. AND al.amount > 0)
  139. LEFT JOIN chart alc ON (al.chart_id = alc.id)
  140. WHERE c.id = coalesce(in_class_id, c.id) AND
  141. b.description LIKE
  142. '%' || coalesce(in_description, '') || '%' AND
  143. coalesce(in_created_by_eid, b.created_by)
  144. = b.created_by
  145. AND ((coalesce(in_approved, false) = false AND
  146. approved_on IS NULL) OR
  147. (in_approved = true AND approved_on IS NOT NULL)
  148. )
  149. GROUP BY b.id, c.class, b.description, u.username, b.created_on,
  150. b.control_code
  151. HAVING
  152. sum(coalesce(ar.amount - ar.paid, ap.amount - ap.paid,
  153. al.amount))
  154. >= coalesce(in_amount_gt,
  155. sum(coalesce(ar.amount - ar.paid,
  156. ap.amount - ap.paid,
  157. al.amount)))
  158. AND
  159. sum(coalesce(ar.amount - ar.paid, ap.amount - ap.paid,
  160. al.amount))
  161. <= coalesce(in_amount_lt,
  162. sum(coalesce(ar.amount - ar.paid,
  163. ap.amount - ap.paid,
  164. al.amount)))
  165. LOOP
  166. RETURN NEXT out_value;
  167. END LOOP;
  168. END;
  169. $$ LANGUAGE PLPGSQL;
  170. CREATE OR REPLACE FUNCTION batch_post(in_batch_id INTEGER)
  171. returns date AS
  172. $$
  173. BEGIN
  174. UPDATE ar SET approved = true
  175. WHERE id IN (select trans_id FROM voucher
  176. WHERE batch_id = in_batch_id
  177. AND batch_class = 2);
  178. UPDATE ap SET approved = true
  179. WHERE id IN (select trans_id FROM voucher
  180. WHERE batch_id = in_batch_id
  181. AND batch_class = 1);
  182. UPDATE gl SET approved = true
  183. WHERE id IN (select trans_id FROM voucher
  184. WHERE batch_id = in_batch_id
  185. AND batch_class = 5);
  186. UPDATE acc_trans SET approved = true
  187. WHERE id IN (select trans_id FROM voucher
  188. WHERE batch_id = in_batch_id
  189. AND batch_class IN (3, 4, 7, 8));
  190. UPDATE batch
  191. SET approved_on = now(),
  192. approved_by = (select entity_id FROM users
  193. WHERE login = SESSION_USER)
  194. WHERE batch_id = in_batch_id;
  195. RETURN now()::date;
  196. END;
  197. $$ LANGUAGE PLPGSQL;
  198. CREATE OR REPLACE FUNCTION batch_list_classes() RETURNS SETOF batch_class AS
  199. $$
  200. DECLARE out_val record;
  201. BEGIN
  202. FOR out_val IN select * from batch_class
  203. LOOP
  204. return next out_val;
  205. END LOOP;
  206. END;
  207. $$ language plpgsql;
  208. CREATE OR REPLACE FUNCTION batch_get_users() RETURNS SETOF users AS
  209. $$
  210. DECLARE out_record users%ROWTYPE;
  211. BEGIN
  212. FOR out_record IN
  213. SELECT * from users WHERE entity_id IN (select created_by from batch)
  214. LOOP
  215. RETURN NEXT out_record;
  216. END LOOP;
  217. END;
  218. $$ LANGUAGE PLPGSQL;
  219. CREATE OR REPLACE FUNCTION batch_create(
  220. in_batch_number text, in_description text, in_batch_class text) RETURNS int AS
  221. $$
  222. BEGIN
  223. INSERT INTO
  224. batch (batch_class_id, description, control_code, created_by)
  225. VALUES ((SELECT id FROM batch_class WHERE class = in_batch_class),
  226. in_description, in_batch_number,
  227. (select entity_id FROM users WHERE username = session_user));
  228. return currval('batch_id_seq');
  229. END;
  230. $$ LANGUAGE PLPGSQL;
  231. CREATE OR REPLACE FUNCTION batch_delete(in_batch_id int) RETURNS int AS
  232. $$
  233. DECLARE
  234. t_transaction_ids int[];
  235. BEGIN
  236. -- Adjust AR/AP tables for payment and payment reversal vouchers
  237. -- voucher_id is only set in acc_trans on payment/receipt vouchers and
  238. -- their reversals. -CT
  239. update ar set paid = amount -
  240. (select sum(amount) * -1 from acc_trans
  241. join chart ON (acc_trans.chart_id = chart.id)
  242. where link = 'AR' AND trans_id = ar.id
  243. AND voucher_id NOT IN
  244. (select id from voucher
  245. WHERE batch_id = in_batch_id))
  246. where id in (select trans_id from acc_trans where voucher_id IN
  247. (select id from voucher where batch_id = in_batch_id));
  248. update ap set paid = amount - (select sum(amount) from acc_trans
  249. join chart ON (acc_trans.chart_id = chart.id)
  250. where link = 'AP' AND trans_id = ap.id
  251. AND voucher_id NOT IN
  252. (select id from voucher
  253. WHERE batch_id = in_batch_id))
  254. where id in (select trans_id from acc_trans where voucher_id IN
  255. (select id from voucher where batch_id = in_batch_id));
  256. DELETE FROM acc_trans WHERE voucher_id IN
  257. (select id FROM voucher where batch_id = in_batch_id);
  258. -- The rest of this function involves the deletion of actual
  259. -- transactions, vouchers, and batches, and jobs which are in progress.
  260. -- -CT
  261. SELECT as_array(trans_id) INTO t_transaction_ids
  262. FROM voucher WHERE batch_id = in_batch_id AND batch_class IN (1, 2, 5);
  263. DELETE FROM acc_trans WHERE trans_id = ANY(t_transaction_ids);
  264. DELETE FROM ap WHERE id = ANY(t_transaction_ids);
  265. DELETE FROM gl WHERE id = ANY(t_transaction_ids);
  266. DELETE FROM voucher WHERE batch_id = in_batch_id;
  267. DELETE FROM payments_queue WHERE batch_id = in_batch_id;
  268. DELETE FROM pending_job WHERE batch_id = in_batch_id;
  269. DELETE FROM batch WHERE id = in_batch_id;
  270. DELETE FROM transactions WHERE id = ANY(t_transaction_ids);
  271. RETURN 1;
  272. END;
  273. $$ language plpgsql;