Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Updated functions based on new staffing logic #67

Draft
wants to merge 9 commits into
base: master
Choose a base branch
from
53 changes: 37 additions & 16 deletions functions/employee_worked_days_per_week.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,21 +3,42 @@ CREATE OR REPLACE FUNCTION public.employee_worked_days_per_week(in_employee inte
LANGUAGE plpgsql
AS $function$
BEGIN
IF (in_number_of_weeks < 1) then RAISE numeric_value_out_of_range USING MESSAGE = 'number_of_weeks-parameter has to be greater than 0, but was ' || in_number_of_weeks; END IF;
return query(SELECT
current_start_of_week::date as start_of_week,
count(s.date)::integer as days,
array_agg(s.project) as projects
FROM
generate_series(in_start_of_week::date, (in_start_of_week + (7 * in_number_of_weeks - 1))::date, '7 days'::interval) as current_start_of_week
INNER JOIN
staffing s
on s.date between current_start_of_week::date AND (current_start_of_week::date + 6)::date
and s.employee = in_employee
group by
start_of_week
order by
start_of_week
);
IF(in_number_of_weeks < 1) THEN
RAISE numeric_value_out_of_range
USING MESSAGE = 'number_of_weeks-parameter has to be greater than 0, but was ' || in_number_of_weeks;
END IF;
RETURN query (
SELECT
current_start_of_week::date AS start_of_week,
count(s.date)::integer AS days,
array_agg(s.project) AS projects
FROM
generate_series(in_start_of_week::date, (in_start_of_week + (7 * in_number_of_weeks - 1))::date, '7 days'::interval) AS current_start_of_week
INNER JOIN staffing s ON s.date BETWEEN current_start_of_week::date
AND(current_start_of_week::date + 6)::date
AND s.employee = in_employee
WHERE NOT EXISTS (
SELECT
1
FROM (
SELECT
employee_id,
date,
SUM(percentage) AS sum_percentage
FROM
absence
GROUP BY
employee_id,
date) a
WHERE
a.date = s.date
AND a.employee_id = s.employee
AND sum_percentage >= 100
)
GROUP BY
start_of_week
ORDER BY
start_of_week
);
END;
$function$
163 changes: 80 additions & 83 deletions functions/kpi_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -128,11 +128,11 @@ SELECT
sum(tt.business_hours)
FROM
(
SELECT
SELECT
business_hours
FROM
FROM
(
SELECT
SELECT
employees.id AS id,
employees.first_name,
employees.date_of_employment,
Expand All @@ -141,7 +141,7 @@ FROM
employees
) AS e,
business_hours(greatest(in_from_date, e.date_of_employment),least(e.termination_date, in_to_date))
) tt
) tt
);
END
$$ LANGUAGE plpgsql;
Expand All @@ -154,17 +154,18 @@ $$
BEGIN
RETURN QUERY (
SELECT
sum_business_hours - unavailable_hours :: double precision AS sum_available_hours,
SUM(minutes/60.0) :: numeric AS sum_billable_hours
SUM((1 - COALESCE(a.absence_percentage, 0)) * s.staffing_percentage * 7.5) AS sum_available_hours,
SUM(CASE WHEN p.billable = 'billable' THEN (t.minutes / 60.0) ELSE 0 END) AS sum_billable_hours
FROM
sum_business_hours(from_date, to_date),
unavailable_time_entry_hours(from_date, to_date),
time_entry
JOIN projects ON
projects.id = time_entry.project AND
projects.billable = 'billable' AND
time_entry.date <= to_date and time_entry.date >= from_date
GROUP BY (sum_business_hours, unavailable_hours)) LIMIT 1;
employees e
LEFT JOIN staffing s ON e.id = s.employee AND s.date BETWEEN from_date AND to_date
LEFT JOIN absence a ON e.id = a.employee_id AND a.date = s.date
LEFT JOIN time_entry t ON e.id = t.employee AND t.date = s.date
LEFT JOIN projects p ON t.project = p.id
WHERE
e.date_of_employment <= to_date AND (e.termination_date >= from_date OR e.termination_date IS NULL)
GROUP BY e.id
);
END
$$ LANGUAGE plpgsql;

Expand All @@ -182,8 +183,8 @@ SELECT
tt.unavailable
FROM
(
select sum(minutes/60.0) AS unavailable from projects join time_entry on time_entry.project = projects.id where projects.billable='unavailable' and time_entry.date >= in_from_date and time_entry.date <= in_to_date
) tt
select sum(minutes/60.0) AS unavailable from projects join time_entry on time_entry.project = projects.id where projects.billable='unavailable' and time_entry.date >= in_from_date and time_entry.date <= in_to_date
) tt
);
END
$$ LANGUAGE plpgsql;
Expand All @@ -192,37 +193,27 @@ CREATE OR REPLACE FUNCTION month_dates(in_from_date date, in_to_date date, in_in
RETURNS TABLE ( to_date DATE, from_date DATE) AS
$$
BEGIN
RETURN QUERY select date_trunc('DAY', monat - interval '1' day)::DATE, date_trunc('MONTH', monat - in_interval)::DATE from
RETURN QUERY select date_trunc('DAY', monat - interval '1' day)::DATE, date_trunc('MONTH', monat - in_interval)::DATE from
(select * from generate_series(date_trunc('MONTH', in_from_date), date_trunc('MONTH', in_to_date),'1 month') AS monat) AS mt order by 1;
END
$$ LANGUAGE plpgsql;



CREATE OR REPLACE FUNCTION unavailable_staffing_hours(start_date date, end_date date)
RETURNS TABLE (
  unavailable_hours numeric
) AS
RETURNS TABLE (unavailable_hours numeric) AS
$$
BEGIN
RETURN QUERY (

SELECT
  tt.unavailable
FROM
(
SELECT
7.5 * count(*) AS unavailable
SUM(s.staffing_percentage * 7.5) AS unavailable_hours
FROM
staffing
JOIN projects ON
staffing.project = projects.id
WHERE
billable='unavailable' AND
staffing.date <= end_date AND
staffing.date >= start_date
) tt
);
staffing s
JOIN projects p ON s.project = p.id
WHERE
p.billable = 'unavailable' AND
s.date BETWEEN start_date AND end_date
);
END
$$ LANGUAGE plpgsql;

Expand Down Expand Up @@ -261,7 +252,7 @@ begin
return query (
SELECT
sum(minutes)/60::double precision AS project_hours
FROM
FROM
time_entry
WHERE
time_entry.project = project_code AND
Expand Down Expand Up @@ -320,24 +311,30 @@ $function$ LANGUAGE plpgsql;

-- Visibility - forecasted FG (based of 12 next weeks)

CREATE OR REPLACE FUNCTION planned_billable_hours(start_date date, end_date date)
RETURNS TABLE (billable_hours double precision) AS
$$
CREATE OR REPLACE FUNCTION public.planned_billable_hours(start_date date, end_date date)
RETURNS TABLE(billable_hours double precision)
LANGUAGE plpgsql
AS $function$
DECLARE
billable_prc numeric;
absence_prc numeric;
BEGIN
RETURN QUERY (
SELECT
COUNT(*)*7.5::double precision as billable_hours
FROM
staffing as s,
projects as p
WHERE
s.project = p.id AND
p.billable = 'billable' AND
s.date BETWEEN start_date AND end_date
);
SELECT SUM(s.percentage)
INTO billable_prc
FROM staffing s
INNER JOIN projects p ON s.project = p.id
WHERE p.billable = 'billable'
AND s.date BETWEEN start_date AND end_date;

SELECT SUM(a.percentage)
INTO absence_prc
FROM absence a
WHERE a.date BETWEEN start_date AND end_date;

RETURN QUERY
SELECT GREATEST((COALESCE(billable_prc, 0)::INTEGER + COALESCE(absence_prc, 0)::INTEGER) - 100, 0) * 0.075::double precision;
END
$$ LANGUAGE plpgsql;

$function$

CREATE OR REPLACE FUNCTION forcasted_fg_in_period(start_date date, end_date date)
RETURNS TABLE(planned_billable_hours double precision, available_hours double precision, percent double precision)
Expand Down Expand Up @@ -376,12 +373,12 @@ begin
end
$function$;

-- Accumulated reconciliation for whole company
-- Accumulated reconciliation for whole company
create or replace function accumulated_reconciliation(from_date date, to_date date)
returns table (write_off numeric , hours bigint, amount numeric, amount_net numeric, count bigint, subcontractor_hours bigint, subcontractor_expense numeric, other_expense numeric) as
$$
begin
return query (select
return query (select
SUM(summed_write_off.minutes)/60 as write_off,
SUM(invoice_balance.minutes)/60 as hours,
SUM(invoice_balance.amount) as total_amount,
Expand Down Expand Up @@ -526,19 +523,21 @@ $$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION forcasted_available_hours(start_date date, end_date date)
RETURNS TABLE (all_hours double precision, unavail_staffing_hours double precision, unavail_absence_hours double precision, available_hours double precision) AS
RETURNS TABLE (all_hours double precision, unavailable_hours double precision, available_hours double precision) AS
$$
BEGIN
RETURN QUERY (
SELECT
ewd.hours::double precision as all_hours,
usd.hours::double precision as unavail_staffing_hours,
abs.hours::double precision as unavail_absence_hours,
(ewd.hours - usd.hours - abs.hours)::double precision as available_hours
FROM
(SELECT COUNT(work_date) * 7.5 as hours FROM all_employee_work_dates_in_period(start_date, end_date)) AS ewd,
(SELECT COUNT(work_day) * 7.5 as hours FROM unavilable_staffing_dates_in_period(start_date, end_date)) AS usd,
(SELECT COUNT(absence_date) * 7.5 as hours FROM all_absence_dates_in_period(start_date, end_date)) AS abs
SELECT
SUM(7.5) AS all_hours,
SUM(CASE WHEN p.billable = 'unavailable' THEN s.staffing_percentage * 7.5 ELSE 0 END) AS unavailable_hours,
SUM((1 - COALESCE(a.absence_percentage, 0)) * s.staffing_percentage * 7.5) AS available_hours
FROM
employees e
LEFT JOIN staffing s ON e.id = s.employee AND s.date BETWEEN start_date AND end_date
LEFT JOIN absence a ON e.id = a.employee_id AND a.date = s.date
LEFT JOIN projects p ON s.project = p.id
WHERE
e.date_of_employment <= end_date AND (e.termination_date >= start_date OR e.termination_date IS NULL)
);
END
$$ LANGUAGE plpgsql;
Expand All @@ -549,12 +548,12 @@ returns table (hours numeric) as
$$
begin
return query (
SELECT
SELECT
COALESCE(SUM(time_entry.minutes)/60.0, 0) AS hours
FROM
projects JOIN time_entry ON time_entry.project = projects.id
WHERE
date >= from_date
date >= from_date
AND date <= to_date
AND deductable = true
);
Expand Down Expand Up @@ -627,15 +626,15 @@ $$ LANGUAGE plpgsql;
-- and is the ONLY employee to do so for current and preivous month (2 months aggregate)

CREATE OR REPLACE FUNCTION unaccompanied_customer_involvement_kpi(in_from_date date, in_to_date date)
RETURNS TABLE (from_date date, to_date date, percent double precision) AS
RETURNS TABLE (from_date date, to_date date, percent double precision) AS
$$
BEGIN
RETURN QUERY (
SELECT
x.from_date,
x.to_date,
COUNT(ae.employee_count) / t.employee_count :: double precision
FROM
FROM
month_dates(in_from_date, in_to_date, interval '2' month) x,
unaccompanied_customer_involvement_in_period(x.from_date, x.to_date) ae,
number_of_employees_in_period(x.from_date, x.to_date) t
Expand All @@ -647,16 +646,16 @@ $$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION unaccompanied_customer_involvement_in_period(from_date date, to_date date)
RETURNS TABLE (customer_id text, employee_count integer) AS
$$
BEGIN
RETURNS TABLE (customer_id text, employee_count integer) AS
$$
BEGIN
RETURN QUERY (
SELECT
qq.customer_id::text,
qq.customer_id::text,
sum(employee_id)::integer as employee_id
FROM
(
SELECT
SELECT
*,
(q.billable_hours / (q.business_hours - q.unavailable_hours)) AS fg
FROM
Expand Down Expand Up @@ -690,17 +689,17 @@ $$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION number_of_employees_in_period(from_date date, to_date date)
RETURNS TABLE (employee_count bigint) AS
$$
BEGIN
RETURNS TABLE (employee_count bigint) AS
$$
BEGIN
RETURN QUERY (
SELECT
SELECT
COUNT(*)
FROM
FROM
employees
WHERE
date_of_employment <= to_date AND
(termination_date >= from_date or termination_date is null) AND
WHERE
date_of_employment <= to_date AND
(termination_date >= from_date or termination_date is null) AND
has_permanent_position is TRUE
);
END
Expand Down Expand Up @@ -738,5 +737,3 @@ RETURN QUERY (
);
end
$$ LANGUAGE plpgsql;


Loading