Skip to content
Permalink
Browse files

Use SQL views for aggregating over years and months

Replace the DBMS specific aggregation queries with views (that are
created in a dbms specific manner)
  • Loading branch information
steinarb committed Nov 16, 2019
1 parent 22a3d82 commit 94bec24d3ace3c079682f4d216e773b3eba5d09c
@@ -403,7 +403,7 @@ public Account addAccount(User user) {
public List<SumYear> earningsSumOverYear(String username) {
List<SumYear> statistics = new ArrayList<>();
try(Connection connection = database.getConnection()) {
try(PreparedStatement statement = connection.prepareStatement(database.sumOverYearQuery())) {
try(PreparedStatement statement = connection.prepareStatement("select aggregate_amount, aggregate_year from sum_over_year_view where username=?")) {
statement.setString(1, username);
try(ResultSet resultSet = statement.executeQuery()) {
while (resultSet.next()) {
@@ -424,7 +424,7 @@ public Account addAccount(User user) {
public List<SumYearMonth> earningsSumOverMonth(String username) {
List<SumYearMonth> statistics = new ArrayList<>();
try(Connection connection = database.getConnection()) {
try(PreparedStatement statement = connection.prepareStatement(database.sumOverMonthQuery())) {
try(PreparedStatement statement = connection.prepareStatement("select aggregate_amount, aggregate_year, aggregate_month from sum_over_year_and_month_view where username=?")) {
statement.setString(1, username);
try(ResultSet resultSet = statement.executeQuery()) {
while (resultSet.next()) {
@@ -194,14 +194,4 @@ private void logError(String message, Exception exception) {
}
}

@Override
public String sumOverYearQuery() {
return "select sum(t.transaction_amount), YEAR(t.transaction_time) from transactions t join transaction_types tt on tt.transaction_type_id=t.transaction_type_id join accounts a on a.account_id=t.account_id where tt.transaction_is_work and a.username=? group by YEAR(t.transaction_time) order by YEAR(t.transaction_time)";
}

@Override
public String sumOverMonthQuery() {
return "select sum(t.transaction_amount), YEAR(t.transaction_time), MONTH(t.transaction_time) from transactions t join transaction_types tt on tt.transaction_type_id=t.transaction_type_id join accounts a on a.account_id=t.account_id where tt.transaction_is_work and a.username=? group by YEAR(t.transaction_time), MONTH(t.transaction_time) order by YEAR(t.transaction_time), MONTH(t.transaction_time)";
}

}
@@ -104,7 +104,7 @@ public void testThatActivatorCreatesDatabase() throws SQLException, DatabaseExce

// Verify that the schema changeset as well as all of the test data change sets has been run
List<RanChangeSet> ranChangeSets = provider.getChangeLogHistory();
assertEquals(45, ranChangeSets.size());
assertEquals(47, ranChangeSets.size());
}

@Test
@@ -50,4 +50,56 @@
<dropTable tableName="ukelonn_users" />
</changeSet>

<changeSet author="sb" id="sum-over-year-view-derby">
<preConditions onFail="CONTINUE" >
<and>
<not>
<viewExists viewName="sum_over_year_view" />
</not>
<dbms type="derby" />
</and>
</preConditions>

<createView viewName="sum_over_year_view" fullDefinition="false" >select sum(t.transaction_amount) as aggregate_amount, YEAR(t.transaction_time) as aggregate_year, a.username as username from transactions t join transaction_types tt on tt.transaction_type_id=t.transaction_type_id join accounts a on a.account_id=t.account_id where tt.transaction_is_work group by YEAR(t.transaction_time), a.username order by YEAR(t.transaction_time)</createView>
</changeSet>

<changeSet author="sb" id="sum-over-year-view-postgresql">
<preConditions onFail="CONTINUE" >
<and>
<not>
<viewExists viewName="sum_over_year_view" />
</not>
<dbms type="postgresql" />
</and>
</preConditions>

<createView viewName="sum_over_year_view" fullDefinition="false">select sum(t.transaction_amount) as aggregate_amount, extract(year from t.transaction_time) as aggregate_year, a.username as username from transactions t join transaction_types tt on tt.transaction_type_id=t.transaction_type_id join accounts a on a.account_id=t.account_id where tt.transaction_is_work group by extract(year from t.transaction_time), a.username order by extract(year from t.transaction_time)</createView>
</changeSet>

<changeSet author="sb" id="sum-over-year-and-month-view-derby">
<preConditions onFail="CONTINUE" >
<and>
<not>
<viewExists viewName="sum_over_year_and_month_view" />
</not>
<dbms type="derby" />
</and>
</preConditions>

<createView viewName="sum_over_year_and_month_view" fullDefinition="false" >select sum(t.transaction_amount) as aggregate_amount, YEAR(t.transaction_time) as aggregate_year, MONTH(t.transaction_time) as aggregate_month, a.username as username from transactions t join transaction_types tt on tt.transaction_type_id=t.transaction_type_id join accounts a on a.account_id=t.account_id where tt.transaction_is_work group by YEAR(t.transaction_time), MONTH(t.transaction_time), a.username order by YEAR(t.transaction_time), MONTH(t.transaction_time)</createView>
</changeSet>

<changeSet author="sb" id="sum-over-year-and-month-view-postgresql">
<preConditions onFail="CONTINUE" >
<and>
<not>
<viewExists viewName="sum_over_year_and_month_view" />
</not>
<dbms type="postgresql" />
</and>
</preConditions>

<createView viewName="sum_over_year_and_month_view" fullDefinition="false">select sum(t.transaction_amount) as aggregate_amount, extract(year from t.transaction_time) as aggregate_year, extract(month from t.transaction_time) as aggregate_month, a.username as username from transactions t join transaction_types tt on tt.transaction_type_id=t.transaction_type_id join accounts a on a.account_id=t.account_id where tt.transaction_is_work group by extract(year from t.transaction_time), extract(month from t.transaction_time), a.username order by extract(year from t.transaction_time), extract(month from t.transaction_time)</createView>
</changeSet>

</databaseChangeLog>
@@ -173,14 +173,4 @@ private void logError(String message, Exception exception) {
}
}

@Override
public String sumOverYearQuery() {
return "select sum(t.transaction_amount), extract(year from t.transaction_time) as year from transactions t join transaction_types tt on tt.transaction_type_id=t.transaction_type_id join accounts a on a.account_id=t.account_id where tt.transaction_is_work and a.username=? group by extract(year from t.transaction_time) order by extract(year from t.transaction_time)";
}

@Override
public String sumOverMonthQuery() {
return "select sum(t.transaction_amount), extract(year from t.transaction_time) as year, extract(month from t.transaction_time) as month from transactions t join transaction_types tt on tt.transaction_type_id=t.transaction_type_id join accounts a on a.account_id=t.account_id where tt.transaction_is_work and a.username=? group by extract(year from t.transaction_time), extract(month from t.transaction_time) order by extract(year from t.transaction_time), extract(month from t.transaction_time)";
}

}
@@ -23,8 +23,4 @@

void forceReleaseLocks();

String sumOverYearQuery();

String sumOverMonthQuery();

}

0 comments on commit 94bec24

Please sign in to comment.
You can’t perform that action at this time.