summaryrefslogtreecommitdiff
path: root/sql/modules/Company.sql
blob: 6b48ddf764f3bea0185390b8cac52ece5ed210cc (plain)
  1. BEGIN;
  2. CREATE OR REPLACE FUNCTION entity__save_notes(in_entity_id int, in_note text)
  3. RETURNS INT AS
  4. $$
  5. DECLARE out_id int;
  6. BEGIN
  7. -- TODO, change this to create vector too
  8. INSERT INTO entity_note (ref_key, note_class, entity_id, note, vector)
  9. VALUES (in_entity_id, 1, in_entity_id, in_note, '');
  10. SELECT currval('note_id_seq') INTO out_id;
  11. RETURN out_id;
  12. END;
  13. $$ LANGUAGE PLPGSQL;
  14. CREATE OR REPLACE FUNCTION entity_list_contact_class()
  15. RETURNS SETOF contact_class AS
  16. $$
  17. DECLARE out_row RECORD;
  18. BEGIN
  19. FOR out_row IN
  20. SELECT * FROM contact_class ORDER BY id
  21. LOOP
  22. RETURN NEXT out_row;
  23. END LOOP;
  24. END;
  25. $$ language plpgsql;
  26. CREATE TYPE entity_credit_search_return AS (
  27. legal_name text,
  28. id int,
  29. entity_id int,
  30. entity_class int,
  31. discount numeric,
  32. taxincluded bool,
  33. creditlimit numeric,
  34. terms int2,
  35. customernumber text,
  36. business_id int,
  37. language_code text,
  38. pricegroup_id int,
  39. curr char(3),
  40. startdate date,
  41. enddate date
  42. );
  43. COMMENT ON TYPE entity_credit_search_return IS
  44. $$ This may change in 1.4 and should not be relied upon too much $$;
  45. CREATE OR REPLACE FUNCTION entity__retrieve_credit
  46. (in_entity_id int, in_entity_class int)
  47. RETURNS entity_credit_search_return AS
  48. $$
  49. DECLARE out_row customer_search_return;
  50. BEGIN
  51. SELECT c.legal_name, c.id, e.id, ec.entity_class, ec.discount,
  52. ec.taxincluded, ec.creditlimit, ec.terms, ec.meta_number,
  53. ec.business_id, ec.language_code, ec.pricegroup_id,
  54. ec.curr::char(3), ec.startdate, ec.enddate
  55. INTO out_row
  56. FROM company c
  57. JOIN entity e ON (c.entity_id = e.id)
  58. JOIN entity_credit_account ec ON (c.entity_id = ec.entity_id)
  59. WHERE e.id = in_entity_id
  60. AND ec.entity_class = CASE WHEN in_entity_class = 3 THEN 2
  61. ELSE in_entity_class END;
  62. RETURN out_row;
  63. END;
  64. $$ LANGUAGE PLPGSQL;
  65. CREATE company
  66. CREATE OR REPLACE FUNCTION entity_credit_save (
  67. in_id int, in_entity_class int,
  68. in_discount numeric, in_taxincluded bool, in_creditlimit numeric,
  69. in_discount_terms int,
  70. in_terms int, in_meta_number varchar(32), in_business_id int,
  71. in_language varchar(6), in_pricegroup_id int,
  72. in_curr char, in_startdate date, in_enddate date,
  73. in_notes text,
  74. in_name text, in_tax_id TEXT,
  75. in_threshold NUMERIC
  76. ) returns INT as $$
  77. DECLARE
  78. t_entity_class int;
  79. new_entity_id int;
  80. v_row company;
  81. l_id int;
  82. BEGIN
  83. -- TODO: Move every table to an upsert mode independantly.
  84. SELECT INTO v_row * FROM company WHERE id = in_id;
  85. IF NOT FOUND THEN
  86. -- do some inserts
  87. select nextval('entity_id_seq') into new_entity_id;
  88. insert into entity (id, name, entity_class)
  89. VALUES (new_entity_id, in_name, in_entity_class);
  90. INSERT INTO company ( entity_id, legal_name, tax_id )
  91. VALUES ( new_entity_id, in_name, in_tax_id );
  92. IF in_entity_class NOT IN (1, 2) THEN
  93. RETURN new_entity_id;
  94. END IF;
  95. INSERT INTO entity_credit_account (
  96. entity_id,
  97. entity_class,
  98. discount,
  99. taxincluded,
  100. creditlimit,
  101. terms,
  102. meta_number,
  103. business_id,
  104. language_code,
  105. pricegroup_id,
  106. curr,
  107. startdate,
  108. enddate,
  109. discount_terms,
  110. threshold
  111. )
  112. VALUES (
  113. new_entity_id,
  114. in_entity_class,
  115. in_discount / 100,
  116. in_taxincluded,
  117. in_creditlimit,
  118. in_terms,
  119. in_meta_number,
  120. in_business_id,
  121. in_language,
  122. in_pricegroup_id,
  123. in_curr,
  124. in_startdate,
  125. in_enddate,
  126. in_discount_terms,
  127. in_threshold
  128. );
  129. -- entity note class
  130. insert into entity_note (note_class, note, ref_key, vector) VALUES (
  131. 1, in_notes, new_entity_id, to_tsvector(in_notes));
  132. return new_entity_id;
  133. ELSIF FOUND THEN
  134. update company set tax_id = in_tax_id where id = in_id;
  135. update entity_credit_account SET
  136. discount = in_discount,
  137. taxincluded = in_taxincluded,
  138. creditlimit = in_creditlimit,
  139. terms = in_terms,
  140. meta_number = in_meta_number,
  141. business_id = in_business_id,
  142. language_code = in_language,
  143. pricegroup_id = in_pricegroup_id,
  144. curr = in_curr,
  145. startdate = in_startdate,
  146. enddate = in_enddate,
  147. threshold = in_threshold,
  148. discount_terms = in_discount_terms
  149. where entity_id = v_row.entity_id;
  150. UPDATE entity_note SET
  151. note = in_note
  152. WHERE ref_key = v_row.entity_id;
  153. return in_id;
  154. END IF;
  155. END;
  156. $$ language 'plpgsql';
  157. CREATE OR REPLACE FUNCTION company__list_locations(in_entity_id int)
  158. RETURNS SETOF location_result AS
  159. $$
  160. DECLARE out_row RECORD;
  161. BEGIN
  162. FOR out_row IN
  163. SELECT l.id, l.line_one, l.line_two, l.line_three, l.city,
  164. l.state, c.name, lc.class
  165. FROM location l
  166. JOIN company_to_location ctl ON (ctl.location_id = l.id)
  167. JOIN company cp ON (ctl.company_id = cp.id)
  168. JOIN location_class lc ON (ctl.location_class = lc.id)
  169. JOIN country c ON (c.id = l.country_id)
  170. WHERE cp.entity_id = in_entity_id
  171. ORDER BY lc.id, l.id, c.name
  172. LOOP
  173. RETURN NEXT out_row;
  174. END LOOP;
  175. END;
  176. $$ LANGUAGE PLPGSQL;
  177. CREATE TYPE contact_list AS (
  178. class text,
  179. contact text
  180. );
  181. CREATE OR REPLACE FUNCTION company__list_contacts(in_entity_id int)
  182. RETURNS SETOF contact_list AS
  183. $$
  184. DECLARE out_row RECORD;
  185. BEGIN
  186. FOR out_row IN
  187. SELECT cc.class, c.contact
  188. FROM company_to_contact c
  189. JOIN contact_class cc ON (c.contact_class_id = cc.id)
  190. JOIN company cp ON (c.company_id = cp.id)
  191. WHERE cp.entity_id = in_entity_id
  192. LOOP
  193. RETURN NEXT out_row;
  194. END LOOP;
  195. END;
  196. $$ LANGUAGE plpgsql;
  197. CREATE OR REPLACE FUNCTION company__list_bank_account(in_entity_id int)
  198. RETURNS SETOF entity_bank_account AS
  199. $$
  200. DECLARE out_row entity_bank_account%ROWTYPE;
  201. BEGIN
  202. FOR out_row IN
  203. SELECT * from entity_bank_account where entity_id = in_entity_id
  204. LOOP
  205. RETURN NEXT out_row;
  206. END LOOP;
  207. END;
  208. $$ LANGUAGE PLPGSQL;
  209. CREATE OR REPLACE FUNCTION entity__save_bank_account
  210. (in_entity_id int, in_bic text, in_iban text)
  211. RETURNS int AS
  212. $$
  213. DECLARE out_id int;
  214. BEGIN
  215. INSERT INTO entity_bank_account(entity_id, bic, iban)
  216. VALUES(in_entity_id, in_bic, in_iban);
  217. SELECT CURRVAL('entity_bank_account_id_seq') INTO out_id ;
  218. RETURN out_id;
  219. END;
  220. $$ LANGUAGE PLPGSQL;
  221. CREATE OR REPLACE FUNCTION company__save_contact
  222. (in_entity_id int, in_contact_class int, in_contact text)
  223. RETURNS INT AS
  224. $$
  225. DECLARE out_id int;
  226. BEGIN
  227. INSERT INTO company_to_contact(company_id, contact_class_id, contact)
  228. SELECT id, in_contact_class, in_contact FROM company
  229. WHERE entity_id = in_entity_id;
  230. RETURN 1;
  231. END;
  232. $$ LANGUAGE PLPGSQL;
  233. CREATE TYPE entity_note_list AS (
  234. id int,
  235. note text
  236. );
  237. CREATE OR REPLACE FUNCTION company__list_notes(in_entity_id int)
  238. RETURNS SETOF entity_note AS
  239. $$
  240. DECLARE out_row record;
  241. BEGIN
  242. FOR out_row IN
  243. SELECT *
  244. FROM entity_note
  245. WHERE ref_key = in_entity_id
  246. LOOP
  247. RETURN NEXT out_row;
  248. END LOOP;
  249. END;
  250. $$ LANGUAGE PLPGSQL;
  251. CREATE OR REPLACE FUNCTION company__next_id() returns bigint as $$
  252. select nextval('company_id_seq');
  253. $$ language 'sql';
  254. CREATE OR REPLACE FUNCTION company__location_save (
  255. in_company_id int,
  256. in_location_class int, in_line_one text, in_line_two text,
  257. in_city_province TEXT, in_mail_code text, in_country_code int,
  258. in_created date
  259. ) returns int AS $$
  260. BEGIN
  261. return _entity_location_save(
  262. in_company_id,
  263. in_location_class, in_line_one, in_line_two,
  264. in_city_province , in_mail_code, in_country_code,
  265. in_created);
  266. END;
  267. $$ language 'plpgsql';
  268. create or replace function _entity_location_save(
  269. in_entity_id int, in_location_id int,
  270. in_location_class int, in_line_one text, in_line_two text,
  271. in_line_three text, in_city TEXT, in_state TEXT, in_mail_code text,
  272. in_country_code int
  273. ) returns int AS $$
  274. DECLARE
  275. l_row location;
  276. l_id INT;
  277. t_company_id int;
  278. BEGIN
  279. SELECT id INTO t_company_id
  280. FROM company WHERE entity_id = in_entity_id;
  281. DELETE FROM company_to_location
  282. WHERE company_id = t_company_id
  283. AND location_class = in_location_class
  284. AND location_id = in_location_id;
  285. SELECT location_save(in_line_one, in_line_two, in_line_three, in_city,
  286. in_state, in_mail_code, in_country_code)
  287. INTO l_id;
  288. INSERT INTO company_to_location
  289. (company_id, location_class, location_id)
  290. VALUES (t_company_id, in_location_class, l_id);
  291. RETURN l_id;
  292. END;
  293. $$ language 'plpgsql';
  294. COMMIT;