--- title: "HV2 Jahresabrechnung" author: "Wolfgang Hottgenroth" date: "2022-09-18" output: pdf_document: default html_document: default word_document: default --- ```{r setup, include=FALSE, echo=FALSE, message=FALSE} knitr::opts_chunk$set(echo = FALSE, message=FALSE) ``` ```{r} library(tidyverse, warn.conflicts = FALSE) library(DBI, warn.conflicts = FALSE) library(tidyr, warn.conflicts = FALSE) library(dplyr, warn.conflicts = FALSE) ``` ```{r} YEAR <- 2021 HOME <- Sys.getenv("HOME") Sys.setenv(PGHOST = "db.mainscnt.eu", PGDATABASE = "hv2", PGPORT = 5432, PGUSER = "wn", PGSSLMODE = "verify-ca", PGSSLKEY = paste(HOME, "/keys/psql/wn-postgresql-client-2.key", sep=""), PGSSLCERT = paste(HOME, "/keys/psql/wn-postgresql-client-2.crt", sep=""), PGSSLROOTCERT = paste(HOME, "/keys/psql/postgres-ca.crt", sep="")) con <- dbConnect(RPostgres::Postgres()) ``` # Übersicht über die Einnahmen ```{r} res <- dbSendQuery(con, " select f.description as flat, p.description as premise, aec.description as category, sum(ae.amount) as amount from flat_t f, premise_t p, tenancy_t ty, tenant_t t, account_t a, account_entry_t ae, account_entry_category_t aec where p.id = f.premise and ty.flat = f.id and ty.tenant = t.id and a.id = t.account and ae.account = a.id and aec.id = ae.account_entry_category and ae.fiscal_year = $1 and aec.description in ('Mietzahlung', 'Mietforderung', 'Betriebskostenforderung', 'Betriebskostenausgleich') group by p.description, f.description, aec.description; ") dbBind(res, list(YEAR)) income <- dbFetch(res) dbClearResult(res) income <- income %>% pivot_wider(names_from = category, values_from = amount) %>% mutate(Miete := -1 * Mietforderung) %>% mutate(Betriebskosten := Mietzahlung - Miete + Betriebskostenausgleich) %>% select(flat, premise, Miete, Betriebskosten) %>% arrange(premise, flat) %>% # mutate(across(where(is.numeric), ~num(., digits=2))) %>% mutate(across(where(is.numeric), ~replace(., is.na(.), 0))) ``` ```{r} knitr::kable(income) ``` # Übersicht über die Ausgaben ```{r} res <- dbSendQuery(con, " select aec.overhead_relevant as overhead_relevant, aec.description as category, sum(ae.amount) as amount from account_entry_category_t aec, account_entry_t ae where aec.id = ae.account_entry_category and aec.id not in (2, 3, 4, 29) and ae.fiscal_year = $1 group by aec.overhead_relevant, aec.description ") dbBind(res, list(YEAR)) expense <- dbFetch(res) dbClearResult(res) expense <- expense %>% arrange(overhead_relevant, category) %>% # mutate(across(where(is.numeric), ~num(., digits=2))) %>% mutate(across(where(is.numeric), ~replace(., is.na(.), 0))) ``` ```{r} knitr::kable(expense) ``` # Zusammenfassung ```{r} total_fee <- sum(income$Miete) total_overhead <- sum(income$Betriebskosten) total_income <- total_fee + total_overhead total_expense <- sum(expense$amount) overhead_relevant_expense <- expense %>% filter(overhead_relevant == TRUE) total_overhead_relevant_expense <- sum(overhead_relevant_expense$amount) total <- total_income + total_expense overview.income <- as_tibble( data.frame( "Kategorie" = c("Mieteinnahmen", "Betriebskostenvorauszahlungen", "Einnahmen ingesamt"), "Betrag" = c(total_fee, total_overhead, total_income) ) ) overview.expense <- as_tibble( data.frame( "Kategorie" = c("Ausgaben insgesamt", "davon Betriebskostenausgaben"), "Betrag" = c(-1 * total_expense, -1 * total_overhead_relevant_expense) ) ) overview.gain <- as_tibble( data.frame( "Überschuss" = c(total) ) ) ``` ## Einnahmen ```{r} knitr::kable(overview.income) ``` ## Ausgaben ```{r} knitr::kable(overview.expense) ``` ## Überschuss ```{r} knitr::kable(overview.gain) ```