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