summaryrefslogtreecommitdiff
path: root/sql/modules/Voucher.sql
blob: 5227a848820d87cb116b0e54b8190fbc8a14f062 (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. description text,
  96. created_by text,
  97. created_on date,
  98. total numeric
  99. );
  100. CREATE OR REPLACE FUNCTION
  101. batch_search(in_class_id int, in_description text, in_created_by_eid int,
  102. in_amount_gt numeric,
  103. in_amount_lt numeric, in_approved bool)
  104. RETURNS SETOF batch_list_item AS
  105. $$
  106. DECLARE out_value batch_list_item;
  107. BEGIN
  108. FOR out_value IN
  109. SELECT b.id, c.class, b.description, u.username, b.created_on,
  110. sum(coalesce(ar.amount - ar.paid, ap.amount - ap.paid,
  111. al.amount)) AS amount
  112. FROM batch b
  113. JOIN batch_class c ON (b.batch_class_id = c.id)
  114. JOIN users u ON (u.entity_id = b.created_by)
  115. JOIN voucher v ON (v.batch_id = b.id)
  116. JOIN batch_class vc ON (v.batch_class = c.id)
  117. LEFT JOIN ar ON (vc.id = 2 AND v.trans_id = ar.id)
  118. LEFT JOIN ap ON (vc.id = 1 AND v.trans_id = ap.id)
  119. LEFT JOIN acc_trans al ON
  120. ((vc.id = 5 AND v.trans_id = al.trans_id) OR
  121. (vc.id IN (3, 4, 7, 8) AND al.voucher_id = v.id)
  122. AND al.amount > 0)
  123. WHERE c.id = coalesce(in_class_id, c.id) AND
  124. b.description LIKE
  125. '%' || coalesce(in_description, '') || '%' AND
  126. coalesce(in_created_by_eid, b.created_by)
  127. = b.created_by
  128. AND ((coalesce(in_approved, false) = false AND
  129. approved_on IS NULL) OR
  130. (in_approved = true AND approved_on IS NOT NULL)
  131. )
  132. GROUP BY b.id, c.class, b.description, u.username, b.created_on
  133. HAVING
  134. sum(coalesce(ar.amount - ar.paid, ap.amount - ap.paid,
  135. al.amount))
  136. >= coalesce(in_amount_gt,
  137. sum(coalesce(ar.amount - ar.paid,
  138. ap.amount - ap.paid,
  139. al.amount)))
  140. AND
  141. sum(coalesce(ar.amount - ar.paid, ap.amount - ap.paid,
  142. al.amount))
  143. <= coalesce(in_amount_lt,
  144. sum(coalesce(ar.amount - ar.paid,
  145. ap.amount - ap.paid,
  146. al.amount)))
  147. LOOP
  148. RETURN NEXT out_value;
  149. END LOOP;
  150. END;
  151. $$ LANGUAGE PLPGSQL;
  152. CREATE OR REPLACE FUNCTION batch_post(in_batch_id INTEGER)
  153. returns date AS
  154. $$
  155. BEGIN
  156. UPDATE ar SET approved = true
  157. WHERE id IN (select trans_id FROM voucher
  158. WHERE batch_id = in_batch_id
  159. AND batch_class = 2);
  160. UPDATE ap SET approved = true
  161. WHERE id IN (select trans_id FROM voucher
  162. WHERE batch_id = in_batch_id
  163. AND batch_class = 1);
  164. UPDATE gl SET approved = true
  165. WHERE id IN (select trans_id FROM voucher
  166. WHERE batch_id = in_batch_id
  167. AND batch_class = 5);
  168. UPDATE acc_trans SET approved = true
  169. WHERE id IN (select trans_id FROM voucher
  170. WHERE batch_id = in_batch_id
  171. AND batch_class IN (3, 4, 7, 8));
  172. UPDATE batch
  173. SET approved_on = now(),
  174. approved_by = (select entity_id FROM users
  175. WHERE login = SESSION_USER)
  176. WHERE batch_id = in_batch_id;
  177. RETURN now()::date;
  178. END;
  179. $$ LANGUAGE PLPGSQL;
  180. CREATE OR REPLACE FUNCTION batch_list_classes() RETURNS SETOF batch_class AS
  181. $$
  182. DECLARE out_val record;
  183. BEGIN
  184. FOR out_val IN select * from batch_class
  185. LOOP
  186. return next out_val;
  187. END LOOP;
  188. END;
  189. $$ language plpgsql;
  190. CREATE OR REPLACE FUNCTION batch_create(
  191. in_batch_number text, in_description text, in_batch_class text) RETURNS int AS
  192. $$
  193. BEGIN
  194. INSERT INTO
  195. batch (batch_class_id, description, control_code, created_by)
  196. VALUES ((SELECT id FROM batch_class WHERE class = in_batch_class),
  197. in_description, in_batch_number,
  198. (select entity_id FROM users WHERE username = session_user));
  199. return currval('batch_id_seq');
  200. END;
  201. $$ LANGUAGE PLPGSQL;