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