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