summaryrefslogtreecommitdiff
path: root/sql/modules/Customer.sql
blob: 40625cbf0865e485d95619039195d1800ce3f358 (plain)
  1. BEGIN;
  2. CREATE OR REPLACE FUNCTION entity_list_contact_class()
  3. RETURNS SETOF contact_class AS
  4. $$
  5. DECLARE out_row RECORD;
  6. BEGIN
  7. FOR out_row IN
  8. SELECT * FROM contact_class ORDER BY id
  9. LOOP
  10. RETURN NEXT out_row;
  11. END LOOP;
  12. END;
  13. $$ language plpgsql;
  14. CREATE TYPE customer_search_return AS (
  15. legal_name text,
  16. id int,
  17. entity_id int,
  18. entity_class int,
  19. discount numeric,
  20. taxincluded bool,
  21. creditlimit numeric,
  22. terms int2,
  23. customernumber int,
  24. business_id int,
  25. language_code text,
  26. pricegroup_id int,
  27. curr char(3),
  28. startdate date,
  29. enddate date
  30. );
  31. CREATE OR REPLACE FUNCTION customer__retrieve(in_entity_id int) RETURNS
  32. customer_search_return AS
  33. $$
  34. DECLARE out_row customer_search_return;
  35. BEGIN
  36. SELECT c.legal_name, c.id, e.id, ec.entity_class, ec.discount,
  37. ec.taxincluded, ec.creditlimit, ec.terms, ec.meta_number,
  38. ec.business_id, ec.language_code, ec.pricegroup_id,
  39. ec.curr::char(3), ec.startdate, ec.enddate
  40. INTO out_row
  41. FROM company c
  42. JOIN entity e ON (c.entity_id = e.id)
  43. JOIN entity_credit_account ec ON (c.entity_id = ec.entity_id)
  44. WHERE e.id = in_entity_id
  45. AND ec.entity_class = 2;
  46. RETURN out_row;
  47. END;
  48. $$ LANGUAGE PLPGSQL;
  49. -- COMMENT ON TYPE customer_search_result IS
  50. -- $$ This structure will change greatly in 1.4.
  51. -- If you want to reply on it heavily, be prepared for breakage later. $$;
  52. CREATE OR REPLACE FUNCTION entity_credit_save (
  53. in_id int, in_entity_class int,
  54. in_discount numeric, in_taxincluded bool, in_creditlimit numeric,
  55. in_discount_terms int,
  56. in_terms int, in_meta_number varchar(32), in_business_id int,
  57. in_language varchar(6), in_pricegroup_id int,
  58. in_curr char, in_startdate date, in_enddate date,
  59. in_notes text,
  60. in_name text, in_tax_id TEXT,
  61. in_threshold NUMERIC
  62. ) returns INT as $$
  63. DECLARE
  64. t_entity_class int;
  65. new_entity_id int;
  66. v_row company;
  67. l_id int;
  68. BEGIN
  69. SELECT INTO v_row * FROM company WHERE id = in_id;
  70. IF NOT FOUND THEN
  71. -- do some inserts
  72. select nextval('entity_id_seq') into new_entity_id;
  73. insert into entity (id, name, entity_class)
  74. VALUES (new_entity_id, in_name, in_entity_class);
  75. INSERT INTO company ( entity_id, legal_name, tax_id )
  76. VALUES ( new_entity_id, in_name, in_tax_id );
  77. INSERT INTO entity_credit_account (
  78. entity_id,
  79. entity_class,
  80. discount,
  81. taxincluded,
  82. creditlimit,
  83. terms,
  84. meta_number,
  85. business_id,
  86. language_code,
  87. pricegroup_id,
  88. curr,
  89. startdate,
  90. enddate,
  91. discount_terms,
  92. threshold
  93. )
  94. VALUES (
  95. new_entity_id,
  96. in_entity_class,
  97. in_discount / 100,
  98. in_taxincluded,
  99. in_creditlimit,
  100. in_terms,
  101. in_meta_number,
  102. in_business_id,
  103. in_language,
  104. in_pricegroup_id,
  105. in_curr,
  106. in_startdate,
  107. in_enddate,
  108. in_discount_terms,
  109. in_threshold
  110. );
  111. -- entity note class
  112. insert into entity_note (note_class, note, ref_key, vector) VALUES (
  113. 1, in_notes, new_entity_id, '');
  114. return new_entity_id;
  115. ELSIF FOUND THEN
  116. update company set tax_id = in_tax_id where id = in_id;
  117. update entity_credit_account SET
  118. discount = in_discount,
  119. taxincluded = in_taxincluded,
  120. creditlimit = in_creditlimit,
  121. terms = in_terms,
  122. meta_number = in_meta_number,
  123. business_id = in_business_id,
  124. language_code = in_language,
  125. pricegroup_id = in_pricegroup_id,
  126. curr = in_curr,
  127. startdate = in_startdate,
  128. enddate = in_enddate,
  129. threshold = in_threshold,
  130. discount_terms = in_discount_terms
  131. where entity_id = v_row.entity_id;
  132. UPDATE entity_note SET
  133. note = in_note
  134. WHERE ref_key = v_row.entity_id;
  135. return in_id;
  136. END IF;
  137. END;
  138. $$ language 'plpgsql';
  139. CREATE TYPE location_result AS (
  140. id int,
  141. line_one text,
  142. line_two text,
  143. line_three text,
  144. city text,
  145. state text,
  146. country text,
  147. class text
  148. );
  149. CREATE OR REPLACE FUNCTION company__list_locations(in_entity_id int)
  150. RETURNS SETOF location_result AS
  151. $$
  152. DECLARE out_row RECORD;
  153. BEGIN
  154. FOR out_row IN
  155. SELECT l.id, l.line_one, l.line_two, l.line_three, l.city,
  156. l.state, c.name, lc.class
  157. FROM location l
  158. JOIN company_to_location ctl ON (ctl.location_id = l.id)
  159. JOIN company cp ON (ctl.company_id = cp.id)
  160. JOIN location_class lc ON (ctl.location_class = lc.id)
  161. JOIN country c ON (c.id = l.country_id)
  162. WHERE cp.entity_id = in_entity_id
  163. ORDER BY lc.id, l.id, c.name
  164. LOOP
  165. RETURN NEXT out_row;
  166. END LOOP;
  167. END;
  168. $$ LANGUAGE PLPGSQL;
  169. CREATE TYPE contact_list AS (
  170. class text,
  171. contact text
  172. );
  173. CREATE OR REPLACE FUNCTION company__list_contacts(in_entity_id int)
  174. RETURNS SETOF contact_list AS
  175. $$
  176. DECLARE out_row RECORD;
  177. BEGIN
  178. FOR out_row IN
  179. SELECT cc.class, c.contact
  180. FROM company_to_contact c
  181. JOIN contact_class cc ON (c.contact_class_id = cc.id)
  182. JOIN company cp ON (c.company_id = cp.id)
  183. WHERE cp.entity_id = in_entity_id
  184. LOOP
  185. RETURN NEXT out_row;
  186. END LOOP;
  187. END;
  188. $$ LANGUAGE plpgsql;
  189. CREATE OR REPLACE FUNCTION company__list_bank_account(in_entity_id int)
  190. RETURNS SETOF entity_bank_account AS
  191. $$
  192. DECLARE out_row entity_bank_account%ROWTYPE;
  193. BEGIN
  194. FOR out_row IN
  195. SELECT * from entity_bank_account where entity_id = in_entity_id
  196. LOOP
  197. RETURN NEXT;
  198. END LOOP;
  199. END;
  200. $$ LANGUAGE PLPGSQL;
  201. CREATE TYPE entity_note_list AS (
  202. id int,
  203. note text
  204. );
  205. CREATE OR REPLACE FUNCTION company__list_notes(in_entity_id int)
  206. RETURNS SETOF entity_note_list AS
  207. $$
  208. DECLARE out_row record;
  209. BEGIN
  210. FOR out_row IN
  211. SELECT id, note
  212. FROM entity_note
  213. WHERE ref_key = in_entity_id
  214. LOOP
  215. RETURN NEXT out_row;
  216. END LOOP;
  217. END;
  218. $$ LANGUAGE PLPGSQL;
  219. CREATE OR REPLACE FUNCTION customer_location_save (
  220. in_company_id int,
  221. in_location_class int, in_line_one text, in_line_two text,
  222. in_line_three text,
  223. in_city TEXT, in_state text, in_mail_code text, in_country_code int
  224. ) returns int AS $$
  225. BEGIN
  226. return _entity_location_save(
  227. in_company_id, NULL,
  228. in_location_class, in_line_one, in_line_two, in_line_three,
  229. in_city, in_state, in_mail_code, in_country_code);
  230. END;
  231. $$ language 'plpgsql';
  232. CREATE OR REPLACE FUNCTION customer_search(in_pattern TEXT) returns setof customer_search_return as $$
  233. -- searches customer name, account number, street address, city, state,
  234. -- other location-based stuff
  235. declare
  236. v_row customer_search_return;
  237. query text;
  238. begin
  239. for v_row in select c.legal_name, v.* from customer v
  240. join company c on c.entity_id = v.entity_id
  241. join entity e on e.id = v.entity_id
  242. join company_to_location ctl on c.id = ctl.company_id
  243. join location l on l.id = ctl.location_id
  244. where l.line_one % in_pattern
  245. OR l.line_two % in_pattern
  246. OR l.line_three % in_pattern
  247. OR l.city_province % in_pattern
  248. OR c.legal_name % in_pattern
  249. OR e.name % in_pattern
  250. LOOP
  251. RETURN NEXT v_row;
  252. END LOOP;
  253. RETURN;
  254. end;
  255. $$ language 'plpgsql';
  256. CREATE OR REPLACE FUNCTION customer_retrieve(INT) returns setof customer as $$
  257. select v.* from customer v
  258. join company c on c.entity_id = v.entity_id
  259. where v.id = $1;
  260. $$ language 'sql';
  261. CREATE OR REPLACE FUNCTION customer_next_customer_id() returns bigint as $$
  262. select nextval('company_id_seq');
  263. $$ language 'sql';
  264. COMMIT;