summaryrefslogtreecommitdiff
path: root/sql/modules/Location.sql
blob: 363fa52eb47f20f62f7ccf2c22563e2a6c33fe33 (plain)
  1. -- VERSION 1.3.0
  2. CREATE OR REPLACE FUNCTION location_list_class()
  3. RETURNS SETOF location_class AS
  4. $$
  5. DECLARE out_row RECORD;
  6. BEGIN
  7. FOR out_row IN
  8. SELECT * FROM location_class ORDER BY id
  9. LOOP
  10. RETURN NEXT out_row;
  11. END LOOP;
  12. END;
  13. $$ language plpgsql;
  14. CREATE OR REPLACE FUNCTION location_list_country()
  15. RETURNS SETOF country AS
  16. $$
  17. DECLARE out_row RECORD;
  18. BEGIN
  19. FOR out_row IN
  20. SELECT * FROM country ORDER BY name
  21. LOOP
  22. RETURN NEXT out_row;
  23. END LOOP;
  24. END;
  25. $$ language plpgsql;
  26. CREATE OR REPLACE FUNCTION location_save
  27. (in_location_id int, in_address1 text, in_address2 text, in_address3 text,
  28. in_city text, in_state text, in_zipcode text, in_country int)
  29. returns integer AS
  30. $$
  31. DECLARE
  32. location_id integer;
  33. location_row RECORD;
  34. BEGIN
  35. IF in_location_id IS NULL THEN
  36. SELECT id INTO location_id FROM location
  37. WHERE line_one = in_address1 AND line_two = in_address2
  38. AND line_three = in_address3 AND in_city = city
  39. AND in_state = state AND in_zipcode = mail_code
  40. AND in_country = country_id
  41. LIMIT 1;
  42. IF NOT FOUND THEN
  43. -- Straight insert.
  44. location_id = nextval('location_id_seq');
  45. INSERT INTO location (
  46. id,
  47. line_one,
  48. line_two,
  49. line_three,
  50. city,
  51. state,
  52. mail_code,
  53. country_id)
  54. VALUES (
  55. location_id,
  56. in_address1,
  57. in_address2,
  58. in_address3,
  59. in_city,
  60. in_state,
  61. in_zipcode,
  62. in_country
  63. );
  64. END IF;
  65. return location_id;
  66. ELSE
  67. RAISE NOTICE 'Overwriting location id %', in_location_id;
  68. -- Test it.
  69. SELECT * INTO location_row FROM location WHERE id = in_location_id;
  70. IF NOT FOUND THEN
  71. -- Tricky users are lying to us.
  72. RAISE EXCEPTION 'location_save called with nonexistant location ID %', in_location_id;
  73. ELSE
  74. -- Okay, we're good.
  75. UPDATE location SET
  76. line_one = in_address1,
  77. line_two = in_address2,
  78. line_three = in_address3,
  79. city = in_city,
  80. state = in_state,
  81. mail_code = in_zipcode,
  82. country_id = in_country
  83. WHERE id = in_location_id;
  84. return in_location_id;
  85. END IF;
  86. END IF;
  87. END;
  88. $$ LANGUAGE PLPGSQL;
  89. COMMENT ON function location_save
  90. (in_location_id int, in_address1 text, in_address2 text, in_address3 text,
  91. in_city text, in_state text, in_zipcode text, in_country int) IS
  92. $$ Note that this does NOT override the data in the database unless in_location_id is specified.
  93. Instead we search for locations matching the desired specifications and if none
  94. are found, we insert one. Either way, the return value of the location can be
  95. used for mapping to other things. This is necessary because locations are
  96. only loosly coupled with entities, etc.$$;
  97. CREATE OR REPLACE FUNCTION location_get (in_id integer) returns location AS
  98. $$
  99. DECLARE
  100. out_location location%ROWTYPE;
  101. BEGIN
  102. SELECT * INTO out_location FROM location WHERE id = in_id;
  103. RETURN out_location;
  104. END;
  105. $$ language plpgsql;
  106. CREATE OR REPLACE FUNCTION location_search
  107. (in_companyname varchar, in_address1 varchar, in_address2 varchar,
  108. in_city varchar, in_state varchar, in_zipcode varchar,
  109. in_country varchar)
  110. RETURNS SETOF location
  111. AS
  112. $$
  113. DECLARE
  114. out_location location%ROWTYPE;
  115. BEGIN
  116. FOR out_location IN
  117. SELECT * FROM location
  118. WHERE companyname ilike '%' || in_companyname || '%'
  119. AND address1 ilike '%' || in_address1 || '%'
  120. AND address2 ilike '%' || in_address2 || '%'
  121. AND in_city ilike '%' || in_city || '%'
  122. AND in_state ilike '%' || in_state || '%'
  123. AND in_zipcode ilike '%' || in_zipcode || '%'
  124. AND in_country ilike '%' || in_country || '%'
  125. LOOP
  126. RETURN NEXT out_location;
  127. END LOOP;
  128. END;
  129. $$ LANGUAGE PLPGSQL;
  130. CREATE OR REPLACE FUNCTION location_list_all () RETURNS SETOF location AS
  131. $$
  132. DECLARE
  133. out_location location%ROWTYPE;
  134. BEGIN
  135. FOR out_location IN
  136. SELECT * FROM location
  137. ORDER BY company_name, city, state, country
  138. LOOP
  139. RETURN NEXT out_location;
  140. END LOOP;
  141. END;
  142. $$ LANGUAGE plpgsql;
  143. CREATE OR REPLACE FUNCTION location_delete (in_id integer) RETURNS VOID AS
  144. $$
  145. BEGIN
  146. DELETE FROM location WHERE id = in_id;
  147. END;
  148. $$ language plpgsql;
  149. CREATE TYPE location_result AS (
  150. id int,
  151. line_one text,
  152. line_two text,
  153. line_three text,
  154. city text,
  155. state text,
  156. mail_code text,
  157. country text,
  158. class text
  159. );
  160. CREATE OR REPLACE FUNCTION location__get(in_id int) returns location_result AS $$
  161. declare
  162. l_row location_result;
  163. begin
  164. FOR l_row IN
  165. SELECT
  166. l.id,
  167. l.line_one,
  168. l.line_two,
  169. l.line_three,
  170. l.city,
  171. l.state,
  172. l.mail_code,
  173. c.name as country,
  174. NULL
  175. FROM location l
  176. JOIN country c on l.country_id = c.id
  177. WHERE l.id = in_id
  178. LOOP
  179. return l_row;
  180. END LOOP;
  181. END;
  182. $$ language plpgsql ;