summaryrefslogtreecommitdiff
path: root/sql/modules/Company.sql
blob: 45eebee7717164fed83fe7c896608e0ae1b3d633 (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 eca__save_notes(in_credit_id int, in_note text)
  98. RETURNS INT AS
  99. $$
  100. DECLARE out_id int;
  101. BEGIN
  102. -- TODO, change this to create vector too
  103. INSERT INTO eca_note (ref_key, note_class, note, vector)
  104. VALUES (in_credit_id, 3, in_note, '');
  105. SELECT currval('note_id_seq') INTO out_id;
  106. RETURN out_id;
  107. END;
  108. $$ LANGUAGE PLPGSQL;
  109. CREATE OR REPLACE FUNCTION entity_credit_get_id_by_meta_number
  110. (in_meta_number text, in_account_class int)
  111. returns int AS
  112. $$
  113. DECLARE out_credit_id int;
  114. BEGIN
  115. SELECT id INTO out_credit_id
  116. FROM entity_credit_account
  117. WHERE meta_number = in_meta_number
  118. AND entity_class = in_account_class;
  119. RETURN out_credit_id;
  120. END;
  121. $$ LANGUAGE plpgsql;
  122. CREATE OR REPLACE FUNCTION entity_list_contact_class()
  123. RETURNS SETOF contact_class AS
  124. $$
  125. DECLARE out_row RECORD;
  126. BEGIN
  127. FOR out_row IN
  128. SELECT * FROM contact_class ORDER BY id
  129. LOOP
  130. RETURN NEXT out_row;
  131. END LOOP;
  132. END;
  133. $$ language plpgsql;
  134. CREATE TYPE entity_credit_search_return AS (
  135. legal_name text,
  136. id int,
  137. entity_id int,
  138. entity_class int,
  139. discount numeric,
  140. taxincluded bool,
  141. creditlimit numeric,
  142. terms int2,
  143. meta_number text,
  144. business_id int,
  145. language_code text,
  146. pricegroup_id int,
  147. curr char(3),
  148. startdate date,
  149. enddate date,
  150. ar_ap_account_id int,
  151. cash_account_id int,
  152. tax_id text,
  153. threshold numeric
  154. );
  155. CREATE TYPE entity_credit_retrieve AS (
  156. id int,
  157. entity_id int,
  158. entity_class int,
  159. discount numeric,
  160. taxincluded bool,
  161. creditlimit numeric,
  162. terms int2,
  163. meta_number text,
  164. business_id int,
  165. language_code text,
  166. pricegroup_id int,
  167. curr text,
  168. startdate date,
  169. enddate date,
  170. ar_ap_account_id int,
  171. cash_account_id int,
  172. threshold numeric,
  173. control_code text,
  174. credit_id int
  175. );
  176. COMMENT ON TYPE entity_credit_search_return IS
  177. $$ This may change in 1.4 and should not be relied upon too much $$;
  178. CREATE OR REPLACE FUNCTION entity_credit_get_id
  179. (in_entity_id int, in_entity_class int, in_meta_number text)
  180. RETURNS int AS $$
  181. DECLARE out_var int;
  182. BEGIN
  183. SELECT id INTO out_var FROM entity_credit_account
  184. WHERE entity_id = in_entity_id
  185. AND in_entity_class = entity_class
  186. AND in_meta_number = meta_number;
  187. RETURN out_var;
  188. END;
  189. $$ language plpgsql;
  190. CREATE OR REPLACE FUNCTION entity__list_credit
  191. (in_entity_id int, in_entity_class int)
  192. RETURNS SETOF entity_credit_retrieve AS
  193. $$
  194. DECLARE out_row entity_credit_retrieve;
  195. BEGIN
  196. FOR out_row IN
  197. SELECT c.id, e.id, ec.entity_class, ec.discount,
  198. ec.taxincluded, ec.creditlimit, ec.terms,
  199. ec.meta_number, ec.business_id, ec.language_code,
  200. ec.pricegroup_id, ec.curr, ec.startdate,
  201. ec.enddate, ec.ar_ap_account_id, ec.cash_account_id,
  202. ec.threshold, e.control_code, ec.id
  203. FROM company c
  204. JOIN entity e ON (c.entity_id = e.id)
  205. JOIN entity_credit_account ec ON (c.entity_id = ec.entity_id)
  206. WHERE e.id = in_entity_id
  207. AND ec.entity_class =
  208. CASE WHEN in_entity_class = 3 THEN 2
  209. WHEN in_entity_class IS NULL
  210. THEN ec.entity_class
  211. ELSE in_entity_class END
  212. LOOP
  213. RETURN NEXT out_row;
  214. END LOOP;
  215. END;
  216. $$ LANGUAGE PLPGSQL;
  217. CREATE OR REPLACE FUNCTION company_retrieve (in_entity_id int) RETURNS company AS
  218. $$
  219. DECLARE t_company company;
  220. BEGIN
  221. SELECT * INTO t_company FROM company WHERE entity_id = in_entity_id;
  222. RETURN t_company;
  223. END;
  224. $$ language plpgsql;
  225. CREATE TYPE company_billing_info AS (
  226. legal_name text,
  227. tax_id text,
  228. street1 text,
  229. street2 text,
  230. street3 text,
  231. city text,
  232. state text,
  233. mail_code text,
  234. country text
  235. );
  236. CREATE OR REPLACE FUNCTION company_get_billing_info (in_id int)
  237. returns company_billing_info as
  238. $$
  239. DECLARE out_var company_billing_info;
  240. t_id INT;
  241. BEGIN
  242. select c.legal_name, c.tax_id, a.line_one, a.line_two, a.line_three,
  243. a.city, a.state, a.mail_code, cc.name
  244. into out_var
  245. FROM company c
  246. JOIN company eca ON (eca.entity_id = c.entity_id)
  247. JOIN company_to_location cl ON (eca.id = cl.credit_id)
  248. JOIN location a ON (a.id = cl.location_id)
  249. JOIN country cc ON (cc.id = a.country_id)
  250. WHERE eca.id = in_id AND location_class = 1;
  251. RETURN out_var;
  252. END;
  253. $$ language plpgsql;
  254. CREATE OR REPLACE FUNCTION company_save (
  255. in_id int, in_control_code text, in_entity_class int,
  256. in_name text, in_tax_id TEXT,
  257. in_entity_id int, in_sic_code text
  258. ) RETURNS INT AS $$
  259. DECLARE t_entity_id INT;
  260. t_company_id INT;
  261. t_control_code TEXT;
  262. BEGIN
  263. t_company_id := in_id;
  264. IF in_control_code IS NULL THEN
  265. t_control_code := setting_increment('company_control');
  266. ELSE
  267. t_control_code := in_control_code;
  268. END IF;
  269. IF in_entity_id IS NULL THEN
  270. IF in_id IS NULL THEN
  271. RAISE NOTICE 'in_id is null';
  272. SELECT id INTO t_company_id FROM company
  273. WHERE entity_id = (SELECT id FROM entity WHERE
  274. control_code = t_control_code);
  275. END IF;
  276. IF t_company_id IS NOT NULL THEN
  277. SELECT entity_id INTO t_entity_id FROM company
  278. WHERE id = t_company_id;
  279. END IF;
  280. ELSE
  281. t_entity_id := in_entity_id;
  282. END IF;
  283. IF t_entity_id IS NULL THEN
  284. INSERT INTO entity (name, entity_class, control_code)
  285. VALUES (in_name, in_entity_class, t_control_code);
  286. t_entity_id := currval('entity_id_seq');
  287. END IF;
  288. UPDATE company
  289. SET legal_name = in_name,
  290. tax_id = in_tax_id,
  291. sic_code = in_sic_code
  292. WHERE id = t_company_id;
  293. IF NOT FOUND THEN
  294. INSERT INTO company(entity_id, legal_name, tax_id, sic_code)
  295. VALUES (t_entity_id, in_name, in_tax_id, in_sic_code);
  296. END IF;
  297. RETURN t_entity_id;
  298. END;
  299. $$ LANGUAGE PLPGSQL;
  300. CREATE OR REPLACE FUNCTION entity_credit_save (
  301. in_credit_id int, in_entity_class int,
  302. in_entity_id int,
  303. in_discount numeric, in_taxincluded bool, in_creditlimit numeric,
  304. in_discount_terms int,
  305. in_terms int, in_meta_number varchar(32), in_business_id int,
  306. in_language varchar(6), in_pricegroup_id int,
  307. in_curr char, in_startdate date, in_enddate date,
  308. in_threshold NUMERIC,
  309. in_ar_ap_account_id int,
  310. in_cash_account_id int
  311. ) returns INT as $$
  312. DECLARE
  313. t_entity_class int;
  314. l_id int;
  315. BEGIN
  316. update entity_credit_account SET
  317. discount = in_discount,
  318. taxincluded = in_taxincluded,
  319. creditlimit = in_creditlimit,
  320. terms = in_terms,
  321. ar_ap_account_id = in_ar_ap_account_id,
  322. cash_account_id = in_cash_account_id,
  323. meta_number = in_meta_number,
  324. business_id = in_business_id,
  325. language_code = in_language,
  326. pricegroup_id = in_pricegroup_id,
  327. curr = in_curr,
  328. startdate = in_startdate,
  329. enddate = in_enddate,
  330. threshold = in_threshold,
  331. discount_terms = in_discount_terms
  332. where id = in_credit_id;
  333. IF FOUND THEN
  334. RETURN in_credit_id;
  335. ELSE
  336. INSERT INTO entity_credit_account (
  337. entity_id,
  338. entity_class,
  339. discount,
  340. taxincluded,
  341. creditlimit,
  342. terms,
  343. meta_number,
  344. business_id,
  345. language_code,
  346. pricegroup_id,
  347. curr,
  348. startdate,
  349. enddate,
  350. discount_terms,
  351. threshold,
  352. ar_ap_account_id,
  353. cash_account_id
  354. )
  355. VALUES (
  356. in_entity_id,
  357. in_entity_class,
  358. in_discount / 100,
  359. in_taxincluded,
  360. in_creditlimit,
  361. in_terms,
  362. in_meta_number,
  363. in_business_id,
  364. in_language,
  365. in_pricegroup_id,
  366. in_curr,
  367. in_startdate,
  368. in_enddate,
  369. in_discount_terms,
  370. in_threshold,
  371. in_ar_ap_account_id,
  372. in_cash_account_id
  373. );
  374. -- entity note class
  375. RETURN currval('entity_credit_account_id_seq');
  376. END IF;
  377. END;
  378. $$ language 'plpgsql';
  379. CREATE OR REPLACE FUNCTION company__list_locations(in_entity_id int)
  380. RETURNS SETOF location_result AS
  381. $$
  382. DECLARE out_row RECORD;
  383. BEGIN
  384. FOR out_row IN
  385. SELECT l.id, l.line_one, l.line_two, l.line_three, l.city,
  386. l.state, l.mail_code, c.name, lc.class
  387. FROM location l
  388. JOIN company_to_location ctl ON (ctl.location_id = l.id)
  389. JOIN location_class lc ON (ctl.location_class = lc.id)
  390. JOIN country c ON (c.id = l.country_id)
  391. WHERE ctl.company_id = (select id from company where entity_id = in_entity_id)
  392. ORDER BY lc.id, l.id, c.name
  393. LOOP
  394. RETURN NEXT out_row;
  395. END LOOP;
  396. END;
  397. $$ LANGUAGE PLPGSQL;
  398. CREATE TYPE contact_list AS (
  399. class text,
  400. description text,
  401. contact text
  402. );
  403. CREATE OR REPLACE FUNCTION company__list_contacts(in_entity_id int)
  404. RETURNS SETOF contact_list AS $$
  405. DECLARE out_row contact_list;
  406. BEGIN
  407. FOR out_row IN
  408. SELECT cl.class, c.description, c.contact
  409. FROM company_to_contact c
  410. JOIN contact_class cl ON (c.contact_class_id = cl.id)
  411. WHERE company_id =
  412. (select id FROM company
  413. WHERE entity_id = in_entity_id)
  414. LOOP
  415. return next out_row;
  416. END LOOP;
  417. END;
  418. $$ language plpgsql;
  419. CREATE OR REPLACE FUNCTION company__list_bank_account(in_entity_id int)
  420. RETURNS SETOF entity_bank_account AS
  421. $$
  422. DECLARE out_row entity_bank_account%ROWTYPE;
  423. BEGIN
  424. FOR out_row IN
  425. SELECT * from entity_bank_account where entity_id = in_entity_id
  426. LOOP
  427. RETURN NEXT out_row;
  428. END LOOP;
  429. END;
  430. $$ LANGUAGE PLPGSQL;
  431. CREATE OR REPLACE FUNCTION entity__save_bank_account
  432. (in_entity_id int, in_credit_id int, in_bic text, in_iban text)
  433. RETURNS int AS
  434. $$
  435. DECLARE out_id int;
  436. BEGIN
  437. INSERT INTO entity_bank_account(entity_id, bic, iban)
  438. VALUES(in_entity_id, in_bic, in_iban);
  439. SELECT CURRVAL('entity_bank_account_id_seq') INTO out_id ;
  440. IF in_credit_id IS NOT NULL THEN
  441. UPDATE entity_credit_account SET bank_account = out_id
  442. WHERE id = in_credit_id;
  443. END IF;
  444. RETURN out_id;
  445. END;
  446. $$ LANGUAGE PLPGSQL;
  447. CREATE OR REPLACE FUNCTION entity__save_bank_account
  448. (in_entity_id int, in_bic text, in_iban text)
  449. RETURNS int AS
  450. $$
  451. DECLARE out_id int;
  452. BEGIN
  453. INSERT INTO entity_bank_account(entity_id, bic, iban)
  454. VALUES(in_entity_id, in_bic, in_iban);
  455. SELECT CURRVAL('entity_bank_account_id_seq') INTO out_id ;
  456. RETURN out_id;
  457. END;
  458. $$ LANGUAGE PLPGSQL;
  459. CREATE OR REPLACE FUNCTION company__save_contact
  460. (in_entity_id int, in_contact_class int, in_description text, in_contact text)
  461. RETURNS INT AS
  462. $$
  463. DECLARE out_id int;
  464. BEGIN
  465. INSERT INTO company_to_contact(company_id, contact_class_id,
  466. description, contact)
  467. SELECT id, in_contact_class, in_description, in_contact FROM company
  468. WHERE entity_id = in_entity_id;
  469. RETURN 1;
  470. END;
  471. $$ LANGUAGE PLPGSQL;
  472. CREATE TYPE entity_note_list AS (
  473. id int,
  474. note_class int,
  475. note text
  476. );
  477. CREATE OR REPLACE FUNCTION company__list_notes(in_entity_id int)
  478. RETURNS SETOF entity_note AS
  479. $$
  480. DECLARE out_row record;
  481. BEGIN
  482. FOR out_row IN
  483. SELECT *
  484. FROM entity_note
  485. WHERE ref_key = in_entity_id
  486. ORDER BY created
  487. LOOP
  488. RETURN NEXT out_row;
  489. END LOOP;
  490. END;
  491. $$ LANGUAGE PLPGSQL;
  492. CREATE OR REPLACE FUNCTION eca__list_notes(in_credit_id int)
  493. RETURNS SETOF note AS
  494. $$
  495. DECLARE out_row record;
  496. t_entity_id int;
  497. BEGIN
  498. SELECT entity_id INTO t_entity_id
  499. FROM entity_credit_account
  500. WHERE id = in_credit_id;
  501. FOR out_row IN
  502. SELECT *
  503. FROM note
  504. WHERE (note_class = 3 and ref_key = in_credit_id) or
  505. (note_class = 1 and ref_key = t_entity_id)
  506. ORDER BY created
  507. LOOP
  508. RETURN NEXT out_row;
  509. END LOOP;
  510. END;
  511. $$ LANGUAGE PLPGSQL SECURITY DEFINER;
  512. REVOKE EXECUTE ON FUNCTION eca__list_notes(INT) FROM public;
  513. CREATE OR REPLACE FUNCTION company__next_id() returns bigint as $$
  514. select nextval('company_id_seq');
  515. $$ language 'sql';
  516. CREATE OR REPLACE FUNCTION company__location_save (
  517. in_entity_id int, in_location_id int,
  518. in_location_class int, in_line_one text, in_line_two text,
  519. in_city TEXT, in_state TEXT, in_mail_code text, in_country_code int,
  520. in_created date
  521. ) returns int AS $$
  522. BEGIN
  523. return _entity_location_save(
  524. in_entity_id, in_location_id,
  525. in_location_class, in_line_one, in_line_two,
  526. '', in_city , in_state, in_mail_code, in_country_code);
  527. END;
  528. $$ language 'plpgsql';
  529. create or replace function _entity_location_save(
  530. in_entity_id int, in_location_id int,
  531. in_location_class int, in_line_one text, in_line_two text,
  532. in_line_three text, in_city TEXT, in_state TEXT, in_mail_code text,
  533. in_country_code int
  534. ) returns int AS $$
  535. DECLARE
  536. l_row location;
  537. l_id INT;
  538. t_company_id int;
  539. BEGIN
  540. SELECT id INTO t_company_id
  541. FROM company WHERE entity_id = in_entity_id;
  542. DELETE FROM company_to_location
  543. WHERE company_id = t_company_id
  544. AND location_class = in_location_class
  545. AND location_id = in_location_id;
  546. SELECT location_save(in_line_one, in_line_two, in_line_three, in_city,
  547. in_state, in_mail_code, in_country_code)
  548. INTO l_id;
  549. INSERT INTO company_to_location
  550. (company_id, location_class, location_id)
  551. VALUES (t_company_id, in_location_class, l_id);
  552. RETURN l_id;
  553. END;
  554. $$ language 'plpgsql';
  555. -- COMMIT;