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