Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

FINERACT-2081: Fix incorrect usage of appuser_id instead of created_by for m_savings_account_transaction table #4102

Open
wants to merge 1 commit into
base: develop
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -62,6 +62,24 @@ public String formatValue(JdbcJavaType columnType, String value) {
return (columnType.isStringType() || columnType.isAnyDateType()) ? format("'%s'", value) : value;
}

public String castToDate(String fieldName) {
if (databaseTypeResolver.isMySQL()) {
return "DATE(" + fieldName + ")";
} else if (databaseTypeResolver.isPostgreSQL()) {
return fieldName + "::date";
}
throw new UnsupportedOperationException("Unsupported database type");
}

public String castToTime(String fieldName) {
if (databaseTypeResolver.isMySQL()) {
return "TIME(" + fieldName + ")";
} else if (databaseTypeResolver.isPostgreSQL()) {
return fieldName + "::time";
}
throw new UnsupportedOperationException("Unsupported database type");
}

public String groupConcat(String arg) {
if (databaseTypeResolver.isMySQL()) {
return format("GROUP_CONCAT(%s)", arg);
Expand Down Expand Up @@ -149,6 +167,16 @@ public String subDate(String date, String multiplier, String unit) {
}
}

public String addDate(String date, int multiplier, String unit) {
if (databaseTypeResolver.isMySQL()) {
return format("DATE_ADD(%s, INTERVAL %s %s)", date, multiplier, unit);
} else if (databaseTypeResolver.isPostgreSQL()) {
return format("(%s::TIMESTAMP + %s * INTERVAL '1 %s')", date, multiplier, unit);
} else {
throw new IllegalStateException("Database type is not supported for adding date " + databaseTypeResolver.databaseType());
}
}

public String dateDiff(String date1, String date2) {
if (databaseTypeResolver.isMySQL()) {
return format("DATEDIFF(%s, %s)", date1, date2);
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -410,7 +410,7 @@ public CashierTransactionsWithSummaryData retrieveCashierTransactionsWithSummary
hierarchySearchString = hierarchy;
}
final CashierTransactionSummaryMapper ctsm = new CashierTransactionSummaryMapper();
final String sql = "select " + ctsm.cashierTxnSummarySchema() + " limit 1000";
final String sql = "select " + ctsm.cashierTxnSummarySchema(sqlGenerator) + " limit 1000";

Collection<CashierTransactionTypeTotalsData> cashierTxnTypeTotals = this.jdbcTemplate.query(sql, ctsm, // NOSONAR
new Object[] { cashierId, currencyCode, hierarchySearchString, cashierId, currencyCode, hierarchySearchString, cashierId,
Expand Down Expand Up @@ -466,22 +466,24 @@ public Page<CashierTransactionData> retrieveCashierTransactions(final Long cashi
final CashierTransactionMapper ctm = new CashierTransactionMapper();

String sql = "select * from (select " + ctm.cashierTxnSchema()
+ " where txn.cashier_id = ? and txn.currency_code = ? and o.hierarchy like ? "
+ "AND ((case when c.full_day then Date(txn.created_date) between c.start_date AND c.end_date else ( Date(txn.created_date) between c.start_date AND c.end_date"
+ " ) and ( TIME(txn.created_date) between TIME(c.start_time) AND TIME(c.end_time)) end) or txn.txn_type = 101)) cashier_txns "
+ " union (select " + ctm.savingsTxnSchema()
+ " where txn.cashier_id = ? and txn.currency_code = ? and o.hierarchy like ? " + "AND ((case when c.full_day then "
+ sqlGenerator.castToDate("txn.created_date") + " between c.start_date AND c.end_date else ( "
+ sqlGenerator.castToDate("txn.created_date") + " between c.start_date AND c.end_date" + " ) and ( "
+ sqlGenerator.castToTime("txn.created_date") + " between " + sqlGenerator.castToTime("c.start_time") + " AND "
+ sqlGenerator.castToTime("c.end_time") + ") end) or txn.txn_type = 101)) cashier_txns " + " union (select "
+ ctm.savingsTxnSchema()
+ " where sav_txn.is_reversed = false and c.id = ? and sav.currency_code = ? and o.hierarchy like ? and "
+ " sav_txn.transaction_date between c.start_date and date_add(c.end_date, interval 1 day) "
+ " sav_txn.transaction_date between c.start_date and " + sqlGenerator.addDate("c.end_date", 1, "day")
+ " and renum.enum_value in ('deposit','withdrawal fee', 'Pay Charge', 'withdrawal', 'Annual Fee', 'Waive Charge', 'Interest Posting', 'Overdraft Interest') "
+ " and (sav_txn.payment_detail_id IS NULL OR payType.is_cash_payment = true) " + " AND acnttrans.id IS NULL ) "
+ " union (select " + ctm.loansTxnSchema()
+ " where loan_txn.is_reversed = false and c.id = ? and loan.currency_code = ? and o.hierarchy like ? and "
+ " loan_txn.transaction_date between c.start_date and date_add(c.end_date, interval 1 day) "
+ " loan_txn.transaction_date between c.start_date and " + sqlGenerator.addDate("c.end_date", 1, "day")
+ " and renum.enum_value in ('REPAYMENT_AT_DISBURSEMENT','REPAYMENT', 'RECOVERY_REPAYMENT','DISBURSEMENT', 'CHARGE_PAYMENT', 'WAIVE_CHARGES', 'WAIVE_INTEREST', 'WRITEOFF') "
+ " and (loan_txn.payment_detail_id IS NULL OR payType.is_cash_payment = true) " + " AND acnttrans.id IS NULL ) "
+ " union (select " + ctm.clientTxnSchema()
+ " where cli_txn.is_reversed = false and c.id = ? and cli_txn.currency_code = ? and o.hierarchy like ? and cli_txn.transaction_date "
+ " between c.start_date and date_add(c.end_date, interval 1 day) "
+ " between c.start_date and " + sqlGenerator.addDate("c.end_date", 1, "day")
+ " and renum.enum_value in ('PAY_CHARGE', 'WAIVE_CHARGE') "
+ " and (cli_txn.payment_detail_id IS NULL OR payType.is_cash_payment = true) ) " + " order by created_date ";

Expand Down Expand Up @@ -588,8 +590,8 @@ public String savingsTxnSchema() {
sqlBuilder.append(" left join m_savings_account sav on sav_txn.savings_account_id = sav.id ");
sqlBuilder.append(" left join m_client cl on sav.client_id = cl.id ");
sqlBuilder.append(" left join m_office o on cl.office_id = o.id ");
sqlBuilder.append(" left join m_appuser user on sav_txn.appuser_id = user.id ");
sqlBuilder.append(" left join m_staff staff on user.staff_id = staff.id ");
sqlBuilder.append(" left join m_appuser appuser on sav_txn.created_by = appuser.id ");
sqlBuilder.append(" left join m_staff staff on appuser.staff_id = staff.id ");
sqlBuilder.append(" left join m_cashiers c on c.staff_id = staff.id ");
sqlBuilder.append(" left join m_payment_detail payDetails on payDetails.id = sav_txn.payment_detail_id ");
sqlBuilder.append(" left join m_payment_type payType on payType.id = payDetails.payment_type_id ");
Expand Down Expand Up @@ -626,8 +628,8 @@ public String loansTxnSchema() {
sqlBuilder.append(" left join m_loan loan on loan_txn.loan_id = loan.id ");
sqlBuilder.append(" left join m_client cl on loan.client_id = cl.id ");
sqlBuilder.append(" left join m_office o on cl.office_id = o.id ");
sqlBuilder.append(" left join m_appuser user on loan_txn.created_by = user.id ");
sqlBuilder.append(" left join m_staff staff on user.staff_id = staff.id ");
sqlBuilder.append(" left join m_appuser appuser on loan_txn.created_by = appuser.id ");
sqlBuilder.append(" left join m_staff staff on appuser.staff_id = staff.id ");
sqlBuilder.append(" left join m_cashiers c on c.staff_id = staff.id ");
sqlBuilder.append(" left join m_payment_detail payDetails on payDetails.id = loan_txn.payment_detail_id ");
sqlBuilder.append(" left join m_payment_type payType on payType.id = payDetails.payment_type_id ");
Expand Down Expand Up @@ -662,8 +664,8 @@ public String clientTxnSchema() {
" left join r_enum_value renum on cli_txn.transaction_type_enum = renum.enum_id AND renum.enum_name = 'client_transaction_type_enum' ");
sqlBuilder.append(" left join m_client cl on cli_txn.client_id = cl.id ");
sqlBuilder.append(" left join m_office o on cl.office_id = o.id ");
sqlBuilder.append(" left join m_appuser user on cli_txn.created_by = user.id ");
sqlBuilder.append(" left join m_staff staff on user.staff_id = staff.id ");
sqlBuilder.append(" left join m_appuser appuser on cli_txn.created_by = appuser.id ");
sqlBuilder.append(" left join m_staff staff on appuser.staff_id = staff.id ");
sqlBuilder.append(" left join m_cashiers c on c.staff_id = staff.id ");
sqlBuilder.append(" left join m_payment_detail payDetails on payDetails.id = cli_txn.payment_detail_id ");
sqlBuilder.append(" left join m_payment_type payType on payType.id = payDetails.payment_type_id ");
Expand Down Expand Up @@ -707,7 +709,7 @@ public CashierTransactionData mapRow(final ResultSet rs, final int rowNum) throw

private static final class CashierTransactionSummaryMapper implements RowMapper<CashierTransactionTypeTotalsData> {

public String cashierTxnSummarySchema() {
public String cashierTxnSummarySchema(DatabaseSpecificSQLGenerator sqlGenerator) {

final StringBuilder sqlBuilder = new StringBuilder(400);

Expand All @@ -725,9 +727,11 @@ public String cashierTxnSummarySchema() {
sqlBuilder.append(" left join m_office o on o.id = t.office_id ");
sqlBuilder.append(" left join m_staff s on s.id = c.staff_id ");
sqlBuilder.append(" where txn.cashier_id = ? ");
sqlBuilder.append(" AND (( case when c.full_day then Date(txn.created_date) between c.start_date AND c.end_date ");
sqlBuilder.append(
" else ( Date(txn.created_date) between c.start_date AND c.end_date) and ( TIME(txn.created_date) between TIME(c.start_time) AND TIME(c.end_time)) end) or txn.txn_type = 101) ");
sqlBuilder.append(" AND (( case when c.full_day then " + sqlGenerator.castToDate("txn.created_date")
+ " between c.start_date AND c.end_date ");
sqlBuilder.append(" else ( " + sqlGenerator.castToDate("txn.created_date") + " between c.start_date AND c.end_date) and ( "
+ sqlGenerator.castToTime("txn.created_date") + " between " + sqlGenerator.castToTime("c.start_time") + " AND "
+ sqlGenerator.castToTime("c.end_time") + ") end) or txn.txn_type = 101) ");
sqlBuilder.append(" and txn.currency_code = ? ");
sqlBuilder.append(" and o.hierarchy like ? ) cashier_txns ");
sqlBuilder.append(" UNION ");
Expand All @@ -752,8 +756,8 @@ public String cashierTxnSummarySchema() {
sqlBuilder.append(" left join m_savings_account sav on sav_txn.savings_account_id = sav.id ");
sqlBuilder.append(" left join m_client cl on sav.client_id = cl.id ");
sqlBuilder.append(" left join m_office o on cl.office_id = o.id ");
sqlBuilder.append(" left join m_appuser user on sav_txn.appuser_id = user.id ");
sqlBuilder.append(" left join m_staff staff on user.staff_id = staff.id ");
sqlBuilder.append(" left join m_appuser appuser on sav_txn.created_by = appuser.id ");
sqlBuilder.append(" left join m_staff staff on appuser.staff_id = staff.id ");
sqlBuilder.append(" left join m_cashiers c on c.staff_id = staff.id ");
sqlBuilder.append(" left join m_payment_detail payDetails on payDetails.id = sav_txn.payment_detail_id ");
sqlBuilder.append(" left join m_payment_type payType on payType.id = payDetails.payment_type_id ");
Expand All @@ -763,7 +767,7 @@ public String cashierTxnSummarySchema() {
sqlBuilder.append(" where sav_txn.is_reversed = false and c.id = ? ");
sqlBuilder.append(" and sav.currency_code = ? ");
sqlBuilder.append(" and o.hierarchy like ? ");
sqlBuilder.append(" and sav_txn.transaction_date between c.start_date and date_add(c.end_date, interval 1 day) ");
sqlBuilder.append(" and sav_txn.transaction_date between c.start_date and " + sqlGenerator.addDate("c.end_date", 1, "day"));
sqlBuilder.append(" and (sav_txn.payment_detail_id IS NULL OR payType.is_cash_payment = true) ");
sqlBuilder.append(" AND acnttrans.id IS NULL ");
sqlBuilder.append(" ) ");
Expand Down Expand Up @@ -791,8 +795,8 @@ public String cashierTxnSummarySchema() {
sqlBuilder.append(" left join m_loan loan on loan_txn.loan_id = loan.id ");
sqlBuilder.append(" left join m_client cl on loan.client_id = cl.id ");
sqlBuilder.append(" left join m_office o on cl.office_id = o.id ");
sqlBuilder.append(" left join m_appuser user on loan_txn.created_by = user.id ");
sqlBuilder.append(" left join m_staff staff on user.staff_id = staff.id ");
sqlBuilder.append(" left join m_appuser appuser on loan_txn.created_by = appuser.id ");
sqlBuilder.append(" left join m_staff staff on appuser.staff_id = staff.id ");
sqlBuilder.append(" left join m_cashiers c on c.staff_id = staff.id ");
sqlBuilder.append(" left join m_payment_detail payDetails on payDetails.id = loan_txn.payment_detail_id ");
sqlBuilder.append(" left join m_payment_type payType on payType.id = payDetails.payment_type_id ");
Expand All @@ -802,7 +806,7 @@ public String cashierTxnSummarySchema() {
sqlBuilder.append(" where loan_txn.is_reversed = false and c.id = ? ");
sqlBuilder.append(" and loan.currency_code = ? ");
sqlBuilder.append(" and o.hierarchy like ? ");
sqlBuilder.append(" and loan_txn.transaction_date between c.start_date and date_add(c.end_date, interval 1 day) ");
sqlBuilder.append(" and loan_txn.transaction_date between c.start_date and " + sqlGenerator.addDate("c.end_date", 1, "day"));
sqlBuilder.append(" and (loan_txn.payment_detail_id IS NULL OR payType.is_cash_payment = true) ");
sqlBuilder.append(" AND acnttrans.id IS NULL ");
sqlBuilder.append(" ) ");
Expand All @@ -828,15 +832,15 @@ public String cashierTxnSummarySchema() {
" left join r_enum_value renum ON cli_txn.transaction_type_enum = renum.enum_id AND renum.enum_name = 'client_transaction_type_enum' ");
sqlBuilder.append(" left join m_client cl ON cli_txn.client_id = cl.id ");
sqlBuilder.append(" left join m_office o ON cl.office_id = o.id ");
sqlBuilder.append(" left join m_appuser user ON cli_txn.created_by = user.id ");
sqlBuilder.append(" left join m_staff staff ON user.staff_id = staff.id ");
sqlBuilder.append(" left join m_appuser appuser ON cli_txn.created_by = appuser.id ");
sqlBuilder.append(" left join m_staff staff ON appuser.staff_id = staff.id ");
sqlBuilder.append(" left join m_cashiers c ON c.staff_id = staff.id ");
sqlBuilder.append(" left join m_payment_detail payDetails on payDetails.id = cli_txn.payment_detail_id ");
sqlBuilder.append(" left join m_payment_type payType on payType.id = payDetails.payment_type_id ");
sqlBuilder.append(" where cli_txn.is_reversed = false AND c.id = ? ");
sqlBuilder.append(" and cli_txn.currency_code = ? ");
sqlBuilder.append(" and o.hierarchy LIKE ? ");
sqlBuilder.append(" and cli_txn.transaction_date between c.start_date and date_add(c.end_date, interval 1 day) ");
sqlBuilder.append(" and cli_txn.transaction_date between c.start_date and " + sqlGenerator.addDate("c.end_date", 1, "day"));
sqlBuilder.append(" and (cli_txn.payment_detail_id IS NULL OR payType.is_cash_payment = true) ");
sqlBuilder.append(" ) ");
sqlBuilder.append(" ) txns ");
Expand Down
Loading