Skip to content

Commit

Permalink
db: Add fxn/trigger to calculate vacation/expected
Browse files Browse the repository at this point in the history
This function will run against each journey_history when one is inserted or updated. It will use the dates in the range and the journey, along with company fte and yearly vacation hours, to determine how much vacation a user should have in each year in the journey and how many expected hours a user should work in the year.
  • Loading branch information
dmtrek14 committed Jan 24, 2024
1 parent 925c9b3 commit c36a6f5
Show file tree
Hide file tree
Showing 3 changed files with 151 additions and 0 deletions.
87 changes: 87 additions & 0 deletions api/db/functions/calculate_vacation_and_expected_hours.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,87 @@
from alembic_utils.pg_function import PGFunction

calculate_vacation_and_expected_hours = PGFunction(
schema="public",
signature="calculate_vacation_and_expected_hours()",
definition="""
/*
* Author: Danielle Mayabb, Dec 2023
* Purpose: On insert/update of capacity (journey_history), we run this function to calculate two values:
* 1. The total available hours for a user inside each calendar year in capacity range
* 2. The total hours a user is expected to work in a capacity range given their daily capacity
*/
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare init_year text := cast(date_part('year', NEW.init_date) as text);
declare end_year text := cast(date_part('YEAR', NEW.end_date) as text);
declare yearly_vacation_hours int := (select config.yearly_vacation_hours from public.config limit 1);
BEGIN
--first check to see if journey is within same year; if so, do a simple insert
IF (select date_trunc('YEAR', NEW.init_date::date) = date_trunc('YEAR', NEW.end_date::date)) = true THEN
NEW.yearly_expected_and_vacation := jsonb_build_array(
jsonb_build_object(init_year,
jsonb_build_object(
'expectedHours',
NEW.journey *
(select get_workday_count(NEW.init_date, NEW.end_date)),
'availableVacation',
(select get_vacation_for_period(NEW.init_date, NEW.end_date, NEW.journey))
)
));
RETURN NEW;
ELSEIF (select date_trunc('YEAR', NEW.init_date::date) = date_trunc('YEAR', NEW.end_date::date))
= false THEN
-- if many years are in range, we need to do a little more work
-- first, for each year in the range we need to get the dates inside each year as a range
--and hold onto them in a temp table
create temp table ranges(
year int,
range_start date,
range_end date,
range_in_year daterange
);
WITH
t(start_date,end_date) AS (VALUES (NEW.init_date::date, NEW.end_date::date)),
u AS (
SELECT
GENERATE_SERIES(EXTRACT(YEAR FROM start_date)::INT, EXTRACT(YEAR FROM end_date)::INT) AS year,
daterange(start_date,end_date) *
daterange(make_date(
GENERATE_SERIES(
EXTRACT(YEAR FROM start_date)::INT,
EXTRACT(YEAR FROM end_date)::INT),1,1)::date,
make_date(GENERATE_SERIES(EXTRACT(YEAR FROM start_date)::INT,
EXTRACT(YEAR FROM end_date)::INT),12,31)::date) as range_in_year
FROM
t)
insert into ranges select year,
lower(range_in_year),
upper(range_in_year),
range_in_year from u;
-- now we need to get all the rows from our temp table
-- and aggregate them into a json array
NEW.yearly_expected_and_vacation := (select jsonb_agg(
jsonb_build_object(
ranges.year::text,
jsonb_build_object(
'expectedHours',
NEW.journey * (select get_workday_count(ranges.range_start, ranges.range_end)),
'availableVacation',
(select get_vacation_for_period(ranges.range_start, ranges.range_end, NEW.journey))
)
)) from ranges
);
-- finally, we can get rid of our temp table
drop table ranges;
RETURN NEW;
END IF;
END;
$function$
;
""",
)
12 changes: 12 additions & 0 deletions api/db/triggers/trg_update_yearly_expected_and_vacation.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
from alembic_utils.pg_trigger import PGTrigger


trg_update_yearly_expected_and_vacation = PGTrigger(
schema="public",
signature="trg_update_yearly_expected_and_vacation",
on_entity="public.journey_history",
definition="""
before insert or update on
public.journey_history for each row execute procedure calculate_vacation_and_expected_hours();
""",
)
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
"""Add function and trigger to calculate yearly vacation and expected hours
Revision ID: fb8c0e665690
Revises: cd28ca502f89
Create Date: 2024-01-22 14:36:33.854720
"""
from alembic import op
import sqlalchemy as sa
from alembic_utils.pg_function import PGFunction
from alembic_utils.pg_trigger import PGTrigger
from db.functions.calculate_vacation_and_expected_hours import calculate_vacation_and_expected_hours
from db.triggers.trg_update_yearly_expected_and_vacation import trg_update_yearly_expected_and_vacation

# revision identifiers, used by Alembic.
revision = 'fb8c0e665690'
down_revision = 'cd28ca502f89'
branch_labels = None
depends_on = None


def upgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
op.create_entity(calculate_vacation_and_expected_hours)
op.create_entity(trg_update_yearly_expected_and_vacation)
# now, to populate the yearly_expected_and_vacation, we run an update statement
# and set yearly_expected_and_vacation to null, which will set off the trigger
conn = op.get_bind()
query = sa.text("UPDATE journey_history set yearly_expected_and_vacation = null")
res = conn.execute(query)
# ### end Alembic commands ###


def downgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
trg_update_yearly_expected_and_vacation = PGTrigger(
schema="public",
signature="trg_update_yearly_expected_and_vacation",
on_entity="public.journey_history",
definition="# "
)
calculate_vacation_and_expected_hours = PGFunction(
schema="public",
signature="calculate_vacation_and_expected_hours()",
definition="# "
)
op.drop_entity(trg_update_yearly_expected_and_vacation)
op.drop_entity(calculate_vacation_and_expected_hours)
conn = op.get_bind()
query = sa.text("UPDATE journey_history set yearly_expected_and_vacation = null")
res = conn.execute(query)
# ### end Alembic commands ###

0 comments on commit c36a6f5

Please sign in to comment.