summaryrefslogtreecommitdiff
path: root/sql/modules/Payment.sql
blob: c39e6945c6b70924af7fb477470feb2726ac1127 (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.credit_account = coalesce(in_entity_credit_id,
  91. a.credit_account)
  92. LOOP
  93. RETURN NEXT payment_inv;
  94. END LOOP;
  95. END;
  96. $$ LANGUAGE PLPGSQL;
  97. COMMENT ON FUNCTION payment_get_open_invoices(int, int, char(3)) IS
  98. $$ This function takes three arguments:
  99. Type: 1 for vendor, 2 for customer
  100. Entity_id: The entity_id of the customer or vendor
  101. Currency: 3 characters for currency ('USD' for example).
  102. Returns all open invoices for the entity in question. $$;
  103. CREATE TYPE payment_contact_invoice AS (
  104. contact_id int,
  105. contact_name text,
  106. account_number text,
  107. total_due numeric,
  108. invoices text[]
  109. );
  110. CREATE OR REPLACE FUNCTION payment_get_all_contact_invoices
  111. (in_account_class int, in_business_type int, in_currency char(3),
  112. in_date_from date, in_date_to date, in_batch_id int,
  113. in_ar_ap_accno text)
  114. RETURNS SETOF payment_contact_invoice AS
  115. $$
  116. DECLARE payment_item payment_contact_invoice;
  117. BEGIN
  118. FOR payment_item IN
  119. SELECT e.id AS contact_id, e.name AS contact_name,
  120. c.meta_number AS account_number,
  121. sum(a.amount - a.paid) AS total_due,
  122. compound_array(ARRAY[[
  123. a.id::text, a.invnumber, a.transdate::text,
  124. a.amount::text,
  125. (CASE WHEN c.discount_terms
  126. > extract('days' FROM age(a.transdate))
  127. THEN 0
  128. ELSE (a.amount - a.paid) * c.discount / 100
  129. END)::text,
  130. (a.amount - a.paid -
  131. (CASE WHEN c.discount_terms
  132. > extract('days' FROM age(a.transdate))
  133. THEN 0
  134. ELSE (a.amount - a.paid) * c.discount / 100
  135. END))::text]]),
  136. bool_and(lock_record(a.id, (select max(session_id) FROM "session" where users_id = (
  137. select id from users WHERE username =
  138. SESSION_USER))))
  139. FROM entity e
  140. JOIN entity_credit_account c ON (e.id = c.entity_id)
  141. JOIN (SELECT id, invnumber, transdate, amount, entity_id,
  142. paid, curr, 1 as invoice_class
  143. FROM ap
  144. UNION
  145. SELECT id, invnumber, transdate, amount, entity_id,
  146. paid, curr, 2 as invoice_class
  147. FROM ar
  148. ) a USING (entity_id)
  149. JOIN transactions t ON (a.id = t.id)
  150. WHERE a.invoice_class = in_account_class
  151. AND ((a.transdate >= in_date_from
  152. AND a.transdate <= in_date_to)
  153. OR a.id IN (select voucher.trans_id FROM voucher
  154. WHERE batch_id = in_batch_id))
  155. AND c.entity_class = in_account_class
  156. AND a.curr = in_currency
  157. AND a.amount - a.paid <> 0
  158. AND t.locked_by NOT IN
  159. (select "session_id" FROM "session"
  160. WHERE users_id IN
  161. (select id from users
  162. where username <> SESSION_USER))
  163. AND EXISTS (select trans_id FROM acc_trans
  164. WHERE trans_id = a.id AND
  165. chart_id = (SELECT id frOM chart
  166. WHERE accno
  167. = in_ar_ap_accno)
  168. )
  169. GROUP BY e.id, e.name, c.meta_number, c.threshold
  170. HAVING sum(a.amount - a.paid) > c.threshold
  171. LOOP
  172. RETURN NEXT payment_item;
  173. END LOOP;
  174. END;
  175. $$ LANGUAGE plpgsql;
  176. COMMENT ON FUNCTION payment_get_all_contact_invoices
  177. (in_account_class int, in_business_type int, in_currency char(3),
  178. in_date_from date, in_date_to date, in_batch_id int,
  179. in_ar_ap_accno text) IS
  180. $$
  181. This function takes the following arguments (all prefaced with in_ in the db):
  182. account_class: 1 for vendor, 2 for customer
  183. business_type: integer of business.id.
  184. currency: char(3) of currency (for example 'USD')
  185. date_from, date_to: These dates are inclusive.
  186. batch_id: For payment batches, where fees are concerned.
  187. ar_ap_accno: The AR/AP account number.
  188. This then returns a set of contact information with a 2 dimensional array
  189. cnsisting of outstanding invoices.
  190. $$;
  191. CREATE OR REPLACE FUNCTION payment_bulk_post
  192. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  193. in_ar_ap_accno text, in_cash_accno text, in_approved bool,
  194. in_payment_date date, in_account_class int)
  195. RETURNS int AS
  196. $$
  197. DECLARE payment_trans numeric[];
  198. BEGIN
  199. END;
  200. $$ language plpgsql;
  201. COMMENT ON FUNCTION payment_bulk_post
  202. (in_transactions numeric[], in_batch_id int, in_source text, in_total numeric,
  203. in_ar_ap_accno text, in_cash_accno text, in_approved bool,
  204. in_payment_date date, in_account_class int)
  205. IS
  206. $$ Note that in_transactions is a two-dimensional numeric array. Of each
  207. sub-array, the first element is the (integer) transaction id, and the second
  208. is the amount for that transaction. If the total of the amounts do not add up
  209. to in_total, then an error is generated. $$;
  210. CREATE OR REPLACE FUNCTION payment_post
  211. (in_trans_id int, in_batch_id int, in_source text, in_amount numeric,
  212. in_ar_ap_accno text, in_cash_accno text, in_approved bool,
  213. in_payment_date date, in_account_class int)
  214. RETURNS INT AS
  215. $$
  216. DECLARE out_entry_id int;
  217. BEGIN
  218. INSERT INTO acc_trans (chart_id, amount,
  219. trans_id, transdate, approved, source)
  220. VALUES ((SELECT id FROM chart WHERE accno = in_ar_ap_accno),
  221. CASE WHEN in_account_class = 1 THEN in_amount * -1
  222. ELSE amount
  223. END,
  224. in_trans_id, in_payment_date, in_approved, in_source);
  225. INSERT INTO acc_trans (chart_id, amount,
  226. trans_id, transdate, approved, source)
  227. VALUES ((SELECT id FROM chart WHERE accno = in_cash_accno),
  228. CASE WHEN in_account_class = 2 THEN in_amount * -1
  229. ELSE amount
  230. END,
  231. in_trans_id, in_payment_date, coalesce(in_approved, true),
  232. in_source);
  233. SELECT currval('acc_trans_entry_id_seq') INTO out_entry_id;
  234. RETURN out_entry_id;
  235. END;
  236. $$ LANGUAGE PLPGSQL;
  237. COMMENT ON FUNCTION payment_post
  238. (in_trans_id int, in_source text, in_amount numeric, in_ar_ap_accno text,
  239. in_cash_accno text, in_approved bool, in_payment_date date,
  240. in_account_class int)
  241. IS $$
  242. This function takes the following arguments (prefaced with in_ in the db):
  243. trans_id: Id for ar/ap transaction.
  244. source: text for source documnet identifier (for example, check number)
  245. amount: numeric for the amount of the transaction
  246. ar_ap_accno: AR/AP account number
  247. cash_accno: Cash Account number, i.e. the account where the payment will be
  248. held
  249. approved: False, for a voucher.
  250. This function posts the payment or saves the payment voucher.
  251. $$;
  252. -- Move this to the projects module when we start on that. CT
  253. CREATE OR REPLACE FUNCTION project_list_open(in_date date)
  254. RETURNS SETOF project AS
  255. $$
  256. DECLARE out_project project%ROWTYPE;
  257. BEGIN
  258. FOR out_project IN
  259. SELECT * from project
  260. WHERE startdate <= in_date AND enddate >= in_date
  261. AND completed = 0
  262. LOOP
  263. return next out_project;
  264. END LOOP;
  265. END;
  266. $$ language plpgsql;
  267. comment on function project_list_open(in_date date) is
  268. $$ This function returns all projects that were open as on the date provided as
  269. the argument.$$;
  270. -- Move this to the projects module when we start on that. CT
  271. CREATE OR REPLACE FUNCTION department_list(in_role char)
  272. RETURNS SETOF department AS
  273. $$
  274. DECLARE out_department department%ROWTYPE;
  275. BEGIN
  276. FOR out_department IN
  277. SELECT * from department
  278. WHERE role = coalesce(in_role, role)
  279. LOOP
  280. return next out_department;
  281. END LOOP;
  282. END;
  283. $$ language plpgsql;
  284. -- Move this into another module.
  285. comment on function department_list(in_role char) is
  286. $$ This function returns all department that match the role provided as
  287. the argument.$$;
  288. CREATE OR REPLACE FUNCTION payments_get_open_currencies(in_account_class int)
  289. RETURNS SETOF char(3) AS
  290. $$
  291. DECLARE resultrow record;
  292. BEGIN
  293. FOR resultrow IN
  294. SELECT curr AS curr FROM ar
  295. WHERE amount <> paid
  296. OR paid IS NULL
  297. AND in_account_class=2
  298. UNION
  299. SELECT curr FROM ap
  300. WHERE amount <> paid
  301. OR paid IS NULL
  302. AND in_account_class=1
  303. ORDER BY curr
  304. LOOP
  305. return next resultrow.curr;
  306. END LOOP;
  307. END;
  308. $$ language plpgsql;
  309. CREATE OR REPLACE FUNCTION currency_get_exchangerate(in_currency char(3), in_date date, in_account_class int)
  310. RETURNS NUMERIC AS
  311. $$
  312. DECLARE
  313. out_exrate exchangerate.buy%TYPE;
  314. BEGIN
  315. IF in_account_class = 1 THEN
  316. SELECT INTO out_exrate buy
  317. FROM exchangerate
  318. WHERE transdate = in_date AND curr = in_currency;
  319. ELSE
  320. SELECT INTO out_exrate sell
  321. FROM exchangerate
  322. WHERE transdate = in_date AND curr = in_currency;
  323. END IF;
  324. RETURN out_exrate;
  325. END;
  326. $$ language plpgsql;
  327. COMMENT ON FUNCTION currency_get_exchangerate(in_currency char(3), in_date date, in_account_class int) IS
  328. $$ This function return the exchange rate of a given currency, date and exchange rate class (buy or sell). $$;
  329. CREATE OR REPLACE FUNCTION payment_get_vc_info(in_entity_id int)
  330. RETURNS SETOF entity AS
  331. $$
  332. DECLARE
  333. out_info entity%ROWTYPE;
  334. BEGIN
  335. FOR out_info IN
  336. SELECT e.id, e.name FROM entity e
  337. JOIN company c ON (e.id = c.entity_id)
  338. WHERE e.id = in_entity_id
  339. --SELECT e.id, c.legal_name, l.line_one, l.city_province, cy.name FROM entity e
  340. --JOIN company c ON (e.id = c.entity_id)
  341. --JOIN company_to_location cl ON (c.id = cl.company_id)
  342. --JOIN location l ON (l.id = cl.location_id)
  343. --JOIN country cy ON (cy.id = l.country_id)
  344. LOOP
  345. return next out_info;
  346. END LOOP;
  347. IF NOT FOUND THEN
  348. RAISE EXCEPTION 'ID % not found!!!!!', in_entity_id;
  349. END IF;
  350. END;
  351. $$ language plpgsql;
  352. COMMENT ON FUNCTION payment_get_vc_info(in_entity_id int) IS
  353. $$ This function return vendor or customer info, its under construction $$;