Files
timetrackjooq/src/main/resources/done.sql
2023-10-06 10:48:11 +02:00

319 lines
11 KiB
SQL

create schema done;
create table done.t_billing (
lastchange timestamp without time zone default now(),
pk integer not null primary key generated always as identity,
name text not null unique,
shortcut text not null unique,
csskey text
);
create table done.t_job (
lastchange timestamp without time zone default now(),
pk integer not null primary key generated always as identity,
name text not null unique
);
create table done.t_module (
lastchange timestamp without time zone default now(),
pk integer not null primary key generated always as identity,
name text not null unique
);
create table done.t_project (
lastchange timestamp without time zone default now(),
pk integer not null primary key generated always as identity,
name text not null unique
);
create table done.t_done (
lastchange timestamp without time zone default now(),
pk integer not null primary key generated always as identity,
time_from timestamp without time zone,
time_until timestamp without time zone,
fk_project integer references done.t_project(pk),
fk_module integer references done.t_module(pk),
fk_job integer references done.t_job(pk),
fk_login integer not null references profile.t_login(pk),
fk_billing integer references done.t_billing(pk)
);
create view done.v_billing as
with x(total) as (
select count(1) as count
from done.t_done
) select b.pk, b.name, b.shortcut, b.csskey,
round(((count(db.*)::double precision / x.total::double precision) * 100::double precision)::numeric, 2) AS percent_usage
from x
left join done.t_billing b on true
left join done.t_done db on db.fk_project = b.pk
group by b.pk, b.name, b.shortcut, b.csskey, x.total
order by b.pk;
create view done.v_done as
select d.pk as fk_done,
l.pk as fk_login,
d.time_from,
d.time_until,
p.name as project_name,
m.name as module_name,
j.name as job_name,
l.login
from done.t_done d
left join done.t_project p on p.pk = d.fk_project
left join done.t_module m on m.pk = d.fk_module
left join done.t_job j on j.pk = d.fk_job
left join profile.t_login l on l.pk = d.fk_login;
create view done.v_duration as
select to_char(coalesce(time_until::timestamp with time zone, now()), 'yyyy-MM-dd'::text) as day,
(coalesce(time_until::timestamp with time zone, now()) - coalesce(time_from::timestamp with time zone, now())) AS duration,
project_name,
module_name,
job_name,
login,
fk_login
from done.v_done;
create view done.v_daily as
select sum(duration) as worktime, day, login, fk_login
from done.v_duration
group by day, login, fk_login;
create view done.v_daylimits as
with x(time_from, time_until, day, fk_login) as (
select time_from,
coalesce(time_until::timestamp with time zone, now()) as "coalesce",
to_char(time_from, 'yyyy-MM-dd'::text) as day,
fk_login
from done.t_done
) select min(x.time_from) as work_start,
max(x.time_until) as work_end,
x.day,
x.fk_login
from x
group by x.day, x.fk_login;
create view done.v_daysummary as
select ((l.work_end - (l.work_start)::timestamp with time zone) - d.worktime) as breaktime,
d.worktime, l.work_start, l.work_end, d.day, d.login, d.fk_login
from done.v_daily d
left join done.v_daylimits l on l.day = d.day;
create view done.v_eucanshare as
select d.pk as fk_done,
d.time_from::date as workday,
age(d.time_until, d.time_from) as duration,
p.name as project_name,
m.name as module_name,
j.name as job_name,
b.name as billing_name,
d.fk_login
from done.t_done d
left join done.t_project p on p.pk = d.fk_project
left join done.t_module m on m.pk = d.fk_module
left join done.t_job j on j.pk = d.fk_job
left join done.t_billing b on b.pk = d.fk_billing;
create view done.v_hamster as
select time_from::date as workday,
age(time_until, time_from) as duration,
project_name,
module_name,
job_name,
login
from done.v_done;
create view done.v_hamstersummary as
select workday,
to_char(sum(duration), 'HH24:MI'::text) as duration,
project_name,
module_name,
job_name,
login
from done.v_hamster
group by workday, project_name, module_name, job_name, login
order by login, workday, project_name, module_name, job_name;
create view done.v_job as
with x(total) as (
select count(1) as count
from done.t_done
) select j.pk, j.name,
round(((count(dj.*)::double precision / x.total::double precision) * 100::double precision)::numeric, 2) as percent_usage
from x
left join done.t_job j on true
left join done.t_done dj on dj.fk_project = j.pk
group by j.pk, j.name, x.total
order by j.pk;
create view done.v_module as
with x(total) as (
select count(1) as count
from done.t_done
) select m.pk, m.name,
round(((count(dm.*)::double precision / x.total::double precision) * 100::double precision)::numeric, 2) as percent_usage
from x
left join done.t_module m on true
left join done.t_done dm on dm.fk_project = m.pk
group by m.pk, m.name, x.total
order by m.pk;
create view done.v_project as
with x(total) as (
select count(1) as count
from done.t_done
) select p.pk, p.name,
round(((count(dp.*)::double precision / x.total::double precision) * 100::double precision)::numeric, 2) as percent_usage
from x
left join done.t_project p on true
left join done.t_done dp on dp.fk_project = p.pk
group by p.pk, p.name, x.total
order by p.pk;
create view done.v_tasklist as
select day,
to_char(sum(duration), 'HH24:MI'::text) as duration,
project_name,
module_name,
job_name,
fk_login
from done.v_duration
group by day, project_name, module_name, job_name, fk_login;
create view done.v_timelength as
select to_char(coalesce(time_until::timestamp with time zone, now()), 'yyyy-MM-dd'::text) as day,
(coalesce(time_until::timestamp with time zone, now()) - coalesce(time_from::timestamp with time zone, now())) as duration,
pk as fk_done,
fk_login
from done.t_done;
create view done.v_totalofday as
select to_char(breaktime, 'HH24:MI'::text) as breaktime,
to_char(worktime, 'HH24:MI'::text) as worktime,
to_char(work_start, 'HH24:MI'::text) as starttime,
to_char(work_end, 'HH24:MI'::text) as endtime,
day,
fk_login
from done.v_daysummary;
create view done.v_worktime as
select t.day,
to_char(sum(t.duration), 'HH24:MI'::text) as duration,
((to_char(sum(t.duration), 'HH24'::text))::double precision + ((to_char(sum(t.duration), 'MI'::text))::double precision / (60)::double precision)) as duration_hours,
p.name as project_name,
m.name as module_name,
j.name as job_name,
b.shortcut as billing_shortcut,
b.csskey as billing_csskey,
t.fk_login
from done.v_timelength t
left join done.t_done d on d.pk = t.fk_done
left join done.t_project p on p.pk = d.fk_project
left join done.t_module m on m.pk = d.fk_module
left join done.t_job j on j.pk = d.fk_job
left join done.t_billing b on b.pk = d.fk_billing
group by t.day, p.name, m.name, j.name, b.shortcut, b.csskey, t.fk_login;
copy done.t_billing (lastchange, pk, name, shortcut, csskey) from stdin;
2021-03-05 19:37:07.12832 1 WP2 (eucs) - Opal/Mica/..., REST WP2 WP2
2021-03-05 19:37:07.12832 2 WP4 (eucs) - Square² WP4 WP4
2021-03-05 19:37:07.12832 3 WP5 (eucs) - SHIP-Datenbereitstellung WP5 WP5
2021-03-05 19:37:07.12832 4 TA3 (nfdi) - Mica Dev NFDI TA3 TA3
\.
copy done.t_job (lastchange, pk, name) from stdin;
2019-01-08 09:38:08.725154 1 Mail
2019-01-08 09:38:08.725154 2 Entwicklung_Programmierung
2019-01-08 09:38:08.725154 3 Entwicklung_Dokumentation
2019-01-08 09:39:37.051674 4 Support
2019-01-09 09:53:36.16863 5 Administration
2019-01-09 09:53:36.16863 6 Backup
2019-01-09 09:53:36.16863 7 Bugfix
2019-01-09 09:53:36.16863 8 Dokumentation
2019-01-09 09:53:36.16863 9 Entwicklung
2019-01-09 09:53:36.16863 10 Entwicklung_Konzept
2019-01-09 09:53:36.16863 11 Entwicklung_Skript
2019-01-09 09:55:11.361812 12 Fachgespräch
2019-01-09 09:55:11.361812 13 Grafikarbeit
2019-01-09 09:55:11.361812 14 Konfiguration
2019-01-09 09:55:11.361812 15 Meeting
2019-01-09 09:55:11.361812 16 Planung/Verwaltung
2019-01-09 09:55:11.361812 17 PM (Projektmanagement)
2019-01-09 09:55:11.361812 18 Sonstiges
2019-01-09 09:55:11.361812 19 Telefonat
2019-01-09 09:55:11.361812 20 Test
2019-01-09 09:55:11.361812 21 Update
2019-01-09 09:55:11.361812 22 Vorbereitung
2019-01-09 09:55:11.361812 23 Zeiterfassung
2020-11-25 09:56:07.603265 24 Schulung
\.
copy done.t_module (lastchange, pk, name) from stdin;
2019-01-08 09:37:36.382486 1 alles
2019-01-08 09:39:25.507767 2 Server
2019-01-09 09:14:28.108934 3 Paper
2019-01-09 09:50:59.50593 4 QiG-Meeting
2019-01-09 09:50:59.50593 5 IT-Meeting
2019-01-09 09:50:59.50593 6 Dev-Meeting
2019-01-09 09:50:59.50593 7 RDev-Meeting
2019-01-09 09:50:59.50593 8 QS-Meeting
2019-01-17 21:59:44.714577 9 Anreise
2019-01-17 21:59:44.714577 10 Abreise
2019-02-19 09:38:02.150011 11 Datenbank
2019-03-04 09:21:22.188118 12 Dienstreise
2019-03-29 14:57:36.466358 13 Meeting/Konferenz
2019-11-05 10:44:52.630014 14 Bodyscanner
2019-12-16 09:33:19.829313 15 Dicom
2020-03-05 10:17:59.534045 16 NEXT-Meeting
\.
copy done.t_project (lastchange, pk, name) from stdin;
2019-01-08 09:37:17.390547 1 Ship
2019-01-08 09:37:17.390547 2 Square
2019-01-09 09:52:07.553366 3 Arcus
2019-01-09 09:52:07.553366 4 AssPro
2019-01-09 09:52:07.553366 5 Shipboss
2019-01-09 09:52:07.553366 6 Shipdesigner
2019-01-09 09:52:07.553366 7 Shippie
2019-01-09 09:52:07.553366 8 Sonstiges
2019-01-09 09:52:07.553366 10 Wiki
2019-03-27 17:50:02.992079 11 Modys
2019-03-29 14:57:06.124951 12 EUCanShare
2019-10-02 11:57:42.143895 13 MDM Münster
2019-11-28 12:13:45.29931 14 Pakt-MV
2020-06-15 09:23:42.387339 16 COVID-Replica
2020-05-15 14:35:41.477733 15 COVID-NFDI
2019-01-09 09:52:07.553366 9 Transferstelle
2020-08-26 08:39:50.160896 17 DGEpi
2021-02-09 08:54:23.966083 18 NFDI4Health
2021-03-15 10:02:23.771719 19 LimeSurvey
2021-06-01 14:35:07.469872 20 PIA
2021-12-09 14:02:07.387276 21 Website
2022-01-20 08:23:17.341068 22 NAKO
2023-03-06 08:31:28.498288 23 EUthyroid
2023-04-20 10:10:15.250677 24 gICS
\.
grant usage on schema done to timetrack;
grant select,insert,delete,update on table done.t_billing to timetrack;
grant select,insert,delete,update on table done.t_done to timetrack;
grant select,insert,delete,update on table done.t_job to timetrack;
grant select,insert,delete,update on table done.t_module to timetrack;
grant select,insert,delete,update on table done.t_project to timetrack;
grant select on table done.v_billing to timetrack;
grant select on table done.v_done to timetrack;
grant select on table done.v_duration to timetrack;
grant select on table done.v_daily to timetrack;
grant select on table done.v_daylimits to timetrack;
grant select on table done.v_daysummary to timetrack;
grant select on table done.v_hamstersummary to timetrack;
grant select on table done.v_job to timetrack;
grant select on table done.v_module to timetrack;
grant select on table done.v_project to timetrack;
grant select on table done.v_tasklist to timetrack;
grant select on table done.v_timelength to timetrack;
grant select on table done.v_totalofday to timetrack;
grant select on table done.v_worktime to timetrack;