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