summaryrefslogtreecommitdiff
path: root/sql/modules/Payment.sql
blob: b5beb196f4dd830f11ca6d0598ca90681fd8b453 (plain)
  1. CREATE OR REPLACE FUNCTION payment_get_open_accounts(in_account_class int)
  2. returns SETOF entity AS
  3. $$
  4. DECLARE out_entity entity%ROWTYPE;
  5. BEGIN
  6. FOR out_entity IN
  7. SELECT * FROM entity
  8. WHERE id IN (SELECT entity_id FROM entity_credit_account
  9. WHERE entity_class = in_account_class)
  10. AND CASE WHEN in_account_class = 1 THEN
  11. id IN (SELECT entity_id FROM ap
  12. WHERE amount <> paid
  13. GROUP BY entity_id)
  14. WHEN in_account_class = 2 THEN
  15. id IN (SELECT entity_id FROM ar
  16. WHERE amount <> paid
  17. GROUP BY entity_id)
  18. END
  19. LOOP
  20. RETURN NEXT out_entity;
  21. END LOOP;
  22. END;
  23. $$ LANGUAGE PLPGSQL;
  24. COMMENT ON FUNCTION payment_get_open_accounts(int) IS
  25. $$ This function takes a single argument (1 for vendor, 2 for customer as
  26. always) and returns all entities with open accounts of the appropriate type. $$;
  27. CREATE OR REPLACE FUNCTION payment_get_all_accounts(in_account_class int)
  28. RETURNS SETOF entity AS
  29. $$
  30. DECLARE out_entity entity%ROWTYPE;
  31. BEGIN
  32. FOR out_entity IN
  33. SELECT * FROM entity
  34. WHERE id IN (seLECT entity_id FROM entity_credit_account
  35. WHERE entity_class = in_account_class)
  36. LOOP
  37. RETURN NEXT out_entity;
  38. END LOOP;
  39. END;
  40. $$ LANGUAGE PLPGSQL;
  41. COMMENT ON FUNCTION payment_get_open_accounts(int) IS
  42. $$ This function takes a single argument (1 for vendor, 2 for customer as
  43. always) and returns all entities with accounts of the appropriate type. $$;
  44. CREATE TYPE payment_invoice AS (
  45. invoice_id int,
  46. invnumber text,
  47. invoice_date date,
  48. amount numeric,
  49. discount numeric,
  50. due numeric
  51. );
  52. CREATE OR REPLACE FUNCTION payment_get_open_invoices
  53. (in_account_class int, in_entity_id int, in_curr char(3))
  54. RETURNS SETOF payment_invoice AS
  55. $$
  56. DECLARE payment_inv payment_invoice;
  57. BEGIN
  58. FOR payment_inv IN
  59. SELECT a.id AS invoice_id, a.invnumber,
  60. a.transdate AS invoice_date, a.amount,
  61. CASE WHEN discount_terms
  62. < extract('days' FROM age(a.transdate))
  63. THEN 0
  64. ELSE (a.amount - a.paid) * c.discount / 100
  65. END AS discount,
  66. a.amount - a.paid -
  67. CASE WHEN discount_terms
  68. < extract('days' FROM age(a.transdate))
  69. THEN 0
  70. ELSE (a.amount - a.paid) * c.discount / 100
  71. END AS due
  72. FROM (SELECT id, invnumber, transdate, amount, entity_id,
  73. 1 as invoice_class, paid, curr
  74. FROM ap
  75. UNION
  76. SELECT id, invnumber, transdate, amount, entity_id,
  77. 2 AS invoice_class, paid, curr
  78. FROM ar
  79. ) a
  80. JOIN entity_credit_account c USING (entity_id)
  81. WHERE a.invoice_class = in_account_class
  82. AND c.entity_class = in_account_class
  83. AND a.curr = in_curr
  84. AND a.entity_id = coalesce(in_entity_id, a.entity_id)
  85. LOOP
  86. RETURN NEXT payment_inv;
  87. END LOOP;
  88. END;
  89. $$ LANGUAGE PLPGSQL;
  90. COMMENT ON FUNCTION payment_get_open_invoices(int, int, char(3)) IS
  91. $$ This function takes three arguments:
  92. Type: 1 for vendor, 2 for customer
  93. Entity_id: The entity_id of the customer or vendor
  94. Currency: 3 characters for currency ('USD' for example).
  95. Returns all open invoices for the entity in question. $$;
  96. CREATE TYPE payment_contact_invoice AS (
  97. contact_id int,
  98. contact_name text,
  99. account_number text,
  100. total_due numeric,
  101. invoices text[]
  102. );
  103. CREATE OR REPLACE FUNCTION payment_get_all_contact_invoices
  104. (in_account_class int, in_business_type int, in_currency char(3),
  105. in_date_from date, in_date_to date, in_batch_id int,
  106. in_ar_ap_accno text)
  107. RETURNS SETOF payment_contact_invoice AS
  108. $$
  109. DECLARE payment_item payment_contact_invoice;
  110. BEGIN
  111. FOR payment_item IN
  112. SELECT e.id AS contact_id, e.name AS contact_name,
  113. c.meta_number AS account_number,
  114. sum(a.amount - a.paid) AS total_due,
  115. compound_array(ARRAY[[
  116. a.id::text, a.invnumber, a.transdate::text,
  117. a.amount::text,
  118. (CASE WHEN c.discount_terms
  119. > extract('days' FROM age(a.transdate))
  120. THEN 0
  121. ELSE (a.amount - a.paid) * c.discount / 100
  122. END)::text,
  123. (a.amount - a.paid -
  124. CASE WHEN c.discount_terms
  125. > extract('days' FROM age(a.transdate))
  126. THEN 0
  127. ELSE (a.amount - a.paid) * c.discount / 100
  128. END)::text]])
  129. FROM entity e
  130. JOIN entity_credit_account c ON (e.id = c.entity_id)
  131. JOIN (SELECT id, invnumber, transdate, amount, entity_id,
  132. paid, curr, 1 as invoice_class
  133. FROM ap
  134. UNION
  135. SELECT id, invnumber, transdate, amount, entity_id,
  136. paid, curr, 2 as invoice_class
  137. FROM ar
  138. ) a USING (entity_id)
  139. WHERE a.invoice_class = in_account_class
  140. AND ((a.transdate >= in_date_from
  141. AND a.transdate <= in_date_to)
  142. OR a.id IN (select voucher.trans_id FROM voucher
  143. WHERE batch_id = in_batch_id))
  144. AND c.entity_class = in_account_class
  145. AND a.curr = in_currency
  146. AND EXISTS (select trans_id FROM acc_trans
  147. WHERE trans_id = a.id AND
  148. chart_id = (SELECT id frOM chart
  149. WHERE accno
  150. = in_ar_ap_accno)
  151. )
  152. GROUP BY e.id, e.name, c.meta_number, c.threshold
  153. HAVING sum(a.amount - a.paid) > c.threshold
  154. LOOP
  155. RETURN NEXT payment_item;
  156. END LOOP;
  157. END;
  158. $$ LANGUAGE plpgsql;
  159. COMMENT ON FUNCTION payment_get_all_contact_invoices
  160. (in_account_class int, in_business_type int, in_currency char(3),
  161. in_date_from date, in_date_to date, in_batch_id int,
  162. in_ar_ap_accno text) IS
  163. $$
  164. This function takes the following arguments (all prefaced with in_ in the db):
  165. account_class: 1 for vendor, 2 for customer
  166. business_type: integer of business.id.
  167. currency: char(3) of currency (for example 'USD')
  168. date_from, date_to: These dates are inclusive.
  169. batch_id: For payment batches, where fees are concerned.
  170. ar_ap_accno: The AR/AP account number.
  171. This then returns a set of contact information with a 2 dimensional array
  172. cnsisting of outstanding invoices.
  173. $$;
  174. CREATE OR REPLACE FUNCTION payment_post
  175. (in_trans_id int, in_source text, in_amount numeric, in_ar_ap_accno text,
  176. in_cash_accno text, in_approved bool, in_payment_date date,
  177. in_account_class int)
  178. RETURNS INT AS
  179. $$
  180. DECLARE out_entry_id int;
  181. BEGIN
  182. INSERT INTO acc_trans (chart_id, amount,
  183. trans_id, transdate, approved, source)
  184. VALUES ((SELECT id FROM chart WHERE accno = in_ar_ap_accno),
  185. CASE WHEN in_account_class = 1 THEN in_amount * -1
  186. ELSE amount
  187. END,
  188. in_trans_id, in_payment_date, in_approved, in_source);
  189. INSERT INTO acc_trans (chart_id, amount,
  190. trans_id, transdate, approved, source)
  191. VALUES ((SELECT id FROM chart WHERE accno = in_cash_accno),
  192. CASE WHEN in_account_class = 2 THEN in_amount * -1
  193. ELSE amount
  194. END,
  195. in_trans_id, in_payment_date, coalesce(in_approved, true),
  196. in_source);
  197. SELECT currval('acc_trans_entry_id_seq') INTO out_entry_id;
  198. RETURN out_entry_id;
  199. END;
  200. $$ LANGUAGE PLPGSQL;
  201. COMMENT ON FUNCTION payment_post
  202. (in_trans_id int, in_source text, in_amount numeric, in_ar_ap_accno text,
  203. in_cash_accno text, in_approved bool, in_payment_date date,
  204. in_account_class int)
  205. IS $$
  206. This function takes the following arguments (prefaced with in_ in the db):
  207. trans_id: Id for ar/ap transaction.
  208. source: text for source documnet identifier (for example, check number)
  209. amount: numeric for the amount of the transaction
  210. ar_ap_accno: AR/AP account number
  211. cash_accno: Cash Account number, i.e. the account where the payment will be
  212. held
  213. approved: False, for a voucher.
  214. This function posts the payment or saves the payment voucher.
  215. $$;
  216. -- Move this to the projects module when we start on that. CT
  217. CREATE OR REPLACE FUNCTION project_list_open(in_date date)
  218. RETURNS SETOF project AS
  219. $$
  220. DECLARE out_project project%ROWTYPE;
  221. BEGIN
  222. FOR out_project IN
  223. SELECT * from project
  224. WHERE startdate <= in_date AND enddate >= in_date
  225. AND completed = 0
  226. LOOP
  227. return next out_project;
  228. END LOOP;
  229. END;
  230. $$ language plpgsql;
  231. comment on function project_list_open(in_date date) is
  232. $$ This function returns all projects that were open as on the date provided as
  233. the argument.$$;
  234. -- Move this to the projects module when we start on that. CT
  235. CREATE OR REPLACE FUNCTION department_list(in_role char)
  236. RETURNS SETOF department AS
  237. $$
  238. DECLARE out_department department%ROWTYPE;
  239. BEGIN
  240. FOR out_department IN
  241. SELECT * from department
  242. WHERE role = in_role
  243. LOOP
  244. return next out_department;
  245. END LOOP;
  246. END;
  247. $$ language plpgsql;
  248. comment on function department_list(in_role char) is
  249. $$ This function returns all department that match the role provided as
  250. the argument.$$;
  251. CREATE OR REPLACE FUNCTION payments_get_open_currencies(in_account_class int)
  252. RETURNS SETOF char(3) AS
  253. $$
  254. DECLARE resultrow record;
  255. BEGIN
  256. FOR resultrow IN
  257. SELECT curr FROM ar
  258. WHERE amount <> paid
  259. OR paid IS NULL
  260. AND in_account_class=2
  261. UNION
  262. SELECT curr FROM ap
  263. WHERE amount <> paid
  264. OR paid IS NULL
  265. AND in_account_class=1
  266. ORDER BY curr
  267. LOOP
  268. return next resultrow.curr;
  269. END LOOP;
  270. END;
  271. $$ language plpgsql;
  272. CREATE OR REPLACE FUNCTION currency_get_exchangerate(in_currency char(3), in_date date, in_account_class int)
  273. RETURNS NUMERIC AS
  274. $$
  275. DECLARE
  276. out_exrate exchangerate.buy%TYPE;
  277. BEGIN
  278. IF in_account_class = 1 THEN
  279. SELECT INTO out_exrate buy
  280. FROM exchangerate
  281. WHERE transdate = in_date AND curr = in_currency;
  282. ELSE
  283. SELECT INTO out_exrate sell
  284. FROM exchangerate
  285. WHERE transdate = in_date AND curr = in_currency;
  286. END IF;
  287. RETURN out_exrate;
  288. END;
  289. $$ language plpgsql;
  290. COMMENT ON FUNCTION currency_get_exchangerate(in_currency char(3), in_date date, in_account_class int) IS
  291. $$ This function return the exchange rate of a given currency, date and exchange rate class (buy or sell). $$;
  292. CREATE OR REPLACE FUNCTION payment_get_vc_info(in_entity_id int)
  293. RETURNS SETOF entity AS
  294. $$
  295. DECLARE
  296. out_info entity%ROWTYPE;
  297. BEGIN
  298. FOR out_info IN
  299. SELECT e.id, e.name FROM entity e
  300. JOIN company c ON (e.id = c.entity_id)
  301. WHERE e.id = in_entity_id
  302. --SELECT e.id, c.legal_name, l.line_one, l.city_province, cy.name FROM entity e
  303. --JOIN company c ON (e.id = c.entity_id)
  304. --JOIN company_to_location cl ON (c.id = cl.company_id)
  305. --JOIN location l ON (l.id = cl.location_id)
  306. --JOIN country cy ON (cy.id = l.country_id)
  307. LOOP
  308. return next out_info;
  309. END LOOP;
  310. IF NOT FOUND THEN
  311. RAISE EXCEPTION 'ID % not found!!!!!', in_entity_id;
  312. END IF;
  313. END;
  314. $$ language plpgsql;
  315. COMMENT ON FUNCTION payment_get_vc_info(in_entity_id int) IS
  316. $$ This function return vendor or customer info, its under construction $$;