From ccc5018ec757ceb9dc8fcfc19346bc4754c022dc Mon Sep 17 00:00:00 2001
From: Lorenz Zahn <lorenz.zahn@student.uni-halle.de>
Date: Sun, 2 Jul 2023 19:14:52 +0200
Subject: [PATCH] department evaluations ready for testing

---
 .../accounting/department/evaluation.csv      |   2 +-
 .../workhours/accounting/departments/views.py | 251 +++++++++++++++++-
 2 files changed, 245 insertions(+), 8 deletions(-)

diff --git a/app/vkk/templates/vkk/workhours/accounting/department/evaluation.csv b/app/vkk/templates/vkk/workhours/accounting/department/evaluation.csv
index 2dcbe63e..a968ac78 100644
--- a/app/vkk/templates/vkk/workhours/accounting/department/evaluation.csv
+++ b/app/vkk/templates/vkk/workhours/accounting/department/evaluation.csv
@@ -1,3 +1,3 @@
 Projekt; abgeführte PGK; abgeführte SGK; Summe PGK+SGK; abgeführte VGK; Summe
-{% for project in projects %}
+{% for project in projects %}{% for column in project %}{{ column }};{% endfor %}
 {% endfor %}
\ No newline at end of file
diff --git a/app/vkk/workhours/accounting/departments/views.py b/app/vkk/workhours/accounting/departments/views.py
index d43d8bcb..63ea6e98 100644
--- a/app/vkk/workhours/accounting/departments/views.py
+++ b/app/vkk/workhours/accounting/departments/views.py
@@ -1,4 +1,5 @@
 from django.template import loader
+from django.db import connection
 from django.http import HttpResponse
 from django.views.generic import FormView
 from vkk.workhours.accounting.mixins import AccountantRequiredMixin
@@ -9,22 +10,258 @@ class EvaluationView(AccountantRequiredMixin, FormView):
     template_name = 'vkk/workhours/accounting/department/evaluation.html'
     form_class = EvaluationForm
 
-    def get_context_data(self, **kwargs):
-        context = super().get_context_data(**kwargs)
-        context["projects"] = {}
-        return context    
+    def get_queryset(self, periods):
+        with connection.cursor() as cursor:
+            cursor.execute("WITH assignments AS ( \
+                    SELECT  \
+                        vkk_project.id AS project_id, \
+                        vkk_project.start AS project_start, \
+                        vkk_project.end AS project_end, \
+                        vkk_projectassignment.id AS assignment_id, \
+                        salary_level_id \
+                    FROM vkk_project JOIN vkk_projectassignment \
+                        ON vkk_project.id = vkk_projectassignment.project_id \
+                    WHERE vkk_project.department_id = %s \
+                ), \
+                workhours AS ( \
+                    SELECT  \
+                        project_id, \
+                        project_start, \
+                        project_end, \
+                        assignment_id, \
+                        salary_level_id, \
+                        period_id, \
+                        hours \
+                    FROM assignments JOIN vkk_workhours \
+                        ON assignments.assignment_id = vkk_workhours.project_assignment_id \
+                    UNION \
+                    SELECT  \
+                        project_id, \
+                        project_start, \
+                        project_end, \
+                        assignment_id, \
+                        salary_level_id, \
+                        period_id, \
+                        ammount AS hours \
+                    FROM assignments JOIN vkk_workhourscorrection \
+                        ON assignments.assignment_id = vkk_workhourscorrection.project_assignment_id \
+                ), \
+                periods AS ( \
+                    SELECT  \
+                        vkk_period.id, \
+                        vkk_period.start, \
+                        vkk_period.end \
+                    FROM vkk_period \
+                    WHERE id IN %s \
+                ), \
+                workhours_bounded AS ( \
+                    SELECT \
+                        project_id, \
+                        project_start, \
+                        project_end, \
+                        assignment_id, \
+                        salary_level_id, \
+                        period_id, \
+                        periods.start AS period_start, \
+                        periods.end AS period_end, \
+                        hours \
+                    FROM workhours JOIN periods \
+                    ON workhours.period_id = periods.id \
+                    WHERE  \
+                        periods.end >= workhours.project_start \
+                        AND periods.start <= workhours.project_end \
+                ), \
+                workhours_summed AS ( \
+                    SELECT  \
+                        project_id, \
+                        salary_level_id, \
+                        period_id, \
+                        SUM(hours) AS hours \
+                    FROM workhours_bounded \
+                    GROUP BY  \
+                        project_id, \
+                        salary_level_id, \
+                        period_id \
+                ), \
+                salary_dates AS ( \
+                    SELECT \
+                        vkk_salaryleveldate.id AS salary_date_id, \
+                        p.period_id \
+                    FROM vkk_salaryleveldate JOIN ( \
+                        SELECT \
+                            MAX(vkk_salaryleveldate.date) AS salary_date, \
+                            periods.id AS period_id \
+                        FROM vkk_salaryleveldate, periods \
+                        WHERE vkk_salaryleveldate.date <= periods.start \
+                        GROUP BY periods.id \
+                    ) AS p \
+                    ON vkk_salaryleveldate.date = p.salary_date \
+                ), \
+                department_dates AS ( \
+                    SELECT \
+                        vkk_departmentdate.id AS departmentdate_id, \
+                        p.id AS period_id \
+                    FROM vkk_departmentdate JOIN ( \
+                        SELECT \
+                            MAX(vkk_departmentdate.date) AS department_date, \
+                            periods.id AS id \
+                        FROM vkk_departmentdate, periods \
+                        WHERE vkk_departmentdate.date <= periods.start \
+                        GROUP BY periods.id \
+                    ) AS p \
+                    ON vkk_departmentdate.date = p.department_date \
+                ), \
+                project_funded_staff_date AS ( \
+                    SELECT \
+                        vkk_projectfundedstaffdate.id, \
+                        p.project_id, \
+                        p.period_id \
+                    FROM vkk_projectfundedstaffdate, ( \
+                            SELECT \
+                                MAX(vkk_projectfundedstaffdate.date) AS staff_date, \
+                                project_id, \
+                                periods.id AS period_id \
+                            FROM vkk_projectfundedstaffdate, periods \
+                            WHERE vkk_projectfundedstaffdate.date <= periods.start \
+                            GROUP BY project_id, periods.id \
+                        ) AS p \
+                    WHERE \
+                        vkk_projectfundedstaffdate.date = p.staff_date \
+                        AND vkk_projectfundedstaffdate.project_id = p.project_id \
+                ), \
+                general_costs AS ( \
+                    SELECT \
+                        vkk_generalcosts.costs, \
+                        p.period_id \
+                    FROM vkk_generalcosts JOIN ( \
+                        SELECT \
+                            MAX(vkk_generalcosts.start) AS general_costs_date, \
+                            periods.id AS period_id \
+                        FROM vkk_generalcosts, periods \
+                        WHERE vkk_generalcosts.start <= periods.start \
+                        GROUP BY periods.id \
+                    ) AS p \
+                    ON vkk_generalcosts.start = p.general_costs_date \
+                ), \
+                salary_level_costs AS ( \
+                    SELECT \
+                        vkk_salarylevelcosts.salary_level_id, \
+                        vkk_salarylevelcosts.brutto_per_hour, \
+                        salary_dates.period_id \
+                    FROM vkk_salarylevelcosts JOIN salary_dates \
+                    ON vkk_salarylevelcosts.start_id = salary_dates.salary_date_id \
+                ), \
+                department_costs AS ( \
+                    SELECT \
+                        vkk_departmentcosts.equivalents_per_hour, \
+                        department_dates.period_id \
+                    FROM vkk_departmentcosts JOIN department_dates \
+                    ON vkk_departmentcosts.start_id = department_dates.departmentdate_id \
+                    WHERE department_id = %s \
+                ), \
+                project_funded_staff AS ( \
+                    SELECT \
+                        project_id, \
+                        period_id, \
+                        vkk_projectfundedstaff.salary_level_id, \
+                        vkk_projectfundedstaff.hours \
+                    FROM project_funded_staff_date JOIN vkk_projectfundedstaff \
+                    ON project_funded_staff_date.id = vkk_projectfundedstaff.start_id \
+                ), \
+                workhours_together AS ( \
+                    SELECT  \
+                        project_id, \
+                        salary_level_id, \
+                        period_id, \
+                        hours \
+                    FROM workhours_summed \
+                    UNION \
+                    SELECT \
+                        project_id, \
+                        period_id, \
+                        salary_level_id, \
+                        hours \
+                    FROM project_funded_staff \
+                ), \
+                workhours_together_summed_salary AS ( \
+                    SELECT \
+                        project_id, \
+                        salary_level_id, \
+                        period_id, \
+                        SUM(hours) AS hours \
+                    FROM workhours_together \
+                    GROUP BY project_id, salary_level_id, period_id \
+                ), \
+                salary_costs_by_project AS ( \
+                    SELECT \
+                        workhours_together_summed_salary.project_id, \
+                        SUM(workhours_together_summed_salary.hours * salary_level_costs.brutto_per_hour) AS salary_costs \
+                    FROM workhours_together_summed_salary, salary_level_costs \
+                    WHERE workhours_together_summed_salary.salary_level_id = salary_level_costs.salary_level_id \
+                    AND workhours_together_summed_salary.period_id = salary_level_costs.period_id \
+                    GROUP BY workhours_together_summed_salary.project_id \
+                ), \
+                workhours_together_summed AS ( \
+                    SELECT \
+                        project_id, \
+                        period_id, \
+                        SUM(hours) AS hours \
+                    FROM workhours_together_summed_salary \
+                    GROUP BY project_id, period_id \
+                ), \
+                general_costs_by_project AS ( \
+                    SELECT \
+                        project_id, \
+                        SUM(hours * costs) AS general_costs \
+                    FROM workhours_together_summed JOIN general_costs \
+                    ON workhours_together_summed.period_id = general_costs.period_id \
+                    GROUP BY project_id \
+                ), \
+                department_costs_by_project AS ( \
+                    SELECT \
+                        project_id, \
+                        SUM(hours * equivalents_per_hour) AS department_costs \
+                    FROM workhours_together_summed JOIN department_costs \
+                    ON workhours_together_summed.period_id = department_costs.period_id \
+                    GROUP BY project_id \
+                ) \
+                SELECT \
+                    vkk_project.invoice_number AS projekt, \
+                    salary_costs_by_project.salary_costs AS pgk, \
+                    general_costs_by_project.general_costs AS sgk, \
+                    salary_costs_by_project.salary_costs + general_costs_by_project.general_costs AS sum_pgk_sgk, \
+                    department_costs_by_project.department_costs AS vgk, \
+                    salary_costs_by_project.salary_costs + general_costs_by_project.general_costs + department_costs_by_project.department_costs AS sum_all \
+                FROM  \
+                    vkk_project,  \
+                    salary_costs_by_project, \
+                    general_costs_by_project, \
+                    department_costs_by_project \
+                WHERE  \
+                    vkk_project.id = salary_costs_by_project.project_id \
+                    AND salary_costs_by_project.project_id = general_costs_by_project.project_id \
+                    AND general_costs_by_project.project_id = department_costs_by_project.project_id \
+                ;", 
+                [self.kwargs['pk'], periods, self.kwargs['pk']],
+            )
+            queryset = cursor.fetchall()
+        return queryset
+    
 
     def form_valid(self, form):
+        periods = tuple(n[0] for n in form.cleaned_data['periods'].values_list('id'))
+        context = self.get_context_data()
+        context["projects"] = self.get_queryset(periods)
         response = HttpResponse(
             content_type='text/csv',
             headers={
                 'Content-Disposition': 'attachment; filename="12345.csv"'},
         )
         response.write(
-            loader \
-                .get_template('vkk/workhours/accounting/department/evaluation.csv') \
+            loader
+                .get_template('vkk/workhours/accounting/department/evaluation.csv')
                 .render(
-                    context=self.get_context_data(),
+                    context=context,
                     request=self.request
                 )
         )
-- 
GitLab