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