Skip to content

Commit

Permalink
db: Add utility functions
Browse files Browse the repository at this point in the history
- Add functions to be used in calculation of yearly_expected_and_vacation for work summary
  • Loading branch information
dmtrek14 committed Jan 17, 2024
1 parent 3a061c0 commit bccb653
Show file tree
Hide file tree
Showing 3 changed files with 119 additions and 0 deletions.
48 changes: 48 additions & 0 deletions api/db/functions/get_vacation_for_period.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
from alembic_utils.pg_function import PGFunction


get_vacation_for_period = PGFunction(
schema="public",
signature="get_vacation_for_period(start_date date,end_date date,capacity numeric)",
definition="""
/*
* Author: Danielle Mayabb, Dec 2023
* Purpose: Provided a time range and daily capacity, gets the amount of vacation hours
* available to a user
* Notes: When getting the difference of dates, the end date is not included,
* so 1 day is added to the calculation
* Simplified formula is:
* (Number of days in period) / (Number of days in year)
* * yearly_vacation_hours * (daily_capacity * 5 / company_fte)
* So we determine the fraction of the year for which someone is working (it will be <=1)
* Multiply that by total available vacation hours so that if someone is only working part of the year,
* they get the correct proportion of vacation
* Next, we need to get a fraction for the capacity which is daily_capacity * 5 (for weekly capacity)
* divided by company_fte.
* This is the percentage of time of FTE someone works.
*/
returns numeric(8,4)
as $$
/*
* First, we need to get some constants:
* 1. The amount of yearly vacation hours for the company
* 2. What is considered FTE for the company (per week)
*/
declare yearly_vacation_hours int := (select config.yearly_vacation_hours from public.config limit 1);
declare company_fte_weekly int := (select config.company_fte from public.config limit 1);
BEGIN
return(
select (end_date - start_date + 1) /
(
make_date(date_part('year', end_date::date)::int, 12, 31) -
make_date(date_part('year', start_date::date)::int, 01, 01) + 1
)::float
* yearly_vacation_hours
* (capacity * 5 / company_fte_weekly::float)
);
end;
$$
LANGUAGE plpgsql
;
""",
)
28 changes: 28 additions & 0 deletions api/db/functions/get_workday_count.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
from alembic_utils.pg_function import PGFunction


get_workday_count = PGFunction(
schema="public",
signature="get_workday_count(start_date date, end_date date)",
definition="""
/*
* Author: Danielle Mayabb, Dec 2023
* Purpose: Provided a time range, gets the number of work days for the period,
* i.e., gets the count of non-weekend days
*/
RETURNS integer
as $$
BEGIN
return (
select count(generated_date::date)
from generate_series(
start_date,
end_date,
interval '1 day') as generated_date
where extract(isodow from generated_date) < 6);
END;
$$
LANGUAGE plpgsql
;
""",
)
43 changes: 43 additions & 0 deletions api/migrations/versions/6a1ad39b566d_add_calculation_functions.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
"""Add calculation functions
Revision ID: 6a1ad39b566d
Revises: 2ac6108453f3
Create Date: 2024-01-05 11:07:57.026492
"""
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.get_workday_count import get_workday_count
from db.functions.get_vacation_for_period import get_vacation_for_period

# revision identifiers, used by Alembic.
revision = "6a1ad39b566d"
down_revision = "cf4f31d5cd2d"
branch_labels = None
depends_on = None


def upgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
op.create_entity(get_workday_count)
op.create_entity(get_vacation_for_period)
# ### end Alembic commands ###


def downgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
get_workday_count = PGFunction(
schema="public",
signature="get_workday_count(start_date date, end_date date)",
definition="# ",
)
op.drop_entity(get_workday_count)
get_vacation_for_period = PGFunction(
schema="public",
signature="get_vacation_for_period(start_date date, end_date date, capacity numeric)",
definition="# ",
)
op.drop_entity(get_vacation_for_period)
# ### end Alembic commands ###

0 comments on commit bccb653

Please sign in to comment.