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