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