summaryrefslogtreecommitdiff
path: root/sql/modules/Company.sql
blob: 0ee771593e55868fe664d5b5b24ff271d5b6c1fc (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, in_control_code 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 (e.control_code = in_control_code
  34. or in_control_code IS NULL)
  35. AND (c.id IN (select company_id FROM company_to_contact
  36. WHERE contact LIKE ALL(t_contact_info))
  37. OR '' LIKE ALL(t_contact_info))
  38. AND (ec.meta_number = in_meta_number
  39. OR in_meta_number IS NULL)
  40. AND (c.legal_name like '%' || in_legal_name || '%'
  41. OR in_legal_name IS NULL)
  42. AND ((in_address IS NULL AND in_city IS NULL
  43. AND in_state IS NULL
  44. AND in_country IS NULL)
  45. OR (c.id IN
  46. (select company_id FROM company_to_location
  47. WHERE location_id IN
  48. (SELECT id FROM location
  49. WHERE line_one
  50. ilike '%' ||
  51. coalesce(in_address, '')
  52. || '%'
  53. AND city ILIKE
  54. '%' ||
  55. coalesce(in_city, '')
  56. || '%'
  57. AND state ILIKE
  58. '%' ||
  59. coalesce(in_state, '')
  60. || '%'
  61. AND mail_code ILIKE
  62. '%' ||
  63. coalesce(in_mail_code,
  64. '')
  65. || '%'
  66. AND country_id IN
  67. (SELECT id FROM country
  68. WHERE name LIKE '%' ||
  69. in_country ||'%'
  70. OR short_name
  71. ilike
  72. in_country)))))
  73. AND (ec.business_id =
  74. coalesce(in_business_id, ec.business_id)
  75. OR (ec.business_id IS NULL
  76. AND in_business_id IS NULL))
  77. AND (ec.startdate <= coalesce(in_date_to,
  78. ec.startdate)
  79. OR (ec.startdate IS NULL))
  80. AND (ec.enddate >= coalesce(in_date_from, ec.enddate)
  81. OR (ec.enddate IS NULL))
  82. LOOP
  83. RETURN NEXT out_row;
  84. END LOOP;
  85. END;
  86. $$ language plpgsql;
  87. CREATE OR REPLACE FUNCTION entity__save_notes(in_entity_id int, in_note text)
  88. RETURNS INT AS
  89. $$
  90. DECLARE out_id int;
  91. BEGIN
  92. -- TODO, change this to create vector too
  93. INSERT INTO entity_note (ref_key, note_class, entity_id, note, vector)
  94. VALUES (in_entity_id, 1, in_entity_id, in_note, '');
  95. SELECT currval('note_id_seq') INTO out_id;
  96. RETURN out_id;
  97. END;
  98. $$ LANGUAGE PLPGSQL;
  99. CREATE OR REPLACE FUNCTION eca__save_notes(in_credit_id int, in_note text)
  100. RETURNS INT AS
  101. $$
  102. DECLARE out_id int;
  103. BEGIN
  104. -- TODO, change this to create vector too
  105. INSERT INTO eca_note (ref_key, note_class, note, vector)
  106. VALUES (in_credit_id, 3, in_note, '');
  107. SELECT currval('note_id_seq') INTO out_id;
  108. RETURN out_id;
  109. END;
  110. $$ LANGUAGE PLPGSQL;
  111. CREATE OR REPLACE FUNCTION entity_credit_get_id_by_meta_number
  112. (in_meta_number text, in_account_class int)
  113. returns int AS
  114. $$
  115. DECLARE out_credit_id int;
  116. BEGIN
  117. SELECT id INTO out_credit_id
  118. FROM entity_credit_account
  119. WHERE meta_number = in_meta_number
  120. AND entity_class = in_account_class;
  121. RETURN out_credit_id;
  122. END;
  123. $$ LANGUAGE plpgsql;
  124. CREATE OR REPLACE FUNCTION entity_list_contact_class()
  125. RETURNS SETOF contact_class AS
  126. $$
  127. DECLARE out_row RECORD;
  128. BEGIN
  129. FOR out_row IN
  130. SELECT * FROM contact_class ORDER BY id
  131. LOOP
  132. RETURN NEXT out_row;
  133. END LOOP;
  134. END;
  135. $$ language plpgsql;
  136. CREATE TYPE entity_credit_search_return AS (
  137. legal_name text,
  138. id int,
  139. entity_id int,
  140. entity_class int,
  141. discount numeric,
  142. taxincluded bool,
  143. creditlimit numeric,
  144. terms int2,
  145. meta_number text,
  146. business_id int,
  147. language_code text,
  148. pricegroup_id int,
  149. curr char(3),
  150. startdate date,
  151. enddate date,
  152. ar_ap_account_id int,
  153. cash_account_id int,
  154. tax_id text,
  155. threshold numeric
  156. );
  157. CREATE TYPE entity_credit_retrieve AS (
  158. id int,
  159. entity_id int,
  160. entity_class int,
  161. discount numeric,
  162. taxincluded bool,
  163. creditlimit numeric,
  164. terms int2,
  165. meta_number text,
  166. description text,
  167. business_id int,
  168. language_code text,
  169. pricegroup_id int,
  170. curr text,
  171. startdate date,
  172. enddate date,
  173. ar_ap_account_id int,
  174. cash_account_id int,
  175. threshold numeric,
  176. control_code text,
  177. credit_id int
  178. );
  179. COMMENT ON TYPE entity_credit_search_return IS
  180. $$ This may change in 1.4 and should not be relied upon too much $$;
  181. CREATE OR REPLACE FUNCTION entity_credit_get_id
  182. (in_entity_id int, in_entity_class int, in_meta_number text)
  183. RETURNS int AS $$
  184. DECLARE out_var int;
  185. BEGIN
  186. SELECT id INTO out_var FROM entity_credit_account
  187. WHERE entity_id = in_entity_id
  188. AND in_entity_class = entity_class
  189. AND in_meta_number = meta_number;
  190. RETURN out_var;
  191. END;
  192. $$ language plpgsql;
  193. CREATE OR REPLACE FUNCTION entity__list_credit
  194. (in_entity_id int, in_entity_class int)
  195. RETURNS SETOF entity_credit_retrieve AS
  196. $$
  197. DECLARE out_row entity_credit_retrieve;
  198. BEGIN
  199. FOR out_row IN
  200. SELECT c.id, e.id, ec.entity_class, ec.discount,
  201. ec.taxincluded, ec.creditlimit, ec.terms,
  202. ec.meta_number, ec.description, ec.business_id,
  203. ec.language_code,
  204. ec.pricegroup_id, ec.curr, ec.startdate,
  205. ec.enddate, ec.ar_ap_account_id, ec.cash_account_id,
  206. ec.threshold, e.control_code, ec.id
  207. FROM company c
  208. JOIN entity e ON (c.entity_id = e.id)
  209. JOIN entity_credit_account ec ON (c.entity_id = ec.entity_id)
  210. WHERE e.id = in_entity_id
  211. AND ec.entity_class =
  212. CASE WHEN in_entity_class = 3 THEN 2
  213. WHEN in_entity_class IS NULL
  214. THEN ec.entity_class
  215. ELSE in_entity_class END
  216. LOOP
  217. RETURN NEXT out_row;
  218. END LOOP;
  219. END;
  220. $$ LANGUAGE PLPGSQL;
  221. CREATE OR REPLACE FUNCTION company_retrieve (in_entity_id int) RETURNS company AS
  222. $$
  223. DECLARE t_company company;
  224. BEGIN
  225. SELECT * INTO t_company FROM company WHERE entity_id = in_entity_id;
  226. RETURN t_company;
  227. END;
  228. $$ language plpgsql;
  229. CREATE TYPE company_billing_info AS (
  230. legal_name text,
  231. meta_number text,
  232. tax_id text,
  233. street1 text,
  234. street2 text,
  235. street3 text,
  236. city text,
  237. state text,
  238. mail_code text,
  239. country text
  240. );
  241. CREATE OR REPLACE FUNCTION company_get_billing_info (in_id int)
  242. returns company_billing_info as
  243. $$
  244. DECLARE out_var company_billing_info;
  245. t_id INT;
  246. BEGIN
  247. select c.legal_name, eca.meta_number, c.tax_id, a.line_one, a.line_two, a.line_three,
  248. a.city, a.state, a.mail_code, cc.name
  249. into out_var
  250. FROM company c
  251. JOIN entity_credit_account eca ON (eca.entity_id = c.entity_id)
  252. JOIN eca_to_location cl ON (eca.id = cl.credit_id)
  253. JOIN location a ON (a.id = cl.location_id)
  254. JOIN country cc ON (cc.id = a.country_id)
  255. WHERE eca.id = in_id AND location_class = 1;
  256. RETURN out_var;
  257. END;
  258. $$ language plpgsql;
  259. CREATE OR REPLACE FUNCTION company_save (
  260. in_id int, in_control_code text, in_entity_class int,
  261. in_name text, in_tax_id TEXT,
  262. in_entity_id int, in_sic_code text
  263. ) RETURNS INT AS $$
  264. DECLARE t_entity_id INT;
  265. t_company_id INT;
  266. t_control_code TEXT;
  267. BEGIN
  268. t_company_id := in_id;
  269. IF in_control_code IS NULL THEN
  270. t_control_code := setting_increment('company_control');
  271. ELSE
  272. t_control_code := in_control_code;
  273. END IF;
  274. IF in_entity_id IS NULL THEN
  275. IF in_id IS NULL THEN
  276. RAISE NOTICE 'in_id is null';
  277. SELECT id INTO t_company_id FROM company
  278. WHERE entity_id = (SELECT id FROM entity WHERE
  279. control_code = t_control_code);
  280. END IF;
  281. IF t_company_id IS NOT NULL THEN
  282. SELECT entity_id INTO t_entity_id FROM company
  283. WHERE id = t_company_id;
  284. END IF;
  285. ELSE
  286. t_entity_id := in_entity_id;
  287. END IF;
  288. IF t_entity_id IS NULL THEN
  289. INSERT INTO entity (name, entity_class, control_code)
  290. VALUES (in_name, in_entity_class, t_control_code);
  291. t_entity_id := currval('entity_id_seq');
  292. END IF;
  293. UPDATE company
  294. SET legal_name = in_name,
  295. tax_id = in_tax_id,
  296. sic_code = in_sic_code
  297. WHERE id = t_company_id;
  298. IF NOT FOUND THEN
  299. INSERT INTO company(entity_id, legal_name, tax_id, sic_code)
  300. VALUES (t_entity_id, in_name, in_tax_id, in_sic_code);
  301. END IF;
  302. RETURN t_entity_id;
  303. END;
  304. $$ LANGUAGE PLPGSQL;
  305. CREATE OR REPLACE FUNCTION entity_credit_save (
  306. in_credit_id int, in_entity_class int,
  307. in_entity_id int, in_description text,
  308. in_discount numeric, in_taxincluded bool, in_creditlimit numeric,
  309. in_discount_terms int,
  310. in_terms int, in_meta_number varchar(32), in_business_id int,
  311. in_language varchar(6), in_pricegroup_id int,
  312. in_curr char, in_startdate date, in_enddate date,
  313. in_threshold NUMERIC,
  314. in_ar_ap_account_id int,
  315. in_cash_account_id int
  316. ) returns INT as $$
  317. DECLARE
  318. t_entity_class int;
  319. l_id int;
  320. t_meta_number text;
  321. t_mn_default_key text;
  322. BEGIN
  323. -- TODO: Move to mapping table.
  324. IF in_entity_class = 1 THEN
  325. t_mn_default_key := 'vendornumber';
  326. ELSIF in_entity_class = 2 THEN
  327. t_mn_default_key := 'customernumber';
  328. END IF;
  329. IF in_meta_number IS NULL THEN
  330. t_meta_number := setting_increment(t_mn_default_key);
  331. ELSE
  332. t_meta_number := in_meta_number;
  333. END IF;
  334. update entity_credit_account SET
  335. discount = in_discount,
  336. taxincluded = in_taxincluded,
  337. creditlimit = in_creditlimit,
  338. description = in_description,
  339. terms = in_terms,
  340. ar_ap_account_id = in_ar_ap_account_id,
  341. cash_account_id = in_cash_account_id,
  342. meta_number = t_meta_number,
  343. business_id = in_business_id,
  344. language_code = in_language,
  345. pricegroup_id = in_pricegroup_id,
  346. curr = in_curr,
  347. startdate = in_startdate,
  348. enddate = in_enddate,
  349. threshold = in_threshold,
  350. discount_terms = in_discount_terms
  351. where id = in_credit_id;
  352. IF FOUND THEN
  353. RETURN in_credit_id;
  354. ELSE
  355. INSERT INTO entity_credit_account (
  356. entity_id,
  357. entity_class,
  358. discount,
  359. description,
  360. taxincluded,
  361. creditlimit,
  362. terms,
  363. meta_number,
  364. business_id,
  365. language_code,
  366. pricegroup_id,
  367. curr,
  368. startdate,
  369. enddate,
  370. discount_terms,
  371. threshold,
  372. ar_ap_account_id,
  373. cash_account_id
  374. )
  375. VALUES (
  376. in_entity_id,
  377. in_entity_class,
  378. in_discount,
  379. in_description,
  380. in_taxincluded,
  381. in_creditlimit,
  382. in_terms,
  383. t_meta_number,
  384. in_business_id,
  385. in_language,
  386. in_pricegroup_id,
  387. in_curr,
  388. in_startdate,
  389. in_enddate,
  390. in_discount_terms,
  391. in_threshold,
  392. in_ar_ap_account_id,
  393. in_cash_account_id
  394. );
  395. RETURN currval('entity_credit_account_id_seq');
  396. END IF;
  397. END;
  398. $$ language 'plpgsql';
  399. CREATE OR REPLACE FUNCTION company__list_locations(in_entity_id int)
  400. RETURNS SETOF location_result AS
  401. $$
  402. DECLARE out_row RECORD;
  403. BEGIN
  404. FOR out_row IN
  405. SELECT l.id, l.line_one, l.line_two, l.line_three, l.city,
  406. l.state, l.mail_code, c.name, lc.class
  407. FROM location l
  408. JOIN company_to_location ctl ON (ctl.location_id = l.id)
  409. JOIN location_class lc ON (ctl.location_class = lc.id)
  410. JOIN country c ON (c.id = l.country_id)
  411. WHERE ctl.company_id = (select id from company where entity_id = in_entity_id)
  412. ORDER BY lc.id, l.id, c.name
  413. LOOP
  414. RETURN NEXT out_row;
  415. END LOOP;
  416. END;
  417. $$ LANGUAGE PLPGSQL;
  418. CREATE TYPE contact_list AS (
  419. class text,
  420. class_id int,
  421. description text,
  422. contact text
  423. );
  424. CREATE OR REPLACE FUNCTION company__list_contacts(in_entity_id int)
  425. RETURNS SETOF contact_list AS $$
  426. DECLARE out_row contact_list;
  427. BEGIN
  428. FOR out_row IN
  429. SELECT cl.class, cl.id, c.description, c.contact
  430. FROM company_to_contact c
  431. JOIN contact_class cl ON (c.contact_class_id = cl.id)
  432. WHERE company_id =
  433. (select id FROM company
  434. WHERE entity_id = in_entity_id)
  435. LOOP
  436. return next out_row;
  437. END LOOP;
  438. END;
  439. $$ language plpgsql;
  440. CREATE OR REPLACE FUNCTION company__list_bank_account(in_entity_id int)
  441. RETURNS SETOF entity_bank_account AS
  442. $$
  443. DECLARE out_row entity_bank_account%ROWTYPE;
  444. BEGIN
  445. FOR out_row IN
  446. SELECT * from entity_bank_account where entity_id = in_entity_id
  447. LOOP
  448. RETURN NEXT out_row;
  449. END LOOP;
  450. END;
  451. $$ LANGUAGE PLPGSQL;
  452. CREATE OR REPLACE FUNCTION entity__save_bank_account
  453. (in_entity_id int, in_credit_id int, in_bic text, in_iban text)
  454. RETURNS int AS
  455. $$
  456. DECLARE out_id int;
  457. BEGIN
  458. INSERT INTO entity_bank_account(entity_id, bic, iban)
  459. VALUES(in_entity_id, in_bic, in_iban);
  460. SELECT CURRVAL('entity_bank_account_id_seq') INTO out_id ;
  461. IF in_credit_id IS NOT NULL THEN
  462. UPDATE entity_credit_account SET bank_account = out_id
  463. WHERE id = in_credit_id;
  464. END IF;
  465. RETURN out_id;
  466. END;
  467. $$ LANGUAGE PLPGSQL;
  468. CREATE OR REPLACE FUNCTION entity__save_bank_account
  469. (in_entity_id int, in_bic text, in_iban text)
  470. RETURNS int AS
  471. $$
  472. DECLARE out_id int;
  473. BEGIN
  474. INSERT INTO entity_bank_account(entity_id, bic, iban)
  475. VALUES(in_entity_id, in_bic, in_iban);
  476. SELECT CURRVAL('entity_bank_account_id_seq') INTO out_id ;
  477. RETURN out_id;
  478. END;
  479. $$ LANGUAGE PLPGSQL;
  480. CREATE OR REPLACE FUNCTION company__save_contact
  481. (in_entity_id int, in_contact_class int, in_description text, in_contact text)
  482. RETURNS INT AS
  483. $$
  484. DECLARE out_id int;
  485. BEGIN
  486. INSERT INTO company_to_contact(company_id, contact_class_id,
  487. description, contact)
  488. SELECT id, in_contact_class, in_description, in_contact FROM company
  489. WHERE entity_id = in_entity_id;
  490. RETURN 1;
  491. END;
  492. $$ LANGUAGE PLPGSQL;
  493. CREATE TYPE entity_note_list AS (
  494. id int,
  495. note_class int,
  496. note text
  497. );
  498. CREATE OR REPLACE FUNCTION company__list_notes(in_entity_id int)
  499. RETURNS SETOF entity_note AS
  500. $$
  501. DECLARE out_row record;
  502. BEGIN
  503. FOR out_row IN
  504. SELECT *
  505. FROM entity_note
  506. WHERE ref_key = in_entity_id
  507. ORDER BY created
  508. LOOP
  509. RETURN NEXT out_row;
  510. END LOOP;
  511. END;
  512. $$ LANGUAGE PLPGSQL;
  513. CREATE OR REPLACE FUNCTION eca__list_notes(in_credit_id int)
  514. RETURNS SETOF note AS
  515. $$
  516. DECLARE out_row record;
  517. t_entity_id int;
  518. BEGIN
  519. SELECT entity_id INTO t_entity_id
  520. FROM entity_credit_account
  521. WHERE id = in_credit_id;
  522. FOR out_row IN
  523. SELECT *
  524. FROM note
  525. WHERE (note_class = 3 and ref_key = in_credit_id) or
  526. (note_class = 1 and ref_key = t_entity_id)
  527. ORDER BY created
  528. LOOP
  529. RETURN NEXT out_row;
  530. END LOOP;
  531. END;
  532. $$ LANGUAGE PLPGSQL SECURITY DEFINER;
  533. REVOKE EXECUTE ON FUNCTION eca__list_notes(INT) FROM public;
  534. CREATE OR REPLACE FUNCTION company__next_id() returns bigint as $$
  535. select nextval('company_id_seq');
  536. $$ language 'sql';
  537. CREATE OR REPLACE FUNCTION company__location_save (
  538. in_entity_id int, in_location_id int,
  539. in_location_class int, in_line_one text, in_line_two text,
  540. in_city TEXT, in_state TEXT, in_mail_code text, in_country_code int,
  541. in_created date
  542. ) returns int AS $$
  543. BEGIN
  544. return _entity_location_save(
  545. in_entity_id, in_location_id,
  546. in_location_class, in_line_one, in_line_two,
  547. '', in_city , in_state, in_mail_code, in_country_code);
  548. END;
  549. $$ language 'plpgsql';
  550. create or replace function _entity_location_save(
  551. in_entity_id int, in_location_id int,
  552. in_location_class int, in_line_one text, in_line_two text,
  553. in_line_three text, in_city TEXT, in_state TEXT, in_mail_code text,
  554. in_country_code int
  555. ) returns int AS $$
  556. DECLARE
  557. l_row location;
  558. l_id INT;
  559. t_company_id int;
  560. BEGIN
  561. SELECT id INTO t_company_id
  562. FROM company WHERE entity_id = in_entity_id;
  563. DELETE FROM company_to_location
  564. WHERE company_id = t_company_id
  565. AND location_class = in_location_class
  566. AND location_id = in_location_id;
  567. SELECT location_save(in_line_one, in_line_two, in_line_three, in_city,
  568. in_state, in_mail_code, in_country_code)
  569. INTO l_id;
  570. INSERT INTO company_to_location
  571. (company_id, location_class, location_id)
  572. VALUES (t_company_id, in_location_class, l_id);
  573. RETURN l_id;
  574. END;
  575. $$ language 'plpgsql';
  576. create or replace function eca__location_save(
  577. in_credit_id int, in_location_id int,
  578. in_location_class int, in_line_one text, in_line_two text,
  579. in_line_three text, in_city TEXT, in_state TEXT, in_mail_code text,
  580. in_country_code int
  581. ) returns int AS $$
  582. DECLARE
  583. l_row location;
  584. l_id INT;
  585. BEGIN
  586. DELETE FROM eca_to_location
  587. WHERE credit_id = in_credit_id
  588. AND location_class = in_location_class
  589. AND location_id = in_location_id;
  590. SELECT location_save(in_line_one, in_line_two, in_line_three, in_city,
  591. in_state, in_mail_code, in_country_code)
  592. INTO l_id;
  593. INSERT INTO eca_to_location
  594. (credit_id, location_class, location_id)
  595. VALUES (in_credit_id, in_location_class, l_id);
  596. RETURN l_id;
  597. END;
  598. $$ language 'plpgsql';
  599. CREATE OR REPLACE FUNCTION company_get_billing_info (in_id int)
  600. returns company_billing_info as
  601. $$
  602. DECLARE out_var company_billing_info;
  603. t_id INT;
  604. BEGIN
  605. select c.legal_name, c.tax_id, a.line_one, a.line_two, a.line_three,
  606. a.city, a.state, a.mail_code, cc.name
  607. into out_var
  608. FROM company c
  609. JOIN entity_credit_account eca ON (eca.entity_id = c.entity_id)
  610. JOIN eca_to_location cl ON (eca.id = cl.credit_id)
  611. JOIN location a ON (a.id = cl.location_id)
  612. JOIN country cc ON (cc.id = a.country_id)
  613. WHERE eca.id = in_id AND location_class = 1;
  614. RETURN out_var;
  615. END;
  616. $$ language plpgsql;
  617. CREATE OR REPLACE FUNCTION eca__list_locations(in_credit_id int)
  618. RETURNS SETOF location_result AS
  619. $$
  620. DECLARE out_row RECORD;
  621. BEGIN
  622. FOR out_row IN
  623. SELECT l.id, l.line_one, l.line_two, l.line_three, l.city,
  624. l.state, l.mail_code, c.name, lc.class
  625. FROM location l
  626. JOIN eca_to_location ctl ON (ctl.location_id = l.id)
  627. JOIN location_class lc ON (ctl.location_class = lc.id)
  628. JOIN country c ON (c.id = l.country_id)
  629. WHERE ctl.credit_id = in_credit_id
  630. ORDER BY lc.id, l.id, c.name
  631. LOOP
  632. RETURN NEXT out_row;
  633. END LOOP;
  634. END;
  635. $$ LANGUAGE PLPGSQL;
  636. CREATE OR REPLACE FUNCTION eca__list_contacts(in_credit_id int)
  637. RETURNS SETOF contact_list AS $$
  638. DECLARE out_row contact_list;
  639. BEGIN
  640. FOR out_row IN
  641. SELECT cl.class, cl.id, c.description, c.contact
  642. FROM eca_to_contact c
  643. JOIN contact_class cl ON (c.contact_class_id = cl.id)
  644. WHERE credit_id = in_credit_id
  645. LOOP
  646. return next out_row;
  647. END LOOP;
  648. END;
  649. $$ language plpgsql;
  650. CREATE OR REPLACE FUNCTION eca__save_contact
  651. (in_credit_id int, in_contact_class int, in_description text, in_contact text,
  652. in_old_contact text, in_old_contact_class int)
  653. RETURNS INT AS
  654. $$
  655. DECLARE out_id int;
  656. BEGIN
  657. DELETE FROM eca_to_contact
  658. WHERE credit_id = in_credit_id
  659. AND contact = in_old_contact
  660. AND contact_class_id = in_old_contact_class;
  661. INSERT INTO eca_to_contact(credit_id, contact_class_id,
  662. description, contact)
  663. VALUES (in_credit_id, in_contact_class, in_description, in_contact);
  664. RETURN 1;
  665. END;
  666. $$ LANGUAGE PLPGSQL;
  667. -- COMMIT;