summaryrefslogtreecommitdiff
path: root/sql/modules/Employee.sql
blob: 0048b873d54d766a2510e500397d984972c37c52 (plain)
  1. -- VERSION 1.3.0
  2. BEGIN;
  3. CREATE OR REPLACE FUNCTION employee__save(
  4. in_person int, in_entity int, in_startdate date, in_enddate date,
  5. in_role text, in_sales boolean, in_dob date,
  6. in_managerid integer, in_employeenumber text
  7. )
  8. returns int AS $$
  9. DECLARE
  10. e_ent entity_employee;
  11. e entity;
  12. p person;
  13. BEGIN
  14. select * into e from entity where id = in_entity and entity_class = 3;
  15. IF NOT FOUND THEN
  16. RAISE EXCEPTION 'No entity found for ID %', in_entity;
  17. END IF;
  18. select * into p from person where id = in_person;
  19. IF NOT FOUND THEN
  20. RAISE EXCEPTION 'No person found for ID %', in_perso;
  21. END IF;
  22. -- Okay, we're good. Check to see if we update or insert.
  23. select * into e_ent from entity_employee where person_id = in_person
  24. and entity_id = in_entity;
  25. IF NOT FOUND THEN
  26. -- insert.
  27. INSERT INTO entity_employee (person_id, entity_id, startdate,
  28. enddate, role, sales, manager_id, employeenumber, dob)
  29. VALUES (in_person, in_entity, in_startdate, in_enddate, in_role,
  30. in_sales, in_managerid, in_employeenumber, in_dob);
  31. return in_entity;
  32. ELSE
  33. -- update
  34. UPDATE entity_employee
  35. SET
  36. startdate = in_startdate,
  37. enddate = in_enddate,
  38. role = in_role,
  39. sales = in_sales,
  40. manager_id = in_managerid,
  41. employeenumber = in_employeenumber,
  42. dob = in_dob
  43. WHERE
  44. entity_id = in_entity
  45. AND
  46. person_id = in_person;
  47. return in_entity;
  48. END IF;
  49. END;
  50. $$ language 'plpgsql';
  51. create view employees as
  52. select
  53. s.salutation,
  54. p.first_name,
  55. p.last_name,
  56. ee.*
  57. FROM person p
  58. JOIN entity_employee ee USING (entity_id)
  59. JOIN salutation s ON (p.salutation_id = s.id);
  60. CREATE OR REPLACE FUNCTION employee__get
  61. (in_id integer)
  62. returns employees as
  63. $$
  64. DECLARE
  65. emp employees%ROWTYPE;
  66. BEGIN
  67. SELECT
  68. ee.*
  69. INTO emp
  70. FROM employees ee
  71. WHERE ee.entity_id = in_id;
  72. RETURN emp;
  73. END;
  74. $$ language plpgsql;
  75. CREATE OR REPLACE FUNCTION employee__list_managers
  76. (in_id integer)
  77. RETURNS SETOF employees as
  78. $$
  79. DECLARE
  80. emp employees%ROWTYPE;
  81. BEGIN
  82. FOR emp IN
  83. SELECT
  84. e.salutation,
  85. e.first_name,
  86. e.last_name,
  87. ee.*
  88. FROM entity_employee ee
  89. JOIN entity e on e.id = ee.entity_id
  90. WHERE ee.sales = 't'::bool AND ee.role='manager'
  91. AND ee.entity_id <> coalesce(in_id, -1)
  92. ORDER BY name
  93. LOOP
  94. RETURN NEXT emp;
  95. END LOOP;
  96. END;
  97. $$ language plpgsql;
  98. CREATE OR REPLACE FUNCTION employee_delete
  99. (in_id integer) returns void as
  100. $$
  101. BEGIN
  102. DELETE FROM employee WHERE entity_id = in_id;
  103. RETURN;
  104. END;
  105. $$ language plpgsql;
  106. -- as long as we need the datatype, might as well get some other use out of it!
  107. --
  108. -- % type is pg_trgm comparison.
  109. CREATE INDEX notes_idx ON entity_note USING gist(note gist_trgm_ops);
  110. CREATE OR REPLACE VIEW employee_search AS
  111. SELECT e.*, em.name AS manager, emn.note, en.name as name
  112. FROM entity_employee e
  113. LEFT JOIN entity en on (e.entity_id = en.id)
  114. LEFT JOIN entity_employee m ON (e.manager_id = m.entity_id)
  115. LEFT JOIN entity em on (em.id = m.entity_id)
  116. LEFT JOIN entity_note emn on (emn.ref_key = em.id);
  117. CREATE OR REPLACE FUNCTION employee_search
  118. (in_startdatefrom date, in_startdateto date, in_name varchar, in_notes text,
  119. in_enddateto date, in_enddatefrom date, in_sales boolean)
  120. RETURNS SETOF employee_search AS
  121. $$
  122. DECLARE
  123. emp employee_search%ROWTYPE;
  124. BEGIN
  125. FOR emp IN
  126. SELECT * FROM employee_search
  127. WHERE coalesce(startdate, 'infinity'::timestamp)
  128. >= coalesce(in_startdateto, '-infinity'::timestamp)
  129. AND coalesce(startdate, '-infinity'::timestamp) <=
  130. coalesce(in_startdatefrom,
  131. 'infinity'::timestamp)
  132. AND coalesce(enddate, '-infinity'::timestamp) <=
  133. coalesce(in_enddateto, 'infinity'::timestamp)
  134. AND coalesce(enddate, 'infinity'::timestamp) >=
  135. coalesce(in_enddatefrom, '-infinity'::timestamp)
  136. AND (name % in_name
  137. OR note % in_notes)
  138. AND (sales = 't' OR coalesce(in_sales, 'f') = 'f')
  139. LOOP
  140. RETURN NEXT emp;
  141. END LOOP;
  142. return;
  143. END;
  144. $$ language plpgsql;
  145. create or replace function employee_set_location
  146. (in_employee int, in_location int)
  147. returns void as $$
  148. INSERT INTO person_to_location (person_id,location_id)
  149. VALUES ($1, $2);
  150. $$ language 'sql';
  151. COMMIT;