summaryrefslogtreecommitdiff
path: root/sql/modules/Report.sql
blob: 9eb6c9c47811c84efbd140e66378e10072b8e44b (plain)
  1. CREATE TYPE report_aging_item AS (
  2. entity_id int,
  3. account_number varchar(24),
  4. name text,
  5. address1 text,
  6. address2 text,
  7. address3 text,
  8. city_province text,
  9. mail_code text,
  10. country text,
  11. contact_name text,
  12. email text,
  13. phone text,
  14. fax text,
  15. invnumber text,
  16. transdate date,
  17. till varchar(20),
  18. ordnumber text,
  19. ponumber text,
  20. notes text,
  21. c0 numeric,
  22. c30 numeric,
  23. c60 numeric,
  24. c90 numeric,
  25. duedate date,
  26. id int,
  27. curr varchar(3),
  28. exchangerate numeric,
  29. line_items text[][]
  30. );
  31. CREATE OR REPLACE FUNCTION
  32. report_invoice_aging(in_entity_id int, in_entity_class int)
  33. RETURNS SETOF report_aging_item
  34. AS
  35. $$
  36. DECLARE
  37. item report_aging_item;
  38. BEGIN
  39. IF in_entity_class = 1 THEN
  40. FOR item IN
  41. SELECT c.entity_id,
  42. c.meta_number, e.name,
  43. l.line_one as address1, l.line_two as address2,
  44. l.line_three as address3,
  45. l.city_province, l.mail_code,
  46. country.name as country,
  47. '' as contact_name, '' as email,
  48. '' as phone, '' as fax,
  49. a.invnumber, a.transdate, a.till, a.ordnumber,
  50. a.ponumber, a.notes,
  51. CASE WHEN
  52. EXTRACT(days FROM age(a.transdate)/30)
  53. = 0
  54. THEN (a.amount - a.paid) ELSE 0 END
  55. as c0,
  56. CASE WHEN EXTRACT(days FROM age(a.transdate)/30)
  57. = 1
  58. THEN (a.amount - a.paid) ELSE 0 END
  59. as c30,
  60. CASE WHEN EXTRACT(days FROM age(a.transdate)/30)
  61. = 2
  62. THEN (a.amount - a.paid) ELSE 0 END
  63. as c60,
  64. CASE WHEN EXTRACT(days FROM age(a.transdate)/30)
  65. > 2
  66. THEN (a.amount - a.paid) ELSE 0 END
  67. as c90,
  68. a.duedate, a.id, a.curr,
  69. COALESCE((SELECT sell FROM exchangerate ex
  70. WHERE a.curr = ex.curr
  71. AND ex.transdate = a.transdate), 1)
  72. AS exchangerate,
  73. (SELECT compound_array(ARRAY[[p.partnumber,
  74. i.description, i.qty::text]])
  75. FROM parts p
  76. JOIN invoice i ON (i.parts_id = p.id)
  77. WHERE i.trans_id = a.id) AS line_items
  78. FROM ap a
  79. JOIN entity_credit_account c USING (entity_id)
  80. JOIN entity e ON (e.id = c.entity_id)
  81. CROSS JOIN location l
  82. JOIN country ON (country.id = l.country_id)
  83. WHERE a.entity_id like coalesce(in_entity_id::text, '%')
  84. AND l.id = (SELECT min(location_id)
  85. FROM company_to_location
  86. WHERE company_id = (select min(id)
  87. FROM company
  88. WHERE entity_id = c.entity_id))
  89. ORDER BY entity_id, curr, transdate, invnumber
  90. LOOP
  91. return next item;
  92. END LOOP;
  93. ELSIF in_entity_class = 2 THEN
  94. FOR item IN
  95. SELECT c.entity_id,
  96. c.meta_number, e.name,
  97. l.line_one as address1, l.line_two as address2,
  98. l.line_three as address3,
  99. l.city_province, l.mail_code,
  100. country.name as country,
  101. '' as contact_name, '' as email,
  102. '' as phone, '' as fax,
  103. a.invnumber, a.transdate, a.till, a.ordnumber,
  104. a.ponumber, a.notes,
  105. CASE WHEN
  106. EXTRACT(days FROM age(a.transdate)/30)
  107. = 0
  108. THEN (a.amount - a.paid) ELSE 0 END
  109. as c0,
  110. CASE WHEN EXTRACT(days FROM age(a.transdate)/30)
  111. = 1
  112. THEN (a.amount - a.paid) ELSE 0 END
  113. as c30,
  114. CASE WHEN EXTRACT(days FROM age(a.transdate)/30)
  115. = 2
  116. THEN (a.amount - a.paid) ELSE 0 END
  117. as c60,
  118. CASE WHEN EXTRACT(days FROM age(a.transdate)/30)
  119. > 2
  120. THEN (a.amount - a.paid) ELSE 0 END
  121. as c90,
  122. a.duedate, a.id, a.curr,
  123. (SELECT buy FROM exchangerate ex
  124. WHERE a.curr = ex.curr
  125. AND ex.transdate = a.transdate)
  126. AS exchangerate,
  127. (SELECT compound_array(ARRAY[[p.partnumber,
  128. i.description, i.qty::text]])
  129. FROM parts p
  130. JOIN invoice i ON (i.parts_id = p.id)
  131. WHERE i.trans_id = a.id) AS line_items
  132. FROM ar a
  133. JOIN entity_credit_account c USING (entity_id)
  134. JOIN entity e ON (e.id = c.entity_id)
  135. CROSS JOIN location l
  136. JOIN country ON (country.id = l.country_id)
  137. WHERE a.entity_id like coalesce(in_entity_id::text, '%')
  138. AND l.id = (SELECT min(location_id)
  139. FROM company_to_location
  140. WHERE company_id = (select min(id)
  141. FROM company
  142. WHERE entity_id = c.entity_id))
  143. ORDER BY entity_id, curr, transdate, invnumber
  144. LOOP
  145. return next item;
  146. END LOOP;
  147. ELSE
  148. RAISE EXCEPTION 'Entity Class % unsupported in aging report',
  149. in_entity_class;
  150. END IF;
  151. END;
  152. $$ language plpgsql;