create table done.t_required_worktime ( pk_required_worktime int primary key generated always as identity, required time without time zone not null default '8:0'::time, day date not null, fk_login int not null references profile.t_login(pk), unique(day, fk_login) ); grant select,insert,update,delete on done.t_required_worktime to timetrack; create table done.t_overtime ( pk_overtime int primary key generated always as identity, worktime_offset time without time zone not null, impact timestamp without time zone not null, fk_login int not null unique references profile.t_login(pk) ); grant select,insert,update on done.t_overtime to timetrack; create table done.t_freetime ( pk_freetime int primary key generated always as identity, day date not null, required_worktime time without time zone not null default '0:0'::time, reason text, fk_login int not null references profile.t_login(pk), unique(day, fk_login) ); grant select,insert,update,delete on done.t_freetime to timetrack; create view done.v_daylimit as with x(dayworktime, day, fk_login) as ( select coalesce(time_until - time_from, '0'::interval), time_from, fk_login from done.t_done ), y(daytime_from, daytime_until, day, fk_login) as ( select min(time_from), max(time_until), time_from, fk_login from done.t_done group by time_from, fk_login ) select y.daytime_from::time, y.daytime_until::time, sum(x.dayworktime)::time as dayworktime, y.daytime_until - y.daytime_from - sum(x.dayworktime) as breaks, y.day::date, y.fk_login from x left join y on y.day = x.day and y.fk_login = x.fk_login group by y.daytime_from, y.daytime_until, y.day, y.fk_login order by y.day desc; grant select on done.v_daylimit to timetrack; create view done.v_current_overtime as select x.worktime_offset + sum(l.dayworktime - r.required) as overtime, to_char(now(), 'DD.MM.YYYY HH24:MI') as impact, x.fk_login from done.t_overtime x left join done.v_daylimit l on l.fk_login = x.fk_login and l.day >= x.impact left join done.t_required_worktime r on r.fk_login = x.fk_login and r.day = l.day where l.day < now() group by x.worktime_offset, x.fk_login; grant select on done.v_current_overtime to timetrack; create view done.v_day as with x(dayworktime, day, fk_login, required, starttime, endtime) as ( select sum(d.dayworktime), d.day, d.fk_login, r.required, min(d.daytime_from), max(d.daytime_until) from done.v_daylimit d left join done.t_required_worktime r on r.day = d.day and r.fk_login = d.fk_login group by d.day, d.fk_login, r.required ) select day, dayworktime as worktime, endtime - starttime - dayworktime as breaktime, dayworktime - required as day_overtime, fk_login from x order by day desc, fk_login; grant select on done.v_day to timetrack; create or replace view done.v_version as select 20240103 as version;