@@ -1,5 +1,6 @@
|
||||
package de.financer.controller;
|
||||
|
||||
import de.financer.dto.PeriodOverviewDto;
|
||||
import de.financer.model.Period;
|
||||
import de.financer.service.PeriodService;
|
||||
import org.slf4j.Logger;
|
||||
@@ -9,6 +10,8 @@ import org.springframework.http.ResponseEntity;
|
||||
import org.springframework.web.bind.annotation.RequestMapping;
|
||||
import org.springframework.web.bind.annotation.RestController;
|
||||
|
||||
import java.util.List;
|
||||
|
||||
@RestController
|
||||
@RequestMapping("periods")
|
||||
public class PeriodController {
|
||||
@@ -46,4 +49,19 @@ public class PeriodController {
|
||||
|
||||
return currentExpensePeriod;
|
||||
}
|
||||
|
||||
@RequestMapping("getPeriodOverview")
|
||||
public List<PeriodOverviewDto> getPeriodOverview() {
|
||||
if (LOGGER.isDebugEnabled()) {
|
||||
LOGGER.debug("/periods/getPeriodOverview called");
|
||||
}
|
||||
|
||||
final List<PeriodOverviewDto> overview = this.periodService.getPeriodOverview();
|
||||
|
||||
if (LOGGER.isDebugEnabled()) {
|
||||
LOGGER.debug(String.format("/periods/getPeriodOverview returns with %s", overview));
|
||||
}
|
||||
|
||||
return overview;
|
||||
}
|
||||
}
|
||||
|
||||
@@ -0,0 +1,22 @@
|
||||
package de.financer.dba;
|
||||
|
||||
import java.io.BufferedReader;
|
||||
import java.io.InputStreamReader;
|
||||
import java.util.stream.Collectors;
|
||||
|
||||
public enum NativeQueries {
|
||||
PERIOD_OVERVIEW_QUERY("period_overview.sql");
|
||||
|
||||
private String query;
|
||||
|
||||
private NativeQueries(String fileName) {
|
||||
this.query = new BufferedReader(
|
||||
new InputStreamReader(NativeQueries.class.getClassLoader()
|
||||
.getResourceAsStream("native_queries/" + fileName)))
|
||||
.lines().collect(Collectors.joining("\n"));
|
||||
}
|
||||
|
||||
public String getQuery() {
|
||||
return this.query;
|
||||
}
|
||||
}
|
||||
@@ -10,7 +10,7 @@ import org.springframework.transaction.annotation.Transactional;
|
||||
import java.time.LocalDateTime;
|
||||
|
||||
@Transactional(propagation = Propagation.REQUIRED)
|
||||
public interface PeriodRepository extends CrudRepository<Period, Long> {
|
||||
public interface PeriodRepository extends CrudRepository<Period, Long>, PeriodRepositoryCustom {
|
||||
@Query("SELECT p FROM Period p WHERE p.type = :type AND p.end IS NULL")
|
||||
Period findCurrentExpensePeriod(PeriodType type);
|
||||
|
||||
|
||||
@@ -0,0 +1,9 @@
|
||||
package de.financer.dba;
|
||||
|
||||
import de.financer.dto.PeriodOverviewDto;
|
||||
|
||||
import java.util.List;
|
||||
|
||||
public interface PeriodRepositoryCustom {
|
||||
List<PeriodOverviewDto> getPeriodOverview();
|
||||
}
|
||||
@@ -0,0 +1,23 @@
|
||||
package de.financer.dba.impl;
|
||||
|
||||
import de.financer.dba.NativeQueries;
|
||||
import de.financer.dba.PeriodRepositoryCustom;
|
||||
import de.financer.dto.PeriodOverviewDto;
|
||||
import org.springframework.stereotype.Repository;
|
||||
|
||||
import javax.persistence.EntityManager;
|
||||
import javax.persistence.PersistenceContext;
|
||||
import java.util.List;
|
||||
|
||||
@Repository
|
||||
public class PeriodRepositoryCustomImpl implements PeriodRepositoryCustom {
|
||||
@PersistenceContext
|
||||
private EntityManager entityManager;
|
||||
|
||||
@Override
|
||||
public List<PeriodOverviewDto> getPeriodOverview() {
|
||||
return this.entityManager
|
||||
.createNativeQuery(NativeQueries.PERIOD_OVERVIEW_QUERY.getQuery(), "PeriodOverviewResult")
|
||||
.getResultList();
|
||||
}
|
||||
}
|
||||
@@ -2,6 +2,7 @@ package de.financer.service;
|
||||
|
||||
import de.financer.ResponseReason;
|
||||
import de.financer.dba.PeriodRepository;
|
||||
import de.financer.dto.PeriodOverviewDto;
|
||||
import de.financer.model.Period;
|
||||
import de.financer.model.PeriodType;
|
||||
import de.financer.model.Transaction;
|
||||
@@ -14,6 +15,7 @@ import org.springframework.transaction.annotation.Transactional;
|
||||
|
||||
import java.time.LocalDateTime;
|
||||
import java.time.LocalTime;
|
||||
import java.util.List;
|
||||
import java.util.Optional;
|
||||
|
||||
@Service
|
||||
@@ -139,4 +141,8 @@ public class PeriodService {
|
||||
public Optional<Period> getPeriodById(Long id) {
|
||||
return this.periodRepository.findById(id);
|
||||
}
|
||||
|
||||
public List<PeriodOverviewDto> getPeriodOverview() {
|
||||
return this.periodRepository.getPeriodOverview();
|
||||
}
|
||||
}
|
||||
|
||||
@@ -0,0 +1,10 @@
|
||||
This folder contains DBMS-agnostic native queries.
|
||||
|
||||
Reasons for doing it like this:
|
||||
- Queries in here are quite big and expressing those either with Criteria API or HQL/JPQL is a PITA
|
||||
- Easy formatting for readability
|
||||
- Actually SQL files
|
||||
|
||||
Downsides:
|
||||
- No compile-time check via e.g. the static meta model created during build, but will be mitigated with Unit tests
|
||||
- Quite unique infrastructure to integrate these queries into the Spring repositories (SqlResultSetMapping, NativeQueries)
|
||||
@@ -0,0 +1,130 @@
|
||||
WITH income AS (
|
||||
-- Regular income based on INCOME accounts
|
||||
SELECT p.ID, SUM(asIncome.spending_total_from) AS incomeSum
|
||||
FROM period p
|
||||
INNER JOIN account_statistic asIncome ON asIncome.period_id = p.id
|
||||
INNER JOIN account aIncome ON aIncome.id = asIncome.account_id AND aIncome.type = 'INCOME'
|
||||
GROUP BY p.id, p.type, p.start, p."end"
|
||||
),
|
||||
incomeCredit as (
|
||||
-- Special case for credits that can be booked from a LIABILITY account to a BANK/CASH account
|
||||
-- Need to be counted as income as the money is used for expenses and those expenses will be counted
|
||||
-- as expense, so to make it even we need to count it here as well
|
||||
SELECT p2.id, SUM(amount) AS incomeCreditSum
|
||||
FROM "transaction" t
|
||||
INNER JOIN account a on a.id = t.from_account_id
|
||||
INNER JOIN account a2 on a2.id = t.to_account_id
|
||||
INNER JOIN link_transaction_period ltp on ltp.transaction_id = t.id
|
||||
INNER JOIN period p2 on p2.id = ltp.period_id
|
||||
WHERE 1 = 1
|
||||
AND a.type in ('LIABILITY')
|
||||
AND a2.type in ('BANK', 'CASH')
|
||||
GROUP BY p2.id, p2.type, p2.start, p2."end"
|
||||
),
|
||||
incomeStart as (
|
||||
-- Special case for money that was there at the starting time of a financer instance
|
||||
-- Will be counted as income as this money is used for expanses, so to make it even
|
||||
-- we need to count it here as well
|
||||
SELECT p2.id, SUM(amount) AS incomeStartSum
|
||||
FROM "transaction" t
|
||||
INNER JOIN account a on a.id = t.from_account_id
|
||||
INNER JOIN account a2 on a2.id = t.to_account_id
|
||||
INNER JOIN link_transaction_period ltp on ltp.transaction_id = t.id
|
||||
INNER JOIN period p2 on p2.id = ltp.period_id
|
||||
WHERE 1 = 1
|
||||
AND a.type in ('START')
|
||||
AND a2.type in ('BANK', 'CASH')
|
||||
GROUP BY p2.id, p2.type, p2.start, p2."end"
|
||||
),
|
||||
expense AS (
|
||||
-- Expense booking - NOT counted is the case LIABILITY -> EXPENSE even though that is a
|
||||
-- valid booking in the app. This is because we would count the expense once here and a second time
|
||||
-- with the liability query
|
||||
SELECT p2.id, SUM(amount) AS expenseSum
|
||||
FROM "transaction" t
|
||||
INNER JOIN account a on a.id = t.from_account_id
|
||||
INNER JOIN account a2 on a2.id = t.to_account_id
|
||||
INNER JOIN link_transaction_period ltp on ltp.transaction_id = t.id
|
||||
INNER JOIN period p2 on p2.id = ltp.period_id
|
||||
WHERE 1 = 1
|
||||
AND a.type in ('BANK', 'CASH')
|
||||
AND a2.type in ('EXPENSE')
|
||||
GROUP BY p2.id, p2.type, p2.start, p2."end"
|
||||
),
|
||||
liability AS (
|
||||
-- Excluded is the special case for start bookings, START -> LIABILITY
|
||||
-- as the actual expense for that was some time in the past before the starting
|
||||
-- of the financer instance
|
||||
SELECT p2.id, SUM(amount) AS liabilitySum
|
||||
FROM "transaction" t
|
||||
INNER JOIN account a on a.id = t.from_account_id
|
||||
INNER JOIN account a2 on a2.id = t.to_account_id
|
||||
INNER JOIN link_transaction_period ltp on ltp.transaction_id = t.id
|
||||
INNER JOIN period p2 on p2.id = ltp.period_id
|
||||
WHERE 1 = 1
|
||||
AND a.type in ('BANK', 'CASH')
|
||||
AND a2.type in ('LIABILITY')
|
||||
GROUP BY p2.id, p2.type, p2.start, p2."end"
|
||||
),
|
||||
assets AS (
|
||||
-- Returns only the assets for closed periods
|
||||
SELECT p.ID, SUM(asBankCash.end_balance) AS assetSum
|
||||
FROM period p
|
||||
INNER JOIN account_statistic asBankCash ON asBankCash.period_id = p.id
|
||||
INNER JOIN account aBankCash ON aBankCash.id = asBankCash.account_id AND aBankCash.type IN ('BANK', 'CASH')
|
||||
GROUP BY p.id, p.type, p.start, p."end"
|
||||
),
|
||||
transactions AS (
|
||||
-- The count of transactions in a period
|
||||
SELECT ltp.period_id, COUNT(*) AS transaction_count
|
||||
FROM link_transaction_period ltp
|
||||
GROUP BY ltp.period_id
|
||||
)
|
||||
SELECT
|
||||
p.ID PERIOD_ID,
|
||||
p.type PERIOD_TYPE,
|
||||
p.start PERIOD_START,
|
||||
p."end" PERIOD_END,
|
||||
CASE
|
||||
-- 2^3 possible cases
|
||||
WHEN i.incomeSum IS NULL AND ic.incomeCreditSum IS NULL AND "is".incomeStartSum IS NULL THEN 0
|
||||
WHEN i.incomeSum IS NOT NULL AND ic.incomeCreditSum IS NULL AND "is".incomeStartSum IS NULL THEN i.incomeSum
|
||||
WHEN i.incomeSum IS NULL AND ic.incomeCreditSum IS NOT NULL AND "is".incomeStartSum IS NULL THEN ic.incomeCreditSum
|
||||
WHEN i.incomeSum IS NOT NULL AND ic.incomeCreditSum IS NOT NULL AND "is".incomeStartSum IS NULL THEN (i.incomeSum + ic.incomeCreditSum)
|
||||
WHEN i.incomeSum IS NULL AND ic.incomeCreditSum IS NULL AND "is".incomeStartSum IS NOT NULL THEN "is".incomeStartSum
|
||||
WHEN i.incomeSum IS NOT NULL AND ic.incomeCreditSum IS NULL AND "is".incomeStartSum IS NOT NULL THEN (i.incomeSum + "is".incomeStartSum)
|
||||
WHEN i.incomeSum IS NULL AND ic.incomeCreditSum IS NOT NULL AND "is".incomeStartSum IS NOT NULL THEN (ic.incomeCreditSum + "is".incomeStartSum)
|
||||
WHEN i.incomeSum IS NOT NULL AND ic.incomeCreditSum IS NOT NULL AND "is".incomeStartSum IS NOT NULL THEN (i.incomeSum + ic.incomeCreditSum + "is".incomeStartSum)
|
||||
END INCOME_SUM,
|
||||
CASE
|
||||
WHEN e.expenseSum IS NULL THEN 0
|
||||
WHEN e.expenseSum IS NOT NULL THEN e.expenseSum
|
||||
END EXPENSE_SUM,
|
||||
CASE
|
||||
WHEN l.liabilitySum IS NULL THEN 0
|
||||
WHEN l.liabilitySum IS NOT NULL THEN l.liabilitySum
|
||||
END LIABILITY_SUM,
|
||||
CASE
|
||||
-- 2^2 possible cases
|
||||
WHEN e.expenseSum IS NULL AND l.liabilitySum IS NULL THEN 0
|
||||
WHEN e.expenseSum IS NOT NULL AND l.liabilitySum IS NULL THEN e.expenseSum
|
||||
WHEN e.expenseSum IS NULL AND l.liabilitySum IS NOT NULL THEN l.liabilitySum
|
||||
WHEN e.expenseSum IS NOT NULL AND l.liabilitySum IS NOT NULL THEN (e.expenseSum + l.liabilitySum)
|
||||
END TOTAL,
|
||||
a.assetSum ASSETS_SUM,
|
||||
CASE
|
||||
WHEN t.transaction_count IS NULL THEN 0
|
||||
WHEN t.transaction_count IS NOT NULL THEN t.transaction_count
|
||||
END TRANSACTION_COUNT
|
||||
FROM
|
||||
period p
|
||||
LEFT JOIN income i ON i.ID = p.ID
|
||||
LEFT JOIN incomeCredit ic ON ic.ID = p.ID
|
||||
LEFT JOIN incomeStart "is" ON "is".ID = p.ID
|
||||
LEFT JOIN expense e ON e.ID = p.ID
|
||||
LEFT JOIN assets a ON a.ID = p.ID
|
||||
LEFT JOIN liability l ON l.ID = p.ID
|
||||
LEFT JOIN transactions t ON t.period_id = p.ID
|
||||
ORDER BY
|
||||
"end" DESC,
|
||||
start ASC;
|
||||
@@ -0,0 +1,50 @@
|
||||
package de.financer.controller.integration;
|
||||
|
||||
import com.fasterxml.jackson.core.type.TypeReference;
|
||||
import com.fasterxml.jackson.databind.ObjectMapper;
|
||||
import de.financer.FinancerApplication;
|
||||
import de.financer.dto.PeriodOverviewDto;
|
||||
import de.financer.model.Account;
|
||||
import org.junit.Assert;
|
||||
import org.junit.Test;
|
||||
import org.junit.runner.RunWith;
|
||||
import org.springframework.beans.factory.annotation.Autowired;
|
||||
import org.springframework.boot.test.autoconfigure.web.servlet.AutoConfigureMockMvc;
|
||||
import org.springframework.boot.test.context.SpringBootTest;
|
||||
import org.springframework.http.MediaType;
|
||||
import org.springframework.test.context.TestPropertySource;
|
||||
import org.springframework.test.context.junit4.SpringRunner;
|
||||
import org.springframework.test.web.servlet.MockMvc;
|
||||
import org.springframework.test.web.servlet.MvcResult;
|
||||
|
||||
import java.util.List;
|
||||
|
||||
import static org.springframework.test.web.servlet.request.MockMvcRequestBuilders.get;
|
||||
import static org.springframework.test.web.servlet.result.MockMvcResultMatchers.status;
|
||||
|
||||
@RunWith(SpringRunner.class)
|
||||
@SpringBootTest(classes = FinancerApplication.class)
|
||||
@AutoConfigureMockMvc
|
||||
@TestPropertySource(
|
||||
locations = "classpath:application-integrationtest.properties")
|
||||
public class PeriodController_getPeriodOverviewIntegrationTest {
|
||||
@Autowired
|
||||
private MockMvc mockMvc;
|
||||
|
||||
@Autowired
|
||||
private ObjectMapper objectMapper;
|
||||
|
||||
@Test
|
||||
public void test_getPeriodOverview() throws Exception {
|
||||
final MvcResult mvcResult = this.mockMvc
|
||||
.perform(get("/periods/getPeriodOverview").contentType(MediaType.APPLICATION_JSON))
|
||||
.andExpect(status().isOk())
|
||||
.andReturn();
|
||||
|
||||
final List<PeriodOverviewDto> periodOverview = this.objectMapper
|
||||
.readValue(mvcResult.getResponse().getContentAsByteArray(), new TypeReference<List<PeriodOverviewDto>>() {});
|
||||
|
||||
// No results in DB, we just want to test the execution of the query because it is native
|
||||
Assert.assertEquals(0, periodOverview.size());
|
||||
}
|
||||
}
|
||||
Reference in New Issue
Block a user