summaryrefslogtreecommitdiff
path: root/sql/modules/Vendor.sql
blob: 2026fffa32b086c488c61d8b60274d49f8b4abd7 (plain)
  1. BEGIN;
  2. CREATE TYPE vendor_search_return AS (
  3. legal_name text,
  4. id int,
  5. entity_id int,
  6. entity_class int,
  7. discount numeric,
  8. taxincluded bool,
  9. creditlimit numeric,
  10. terms int2,
  11. vendornumber int,
  12. cc text,
  13. bcc text,
  14. business_id int,
  15. language_code text,
  16. pricegroup_id int,
  17. curr char,
  18. startdate date,
  19. enddate date,
  20. bic varchar,
  21. iban varchar,
  22. note text
  23. );
  24. CREATE OR REPLACE FUNCTION vendor_save (
  25. in_id int,
  26. in_discount numeric, in_taxincluded bool, in_creditlimit numeric,
  27. in_terms int, in_vendornumber varchar(32), in_cc text, in_bcc text,
  28. in_business_id int, in_language varchar(6), in_pricegroup_id int,
  29. in_curr char, in_startdate date, in_enddate date,
  30. in_bic text, in_iban text,
  31. in_notes text,
  32. in_name text, in_tax_id TEXT
  33. ) returns INT as $$
  34. -- does not require entity_class, as entity_class is a known given to be 1
  35. DECLARE
  36. t_entity_class int;
  37. new_entity_id int;
  38. v_row company;
  39. l_id int;
  40. BEGIN
  41. t_entity_class := 1;
  42. SELECT INTO v_row * FROM company WHERE id = in_id;
  43. IF NOT FOUND THEN
  44. -- do some inserts
  45. new_entity_id := nextval('entity_id_seq');
  46. insert into entity (id, name, entity_class)
  47. VALUES (new_entity_id, in_name, t_entity_class);
  48. INSERT INTO company ( id, entity_id, legal_name, tax_id )
  49. VALUES ( in_id, new_entity_id, in_name, in_tax_id );
  50. INSERT INTO entity_credit_account (
  51. entity_id,
  52. entity_class,
  53. discount,
  54. taxincluded,
  55. creditlimit,
  56. terms,
  57. cc,
  58. bcc,
  59. business_id,
  60. language_code,
  61. pricegroup_id,
  62. curr,
  63. startdate,
  64. enddate,
  65. meta_number
  66. )
  67. VALUES (
  68. new_entity_id,
  69. t_entity_class,
  70. in_discount,
  71. in_taxincluded,
  72. in_creditlimit,
  73. in_terms,
  74. in_cc,
  75. in_bcc,
  76. in_business_id,
  77. in_language,
  78. in_pricegroup_id,
  79. in_curr,
  80. in_startdate,
  81. in_enddate,
  82. in_vendornumber
  83. );
  84. INSERT INTO entity_bank_account (
  85. entity_id,
  86. bic,
  87. iban
  88. )
  89. VALUES (
  90. new_entity_id,
  91. in_bic,
  92. in_iban
  93. );
  94. -- entity note class
  95. insert into entity_note (note_class, note, ref_key, vector) VALUES (
  96. 1, in_notes, new_entity_id, '');
  97. ELSIF FOUND THEN
  98. update company set tax_id = in_tax_id where id = in_id;
  99. update entity_credit_account SET
  100. discount = in_discount,
  101. taxincluded = in_taxincluded,
  102. creditlimit = in_creditlimit,
  103. terms = in_terms,
  104. cc = in_cc,
  105. bcc = in_bcc,
  106. business_id = in_business_id,
  107. language_code = in_language,
  108. pricegroup_id = in_pricegroup_id,
  109. curr = in_curr,
  110. startdate = in_startdate,
  111. enddate = in_enddate,
  112. meta_number = in_vendornumber
  113. where entity_id = v_row.entity_id;
  114. UPDATE entity_bank_account SET
  115. bic = in_bic,
  116. iban = in_iban
  117. WHERE entity_id = v_row.entity_id;
  118. UPDATE entity_note SET
  119. note = in_note
  120. WHERE ref_key = v_row.entity_id;
  121. END IF;
  122. return in_id;
  123. END;
  124. $$ language 'plpgsql';
  125. CREATE OR REPLACE FUNCTION vendor_location_save (
  126. in_company_id int,
  127. in_location_class int, in_line_one text, in_line_two text,
  128. in_city_province TEXT, in_mail_code text, in_country_code int,
  129. in_created date
  130. ) returns int AS $$
  131. BEGIN
  132. return _entity_location_save(
  133. in_company_id,
  134. in_location_class, in_line_one, in_line_two,
  135. in_city_province , in_mail_code, in_country_code,
  136. in_created);
  137. END;
  138. $$ language 'plpgsql';
  139. create or replace function _entity_location_save(
  140. in_company_id int,
  141. in_location_class int, in_line_one text, in_line_two text,
  142. in_city_province TEXT, in_mail_code text, in_country_code int,
  143. in_created date
  144. ) returns int AS $$
  145. DECLARE
  146. l_row location;
  147. l_id INT;
  148. BEGIN
  149. SELECT l.* INTO l_row FROM location l
  150. JOIN company_to_location ctl ON ctl.location_id = l.id
  151. JOIN company c on ctl.company_id = c.id
  152. where c.id = in_company_id;
  153. IF NOT FOUND THEN
  154. l_id := nextval('location_id_seq');
  155. INSERT INTO location (id, location_class, line_one, line_two,
  156. city_province, country_id, mail_code, created)
  157. VALUES (
  158. l_id,
  159. in_location_class,
  160. in_line_one,
  161. in_line_two,
  162. in_city_province,
  163. in_country_code,
  164. in_mail_code,
  165. in_created
  166. );
  167. INSERT INTO company_to_location (location_id, company_id)
  168. VALUES (l_id, in_company_id);
  169. ELSIF FOUND THEN
  170. l_id := l.id;
  171. update location SET
  172. location_class = in_location_class,
  173. line_one = in_line_one,
  174. line_two = in_line_two,
  175. city_province = in_city_province,
  176. country_id = in_country_code,
  177. mail_code = in_mail_code
  178. WHERE id = l_id;
  179. END IF;
  180. return l_id;
  181. END;
  182. $$ language 'plpgsql';
  183. CREATE INDEX company_name_gist__idx ON company USING gist(legal_name gist_trgm_ops);
  184. CREATE INDEX location_address_one_gist__idx ON location USING gist(line_one gist_trgm_ops);
  185. CREATE INDEX location_address_two_gist__idx ON location USING gist(line_two gist_trgm_ops);
  186. CREATE INDEX location_address_three_gist__idx ON location USING gist(line_three gist_trgm_ops);
  187. CREATE INDEX location_city_prov_gist_idx ON location USING gist(city_province gist_trgm_ops);
  188. CREATE INDEX entity_name_gist_idx ON entity USING gist(name gist_trgm_ops);
  189. CREATE OR REPLACE FUNCTION vendor_search(in_name TEXT, in_address TEXT,
  190. in_city_prov TEXT)
  191. RETURNS SETOF vendor_search_return AS $$
  192. -- searches vendor name, account number, street address, city, state,
  193. -- other location-based stuff
  194. declare
  195. v_row vendor_search_return;
  196. query text;
  197. begin
  198. for v_row in select c.legal_name, v.* from vendor v
  199. join company c on c.entity_id = v.entity_id
  200. join entity e on e.id = v.entity_id
  201. join company_to_location ctl on c.id = ctl.company_id
  202. join location l on l.id = ctl.location_id
  203. where (
  204. l.line_one % in_address
  205. OR l.line_two % in_address
  206. OR l.line_three % in_address
  207. )
  208. OR l.city_province % in_city_prov
  209. OR (
  210. c.legal_name % in_name
  211. OR e.name % in_name
  212. )
  213. LOOP
  214. RETURN NEXT v_row;
  215. END LOOP;
  216. RETURN;
  217. end;
  218. $$ language 'plpgsql';
  219. CREATE OR REPLACE FUNCTION vendor_retrieve(INT) returns setof vendor as $$
  220. select v.* from vendor v
  221. join company c on c.entity_id = v.entity_id
  222. where v.id = $1;
  223. $$ language 'sql';
  224. COMMIT;
  225. CREATE OR REPLACE FUNCTION vendor_next_vendor_id() returns int as $$
  226. select nextval('company_id_seq');
  227. $$ language 'sql';