summaryrefslogtreecommitdiff
path: root/sql/modules/Company.sql
blob: 45fd89dde224a5bc3829571b0edbbce038e8b7f4 (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 TYPE company_billing_info AS (
  212. legal_name text,
  213. tax_id text,
  214. street1 text,
  215. street2 text,
  216. street3 text,
  217. city text,
  218. state text,
  219. mail_code text,
  220. country text
  221. );
  222. CREATE OR REPLACE FUNCTION company_get_billing_info (in_id int)
  223. returns company_billing_info as
  224. $$
  225. DECLARE out_var company_billing_info;
  226. t_id INT;
  227. BEGIN
  228. select c.legal_name, c.tax_id, a.line_one, a.line_two, a.line_three,
  229. a.city, a.state, a.mail_code, cc.name
  230. into out_var
  231. FROM company c
  232. JOIN company_to_location cl ON (c.id = cl.company_id)
  233. JOIN location a ON (a.id = cl.location_id)
  234. JOIN country cc ON (cc.id = a.country_id)
  235. WHERE c.entity_id = (select entity_id
  236. from entity_credit_account where id = in_id)
  237. AND a.id = (SELECT min(location_id) from company_to_location
  238. where company_id = c.id and location_class = 1);
  239. RETURN out_var;
  240. END;
  241. $$ language plpgsql;
  242. CREATE OR REPLACE FUNCTION company_save (
  243. in_id int, in_entity_class int,
  244. in_name text, in_tax_id TEXT,
  245. in_entity_id int, in_sic_code text
  246. ) RETURNS INT AS $$
  247. DECLARE t_entity_id INT;
  248. t_company_id INT;
  249. BEGIN
  250. t_company_id := in_id;
  251. IF in_entity_id IS NULL THEN
  252. IF in_id IS NULL THEN
  253. RAISE NOTICE 'in_id is null';
  254. SELECT id INTO t_company_id FROM company
  255. WHERE legal_name = in_name AND
  256. (tax_id = in_tax_id OR
  257. (tax_id IS NULL AND in_tax_id IS NULL));
  258. END IF;
  259. IF t_company_id IS NOT NULL THEN
  260. SELECT entity_id INTO t_entity_id FROM company
  261. WHERE id = t_company_id;
  262. END IF;
  263. ELSE
  264. t_entity_id := in_entity_id;
  265. END IF;
  266. IF t_entity_id IS NULL THEN
  267. INSERT INTO entity (name, entity_class)
  268. VALUES (in_name, in_entity_class);
  269. t_entity_id := currval('entity_id_seq');
  270. END IF;
  271. UPDATE company
  272. SET legal_name = in_name,
  273. tax_id = in_tax_id,
  274. sic_code = in_sic_code
  275. WHERE id = t_company_id;
  276. IF NOT FOUND THEN
  277. INSERT INTO company(entity_id, legal_name, tax_id, sic_code)
  278. VALUES (t_entity_id, in_name, in_tax_id, in_sic_code);
  279. END IF;
  280. RETURN t_entity_id;
  281. END;
  282. $$ LANGUAGE PLPGSQL;
  283. CREATE OR REPLACE FUNCTION entity_credit_save (
  284. in_credit_id int, in_entity_class int,
  285. in_entity_id int,
  286. in_discount numeric, in_taxincluded bool, in_creditlimit numeric,
  287. in_discount_terms int,
  288. in_terms int, in_meta_number varchar(32), in_business_id int,
  289. in_language varchar(6), in_pricegroup_id int,
  290. in_curr char, in_startdate date, in_enddate date,
  291. in_threshold NUMERIC,
  292. in_ar_ap_account_id int,
  293. in_cash_account_id int
  294. ) returns INT as $$
  295. DECLARE
  296. t_entity_class int;
  297. l_id int;
  298. BEGIN
  299. update entity_credit_account SET
  300. discount = in_discount,
  301. taxincluded = in_taxincluded,
  302. creditlimit = in_creditlimit,
  303. terms = in_terms,
  304. ar_ap_account_id = in_ar_ap_account_id,
  305. cash_account_id = in_cash_account_id,
  306. meta_number = in_meta_number,
  307. business_id = in_business_id,
  308. language_code = in_language,
  309. pricegroup_id = in_pricegroup_id,
  310. curr = in_curr,
  311. startdate = in_startdate,
  312. enddate = in_enddate,
  313. threshold = in_threshold,
  314. discount_terms = in_discount_terms
  315. where id = in_credit_id;
  316. IF FOUND THEN
  317. RETURN in_credit_id;
  318. ELSE
  319. INSERT INTO entity_credit_account (
  320. entity_id,
  321. entity_class,
  322. discount,
  323. taxincluded,
  324. creditlimit,
  325. terms,
  326. meta_number,
  327. business_id,
  328. language_code,
  329. pricegroup_id,
  330. curr,
  331. startdate,
  332. enddate,
  333. discount_terms,
  334. threshold,
  335. ar_ap_account_id,
  336. cash_account_id
  337. )
  338. VALUES (
  339. in_entity_id,
  340. in_entity_class,
  341. in_discount / 100,
  342. in_taxincluded,
  343. in_creditlimit,
  344. in_terms,
  345. in_meta_number,
  346. in_business_id,
  347. in_language,
  348. in_pricegroup_id,
  349. in_curr,
  350. in_startdate,
  351. in_enddate,
  352. in_discount_terms,
  353. in_threshold,
  354. in_ar_ap_account_id,
  355. in_cash_account_id
  356. );
  357. -- entity note class
  358. RETURN currval('entity_credit_account_id_seq');
  359. END IF;
  360. END;
  361. $$ language 'plpgsql';
  362. CREATE OR REPLACE FUNCTION company__list_locations(in_entity_id int)
  363. RETURNS SETOF location_result AS
  364. $$
  365. DECLARE out_row RECORD;
  366. BEGIN
  367. FOR out_row IN
  368. SELECT l.id, l.line_one, l.line_two, l.line_three, l.city,
  369. l.state, l.mail_code, c.name, lc.class
  370. FROM location l
  371. JOIN company_to_location ctl ON (ctl.location_id = l.id)
  372. JOIN company cp ON (ctl.company_id = cp.id)
  373. JOIN location_class lc ON (ctl.location_class = lc.id)
  374. JOIN country c ON (c.id = l.country_id)
  375. WHERE cp.entity_id = in_entity_id
  376. ORDER BY lc.id, l.id, c.name
  377. LOOP
  378. RETURN NEXT out_row;
  379. END LOOP;
  380. END;
  381. $$ LANGUAGE PLPGSQL;
  382. CREATE TYPE contact_list AS (
  383. class text,
  384. description text,
  385. contact text
  386. );
  387. CREATE OR REPLACE FUNCTION company__list_contacts(in_entity_id int)
  388. RETURNS SETOF contact_list AS $$
  389. DECLARE out_row contact_list;
  390. BEGIN
  391. FOR out_row IN
  392. SELECT cl.class, c.description, c.contact
  393. FROM company_to_contact c
  394. JOIN contact_class cl ON (c.contact_class_id = cl.id)
  395. WHERE company_id =
  396. (select id FROM company
  397. WHERE entity_id = in_entity_id)
  398. LOOP
  399. return next out_row;
  400. END LOOP;
  401. END;
  402. $$ language plpgsql;
  403. CREATE OR REPLACE FUNCTION company__list_bank_account(in_entity_id int)
  404. RETURNS SETOF entity_bank_account AS
  405. $$
  406. DECLARE out_row entity_bank_account%ROWTYPE;
  407. BEGIN
  408. FOR out_row IN
  409. SELECT * from entity_bank_account where entity_id = in_entity_id
  410. LOOP
  411. RETURN NEXT out_row;
  412. END LOOP;
  413. END;
  414. $$ LANGUAGE PLPGSQL;
  415. CREATE OR REPLACE FUNCTION entity__save_bank_account
  416. (in_entity_id int, in_bic text, in_iban text)
  417. RETURNS int AS
  418. $$
  419. DECLARE out_id int;
  420. BEGIN
  421. INSERT INTO entity_bank_account(entity_id, bic, iban)
  422. VALUES(in_entity_id, in_bic, in_iban);
  423. SELECT CURRVAL('entity_bank_account_id_seq') INTO out_id ;
  424. RETURN out_id;
  425. END;
  426. $$ LANGUAGE PLPGSQL;
  427. CREATE OR REPLACE FUNCTION company__save_contact
  428. (in_entity_id int, in_contact_class int, in_description text, in_contact text)
  429. RETURNS INT AS
  430. $$
  431. DECLARE out_id int;
  432. BEGIN
  433. INSERT INTO company_to_contact(company_id, contact_class_id,
  434. description, contact)
  435. SELECT id, in_contact_class, in_description, in_contact FROM company
  436. WHERE entity_id = in_entity_id;
  437. RETURN 1;
  438. END;
  439. $$ LANGUAGE PLPGSQL;
  440. CREATE TYPE entity_note_list AS (
  441. id int,
  442. note text
  443. );
  444. CREATE OR REPLACE FUNCTION company__list_notes(in_entity_id int)
  445. RETURNS SETOF entity_note AS
  446. $$
  447. DECLARE out_row record;
  448. BEGIN
  449. FOR out_row IN
  450. SELECT *
  451. FROM entity_note
  452. WHERE ref_key = in_entity_id
  453. LOOP
  454. RETURN NEXT out_row;
  455. END LOOP;
  456. END;
  457. $$ LANGUAGE PLPGSQL;
  458. CREATE OR REPLACE FUNCTION company__next_id() returns bigint as $$
  459. select nextval('company_id_seq');
  460. $$ language 'sql';
  461. CREATE OR REPLACE FUNCTION company__location_save (
  462. in_entity_id int, in_location_id int,
  463. in_location_class int, in_line_one text, in_line_two text,
  464. in_city TEXT, in_state TEXT, in_mail_code text, in_country_code int,
  465. in_created date
  466. ) returns int AS $$
  467. BEGIN
  468. return _entity_location_save(
  469. in_entity_id, in_location_id,
  470. in_location_class, in_line_one, in_line_two,
  471. '', in_city , in_state, in_mail_code, in_country_code);
  472. END;
  473. $$ language 'plpgsql';
  474. create or replace function _entity_location_save(
  475. in_entity_id int, in_location_id int,
  476. in_location_class int, in_line_one text, in_line_two text,
  477. in_line_three text, in_city TEXT, in_state TEXT, in_mail_code text,
  478. in_country_code int
  479. ) returns int AS $$
  480. DECLARE
  481. l_row location;
  482. l_id INT;
  483. t_company_id int;
  484. BEGIN
  485. SELECT id INTO t_company_id
  486. FROM company WHERE entity_id = in_entity_id;
  487. DELETE FROM company_to_location
  488. WHERE company_id = t_company_id
  489. AND location_class = in_location_class
  490. AND location_id = in_location_id;
  491. SELECT location_save(in_line_one, in_line_two, in_line_three, in_city,
  492. in_state, in_mail_code, in_country_code)
  493. INTO l_id;
  494. INSERT INTO company_to_location
  495. (company_id, location_class, location_id)
  496. VALUES (t_company_id, in_location_class, l_id);
  497. RETURN l_id;
  498. END;
  499. $$ language 'plpgsql';
  500. -- COMMIT;