summaryrefslogtreecommitdiff
path: root/sql/upgrade/1.2-1.3.sql
blob: 563d8b55ebbdbb4c8df45661e6cedc0ba6ba0c52 (plain)
  1. BEGIN;
  2. ALTER TABLE employee RENAME TO employees;
  3. CREATE TABLE locations (
  4. id SERIAL PRIMARY KEY,
  5. companyname text,
  6. address1 text,
  7. address2 text,
  8. city text,
  9. state text,
  10. country text,
  11. zipcode text
  12. );
  13. CREATE SEQUENCE employees_id_seq;
  14. SELECT setval('employees_id_seq', (select max(id) + 1 FROM employees));
  15. ALTER TABLE employees ADD COLUMN locations_id integer;
  16. ALTER TABLE employees ADD FOREIGN KEY (locations_id) REFERENCES locations(id);
  17. ALTER TABLE employees ALTER COLUMN id DROP DEFAULT;
  18. ALTER TABLE employees ALTER COLUMN id SET DEFAULT nextval('employee_id_seq');
  19. DROP RULE employee_id_track_i ON employees; -- no longer needed
  20. CREATE OR REPLACE FUNCTION location_save
  21. (in_id int, in_companyname text, in_address1 text, in_address2 text,
  22. in_city text, in_state text, in_zipcode text, in_country text)
  23. returns integer AS
  24. $$
  25. DECLARE
  26. location_id integer;
  27. BEGIN
  28. UPDATE locations
  29. SET companyname = in_companyname,
  30. address1 = in_address1,
  31. address2 = in_address2,
  32. city = in_city,
  33. state = in_state,
  34. zipcode = in_zipcode,
  35. country = in_country
  36. WHERE id = in_id;
  37. IF FOUND THEN
  38. return in_id;
  39. END IF;
  40. INSERT INTO location
  41. (companyname, address1, address2, city, state, zipcode, country)
  42. VALUES
  43. (in_companyname, in_address1, in_address2, in_city, in_state,
  44. in_zipcode, in_country);
  45. SELECT lastval('location_id_seq') INTO location_id;
  46. return location_id;
  47. END;
  48. $$ LANGUAGE PLPGSQL;
  49. create or replace function employee_save
  50. (in_id integer, in_location_id integer, in_employeenumber varchar(32),
  51. in_name varchar(64), in_address1 varchar(32), in_address2 varchar(32),
  52. in_city varchar(32), in_state varchar(32), in_zipcode varchar(10),
  53. in_country varchar(32), in_workphone varchar(20),
  54. in_homephone varchar(20), in_startdate date, in_enddate date,
  55. in_notes text, in_role varchar(20), in_sales boolean, in_email text,
  56. in_ssn varchar(20), in_dob date, in_iban varchar(34),
  57. in_bic varchar(11), in_managerid integer) returns int
  58. AS
  59. $$
  60. BEGIN
  61. UPDATE employees
  62. SET location_id = in_location_id,
  63. employeenumber = in_employeenumber,
  64. name = in_name,
  65. address1 = in_address1,
  66. address2 = in_address2,
  67. city = in_city,
  68. state = in_state,
  69. zipcode = in_zipcode,
  70. country = in_country,
  71. workphone = in_workphone,
  72. homephone = in_homephone,
  73. startdate = in_startdate,
  74. enddate = in_enddate,
  75. notes = in_notes,
  76. role = in_role,
  77. sales = in_sales,
  78. email = in_email,
  79. ssn = in_ssn,
  80. dob=in_dob,
  81. iban = in_iban,
  82. bic = in_bic,
  83. manager_id = in_managerid
  84. WHERE id = in_id;
  85. IF FOUND THEN
  86. return in_id;
  87. END IF;
  88. INSERT INTO employees
  89. (location_id, employeenumber, name, address1, address2,
  90. city, state, zipcode, country, workphone, homephone,
  91. startdate, enddate, notes, role, sales, email, ssn,
  92. dob, iban, bic, managerid)
  93. VALUES
  94. (in_location_id, in_employeenumber, in_name, in_address1,
  95. in_address2, in_city, in_state, in_zipcode, in_country,
  96. in_workphone, in_homephone, in_startdate, in_enddate,
  97. in_notes, in_role, in_sales, in_email, in_ssn, in_dob,
  98. in_iban, in_bic, in_managerid);
  99. SELECT currval('employee_id_seq') INTO employee_id;
  100. return employee_id;
  101. END;
  102. $$ LANGUAGE PLPGSQL;
  103. CREATE OR REPLACE FUNCTION employee_get
  104. (in_id integer)
  105. returns employees as
  106. $$
  107. DECLARE
  108. emp employees%ROWTYPE;
  109. BEGIN
  110. SELECT * INTO emp FROM employees WHERE id = in_id;
  111. RETURN emp;
  112. END;
  113. $$ language plpgsql;
  114. CREATE OR REPLACE FUNCTION employee_list_managers
  115. (in_id integer)
  116. RETURNS SETOF employees as
  117. $$
  118. DECLARE
  119. emp employees%ROWTYPE;
  120. BEGIN
  121. FOR emp IN
  122. SELECT * FROM employees
  123. WHERE sales = '1' AND role='manager'
  124. AND id <> coalesce(in_id, -1)
  125. ORDER BY name
  126. LOOP
  127. RETURN NEXT emp;
  128. END LOOP;
  129. END;
  130. $$ language plpgsql;
  131. CREATE OR REPLACE FUNCTION employee_delete
  132. (in_id integer) returns void as
  133. $$
  134. BEGIN
  135. DELETE FROM employees WHERE id = in_id;
  136. RETURN;
  137. END;
  138. $$ language plpgsql;
  139. -- as long as we need the datatype, might as well get some other use out of it!
  140. CREATE OR REPLACE VIEW employee_search AS
  141. SELECT e.*, m.name AS manager
  142. FROM employees e JOIN employees m ON (e.managerid = m.id);
  143. CREATE OR REPLACE FUNCTION employee_search
  144. (in_startdatefrom date, in_startdateto date, in_name varchar, in_notes text,
  145. in_enddateto date, in_enddatefrom date)
  146. RETURNS SETOF employee_search AS
  147. $$
  148. DECLARE
  149. emp employee_search%ROWTYPE;
  150. BEGIN
  151. FOR emp IN
  152. SELECT * FROM employee_search
  153. WHERE coalesce(startdate, 'infinity'::timestamp)
  154. >= coalesce(in_startdateto, '-infinity'::timestamp)
  155. AND coalesce(startdate, '-infinity'::timestamp) <=
  156. coalesce(in_startdatefrom,
  157. 'infinity'::timestamp)
  158. AND coalesce(enddate, '-infinity'::timestamp) <=
  159. coalesce(in_enddateto, 'infinity'::timestamp)
  160. AND coalesce(enddate, 'infinity'::timestamp) >=
  161. coalesce(in_enddatefrom, '-infinity'::timestamp)
  162. AND lower(name) LIKE '%' || lower(in_name) || '%'
  163. AND lower(notes) LIKE '%' || lower(in_notes) || '%'
  164. AND (sales = 't' OR coalesce(in_sales, 'f') = 'f')
  165. LOOP
  166. RETURN NEXT emp;
  167. END LOOP;
  168. END;
  169. $$ language plpgsql;
  170. COMMIT;