summaryrefslogtreecommitdiff
path: root/sql/modules/Company.sql
blob: d653d9f73fc78831412ec60c12b163c551136a1f (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. CREATE TYPE entity_credit_retrieve AS (
  144. id int,
  145. entity_id int,
  146. entity_class int,
  147. discount numeric,
  148. taxincluded bool,
  149. creditlimit numeric,
  150. terms int2,
  151. meta_number text,
  152. business_id int,
  153. language_code text,
  154. pricegroup_id int,
  155. curr text,
  156. startdate date,
  157. enddate date,
  158. ar_ap_account_id int,
  159. cash_account_id int,
  160. threshold numeric
  161. );
  162. COMMENT ON TYPE entity_credit_search_return IS
  163. $$ This may change in 1.4 and should not be relied upon too much $$;
  164. CREATE OR REPLACE FUNCTION entity_credit_get_id
  165. (in_entity_id int, in_entity_class int, in_meta_number text)
  166. RETURNS int AS $$
  167. DECLARE out_var int;
  168. BEGIN
  169. SELECT id INTO out_var FROM entity_credit_account
  170. WHERE entity_id = in_entity_id
  171. AND in_entity_class = entity_class
  172. AND in_meta_number = meta_number;
  173. RETURN out_var;
  174. END;
  175. $$ language plpgsql;
  176. CREATE OR REPLACE FUNCTION entity__list_credit
  177. (in_entity_id int, in_entity_class int)
  178. RETURNS SETOF entity_credit_retrieve AS
  179. $$
  180. DECLARE out_row entity_credit_retrieve;
  181. BEGIN
  182. FOR out_row IN
  183. SELECT c.id, e.id, ec.entity_class, ec.discount,
  184. ec.taxincluded, ec.creditlimit, ec.terms,
  185. ec.meta_number, ec.business_id, ec.language_code,
  186. ec.pricegroup_id, ec.curr, ec.startdate,
  187. ec.enddate, ec.ar_ap_account_id, ec.cash_account_id,
  188. c.tax_id, ec.threshold
  189. FROM company c
  190. JOIN entity e ON (c.entity_id = e.id)
  191. JOIN entity_credit_account ec ON (c.entity_id = ec.entity_id)
  192. WHERE e.id = in_entity_id
  193. AND ec.entity_class =
  194. CASE WHEN in_entity_class = 3 THEN 2
  195. WHEN in_entity_class IS NULL
  196. THEN ec.entity_class
  197. ELSE in_entity_class END
  198. LOOP
  199. RETURN NEXT out_row;
  200. END LOOP;
  201. END;
  202. $$ LANGUAGE PLPGSQL;
  203. CREATE OR REPLACE FUNCTION company_retrieve (in_entity_id int) RETURNS company AS
  204. $$
  205. DECLARE t_company company;
  206. BEGIN
  207. SELECT * INTO t_company FROM company WHERE entity_id = in_entity_id;
  208. RETURN t_company;
  209. END;
  210. $$ language plpgsql;
  211. CREATE OR REPLACE FUNCTION company_save (
  212. in_id int, in_entity_class int,
  213. in_name text, in_tax_id TEXT,
  214. in_entity_id int, in_sic_code text
  215. ) RETURNS INT AS $$
  216. DECLARE t_entity_id INT;
  217. t_company_id INT;
  218. BEGIN
  219. t_company_id := in_id;
  220. IF in_entity_id IS NULL THEN
  221. IF in_id IS NULL THEN
  222. RAISE NOTICE 'in_id is null';
  223. SELECT id INTO t_company_id FROM company
  224. WHERE legal_name = in_name AND
  225. (tax_id = in_tax_id OR
  226. (tax_id IS NULL AND in_tax_id IS NULL));
  227. END IF;
  228. IF t_company_id IS NOT NULL THEN
  229. SELECT entity_id INTO t_entity_id FROM company
  230. WHERE id = t_company_id;
  231. END IF;
  232. ELSE
  233. t_entity_id := in_entity_id;
  234. END IF;
  235. IF t_entity_id IS NULL THEN
  236. INSERT INTO entity (name, entity_class)
  237. VALUES (in_name, in_entity_class);
  238. t_entity_id := currval('entity_id_seq');
  239. END IF;
  240. UPDATE company
  241. SET legal_name = in_name,
  242. tax_id = in_tax_id,
  243. sic_code = in_sic_code
  244. WHERE id = t_company_id;
  245. IF NOT FOUND THEN
  246. INSERT INTO company(entity_id, legal_name, tax_id, sic_code)
  247. VALUES (t_entity_id, in_name, in_tax_id, in_sic_code);
  248. END IF;
  249. RETURN t_entity_id;
  250. END;
  251. $$ LANGUAGE PLPGSQL;
  252. CREATE OR REPLACE FUNCTION entity_credit_save (
  253. in_credit_id int, in_entity_class int,
  254. in_entity_id int,
  255. in_discount numeric, in_taxincluded bool, in_creditlimit numeric,
  256. in_discount_terms int,
  257. in_terms int, in_meta_number varchar(32), in_business_id int,
  258. in_language varchar(6), in_pricegroup_id int,
  259. in_curr char, in_startdate date, in_enddate date,
  260. in_threshold NUMERIC,
  261. in_ar_ap_account_id int,
  262. in_cash_account_id int
  263. ) returns INT as $$
  264. DECLARE
  265. t_entity_class int;
  266. l_id int;
  267. BEGIN
  268. update entity_credit_account SET
  269. discount = in_discount,
  270. taxincluded = in_taxincluded,
  271. creditlimit = in_creditlimit,
  272. terms = in_terms,
  273. ar_ap_account_id = in_ar_ap_account_id,
  274. cash_account_id = in_cash_account_id,
  275. meta_number = in_meta_number,
  276. business_id = in_business_id,
  277. language_code = in_language,
  278. pricegroup_id = in_pricegroup_id,
  279. curr = in_curr,
  280. startdate = in_startdate,
  281. enddate = in_enddate,
  282. threshold = in_threshold,
  283. discount_terms = in_discount_terms
  284. where id = in_credit_id;
  285. IF FOUND THEN
  286. RETURN in_credit_id;
  287. ELSE
  288. INSERT INTO entity_credit_account (
  289. entity_id,
  290. entity_class,
  291. discount,
  292. taxincluded,
  293. creditlimit,
  294. terms,
  295. meta_number,
  296. business_id,
  297. language_code,
  298. pricegroup_id,
  299. curr,
  300. startdate,
  301. enddate,
  302. discount_terms,
  303. threshold,
  304. ar_ap_account_id,
  305. cash_account_id
  306. )
  307. VALUES (
  308. in_entity_id,
  309. in_entity_class,
  310. in_discount / 100,
  311. in_taxincluded,
  312. in_creditlimit,
  313. in_terms,
  314. in_meta_number,
  315. in_business_id,
  316. in_language,
  317. in_pricegroup_id,
  318. in_curr,
  319. in_startdate,
  320. in_enddate,
  321. in_discount_terms,
  322. in_threshold,
  323. in_ar_ap_account_id,
  324. in_cash_account_id
  325. );
  326. -- entity note class
  327. RETURN currval('entity_credit_account_id_seq');
  328. END IF;
  329. END;
  330. $$ language 'plpgsql';
  331. CREATE OR REPLACE FUNCTION company__list_locations(in_entity_id int)
  332. RETURNS SETOF location_result AS
  333. $$
  334. DECLARE out_row RECORD;
  335. BEGIN
  336. FOR out_row IN
  337. SELECT l.id, l.line_one, l.line_two, l.line_three, l.city,
  338. l.state, l.mail_code, c.name, lc.class
  339. FROM location l
  340. JOIN company_to_location ctl ON (ctl.location_id = l.id)
  341. JOIN company cp ON (ctl.company_id = cp.id)
  342. JOIN location_class lc ON (ctl.location_class = lc.id)
  343. JOIN country c ON (c.id = l.country_id)
  344. WHERE cp.entity_id = in_entity_id
  345. ORDER BY lc.id, l.id, c.name
  346. LOOP
  347. RETURN NEXT out_row;
  348. END LOOP;
  349. END;
  350. $$ LANGUAGE PLPGSQL;
  351. CREATE TYPE contact_list AS (
  352. class text,
  353. description text,
  354. contact text
  355. );
  356. CREATE OR REPLACE FUNCTION company__list_contacts(in_entity_id int)
  357. RETURNS SETOF contact_list AS $$
  358. DECLARE out_row contact_list;
  359. BEGIN
  360. FOR out_row IN
  361. SELECT cl.class, c.description, c.contact
  362. FROM company_to_contact c
  363. JOIN contact_class cl ON (c.contact_class_id = cl.id)
  364. WHERE company_id =
  365. (select id FROM company
  366. WHERE entity_id = in_entity_id)
  367. LOOP
  368. return next out_row;
  369. END LOOP;
  370. END;
  371. $$ language plpgsql;
  372. CREATE OR REPLACE FUNCTION company__list_bank_account(in_entity_id int)
  373. RETURNS SETOF entity_bank_account AS
  374. $$
  375. DECLARE out_row entity_bank_account%ROWTYPE;
  376. BEGIN
  377. FOR out_row IN
  378. SELECT * from entity_bank_account where entity_id = in_entity_id
  379. LOOP
  380. RETURN NEXT out_row;
  381. END LOOP;
  382. END;
  383. $$ LANGUAGE PLPGSQL;
  384. CREATE OR REPLACE FUNCTION entity__save_bank_account
  385. (in_entity_id int, in_bic text, in_iban text)
  386. RETURNS int AS
  387. $$
  388. DECLARE out_id int;
  389. BEGIN
  390. INSERT INTO entity_bank_account(entity_id, bic, iban)
  391. VALUES(in_entity_id, in_bic, in_iban);
  392. SELECT CURRVAL('entity_bank_account_id_seq') INTO out_id ;
  393. RETURN out_id;
  394. END;
  395. $$ LANGUAGE PLPGSQL;
  396. CREATE OR REPLACE FUNCTION company__save_contact
  397. (in_entity_id int, in_contact_class int, in_description text, in_contact text)
  398. RETURNS INT AS
  399. $$
  400. DECLARE out_id int;
  401. BEGIN
  402. INSERT INTO company_to_contact(company_id, contact_class_id,
  403. description, contact)
  404. SELECT id, in_contact_class, in_description, in_contact FROM company
  405. WHERE entity_id = in_entity_id;
  406. RETURN 1;
  407. END;
  408. $$ LANGUAGE PLPGSQL;
  409. CREATE TYPE entity_note_list AS (
  410. id int,
  411. note text
  412. );
  413. CREATE OR REPLACE FUNCTION company__list_notes(in_entity_id int)
  414. RETURNS SETOF entity_note AS
  415. $$
  416. DECLARE out_row record;
  417. BEGIN
  418. FOR out_row IN
  419. SELECT *
  420. FROM entity_note
  421. WHERE ref_key = in_entity_id
  422. LOOP
  423. RETURN NEXT out_row;
  424. END LOOP;
  425. END;
  426. $$ LANGUAGE PLPGSQL;
  427. CREATE OR REPLACE FUNCTION company__next_id() returns bigint as $$
  428. select nextval('company_id_seq');
  429. $$ language 'sql';
  430. CREATE OR REPLACE FUNCTION company__location_save (
  431. in_entity_id int, in_location_id int,
  432. in_location_class int, in_line_one text, in_line_two text,
  433. in_city TEXT, in_state TEXT, in_mail_code text, in_country_code int,
  434. in_created date
  435. ) returns int AS $$
  436. BEGIN
  437. return _entity_location_save(
  438. in_entity_id, in_location_id,
  439. in_location_class, in_line_one, in_line_two,
  440. '', in_city , in_state, in_mail_code, in_country_code);
  441. END;
  442. $$ language 'plpgsql';
  443. create or replace function _entity_location_save(
  444. in_entity_id int, in_location_id int,
  445. in_location_class int, in_line_one text, in_line_two text,
  446. in_line_three text, in_city TEXT, in_state TEXT, in_mail_code text,
  447. in_country_code int
  448. ) returns int AS $$
  449. DECLARE
  450. l_row location;
  451. l_id INT;
  452. t_company_id int;
  453. BEGIN
  454. SELECT id INTO t_company_id
  455. FROM company WHERE entity_id = in_entity_id;
  456. DELETE FROM company_to_location
  457. WHERE company_id = t_company_id
  458. AND location_class = in_location_class
  459. AND location_id = in_location_id;
  460. SELECT location_save(in_line_one, in_line_two, in_line_three, in_city,
  461. in_state, in_mail_code, in_country_code)
  462. INTO l_id;
  463. INSERT INTO company_to_location
  464. (company_id, location_class, location_id)
  465. VALUES (t_company_id, in_location_class, l_id);
  466. RETURN l_id;
  467. END;
  468. $$ language 'plpgsql';
  469. -- COMMIT;