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

Use prepared statements instead of string concatenated SQL everywhere - PART 1 (FINERACT-854) #1671

Merged
merged 11 commits into from
Apr 12, 2021
Merged
Show file tree
Hide file tree
Changes from 10 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 @@ -57,28 +57,27 @@ public ProvisioningEntriesReadPlatformServiceImpl(final RoutingDataSource dataSo
@Override
public Collection<LoanProductProvisioningEntryData> retrieveLoanProductsProvisioningData(Date date) {
String formattedDate = new SimpleDateFormat("yyyy-MM-dd").format(date);
formattedDate = "'" + formattedDate + "'";
LoanProductProvisioningEntryMapper mapper = new LoanProductProvisioningEntryMapper(formattedDate);
LoanProductProvisioningEntryMapper mapper = new LoanProductProvisioningEntryMapper();
final String sql = mapper.schema();
return this.jdbcTemplate.query(sql, mapper, new Object[] {});
return this.jdbcTemplate.query(sql, mapper, new Object[] { formattedDate, formattedDate, formattedDate });
}

private static final class LoanProductProvisioningEntryMapper implements RowMapper<LoanProductProvisioningEntryData> {

private final StringBuilder sqlQuery;

private LoanProductProvisioningEntryMapper(String formattedDate) {
private LoanProductProvisioningEntryMapper() {
sqlQuery = new StringBuilder().append(
"select if(loan.loan_type_enum=1, mclient.office_id, mgroup.office_id) as office_id, loan.loan_type_enum, pcd.criteria_id as criteriaid, loan.product_id,loan.currency_code,")
.append("GREATEST(datediff(").append(formattedDate)
.append("GREATEST(datediff(?")
.append(",sch.duedate),0) as numberofdaysoverdue,sch.duedate, pcd.category_id, pcd.provision_percentage,")
.append("loan.total_outstanding_derived as outstandingbalance, pcd.liability_account, pcd.expense_account from m_loan_repayment_schedule sch")
.append(" LEFT JOIN m_loan loan on sch.loan_id = loan.id")
.append(" JOIN m_loanproduct_provisioning_mapping lpm on lpm.product_id = loan.product_id")
.append(" JOIN m_provisioning_criteria_definition pcd on pcd.criteria_id = lpm.criteria_id and ")
.append("(pcd.min_age <= GREATEST(datediff(").append(formattedDate).append(",sch.duedate),0) and ")
.append("GREATEST(datediff(").append(formattedDate).append(",sch.duedate),0) <= pcd.max_age) and ")
.append("pcd.criteria_id is not null ").append("LEFT JOIN m_client mclient ON mclient.id = loan.client_id ")
.append("(pcd.min_age <= GREATEST(datediff(?").append(",sch.duedate),0) and ").append("GREATEST(datediff(?")
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Suggested change
.append("(pcd.min_age <= GREATEST(datediff(?").append(",sch.duedate),0) and ").append("GREATEST(datediff(?")
.append("(pcd.min_age <= GREATEST(datediff(?,sch.duedate),0) and GREATEST(datediff(?")

Copy link
Contributor Author

@josemakara2 josemakara2 Apr 12, 2021

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Thank you Petri.
😇
It wasn't in first review but if it improves the code base why not 🙂. Will add fix tonight when I get to my laptop with this project.

There are other things there which I didn't bother with initially but can improve readability. No change to functionality but helps understand things.
Prefer

  • lowerCamel case for SQL functions, and uppercase for other keywords
  • lowerCamel case for column names - dueDate not duedate
  • Only break line if it violates 120 character line limit in the FINERACT eclipse formatter
  • StringBuilder only if it is a conditional query, with if conditions, otherwise just a single query as below suffice.

Simply return

        public String schema() {
            return "" + 
                    "SELECT if(" + 
                    "    loan.loan_type_enum = 1, mclient.office_id, mgroup.office_id" + 
                    "  ) AS office_id," + 
                    "  loan.loan_type_enum," + 
                    "  pcd.criteria_id AS criteriaid," + 
                    "  loan.product_id," + 
                    "  loan.currency_code," + 
                    "  greatest(dateDiff(?, sch.duedate), 0) AS numberofdaysoverdue," + 
                    "  sch.duedate," + 
                    "  pcd.category_id," + 
                    "  pcd.provision_percentage," + 
                    "  loan.total_outstanding_derived AS outstandingbalance," + 
                    "  pcd.liability_account," + 
                    "  pcd.expense_account " + 
                    "FROM m_loan_repayment_schedule sch " + 
                    "LEFT JOIN m_loan loan ON sch.loan_id = loan.id " + 
                    "INNER JOIN m_loanproduct_provisioning_mapping lpm ON lpm.product_id = loan.product_id " + 
                    "INNER JOIN m_provisioning_criteria_definition pcd " + 
                    "  ON pcd.criteria_id = lpm.criteria_id " + 
                    "  AND (" + 
                    "    pcd.min_age <= greatest(dateDiff(?, sch.duedate), 0) AND greatest(dateDiff(?, sch.duedate), 0) <= pcd.max_age" + 
                    "  )" + 
                    "  AND pcd.criteria_id IS NOT NULL" + 
                    "LEFT JOIN m_client mclient ON mclient.id = loan.client_id " + 
                    "LEFT JOIN m_group mgroup ON mgroup.id = loan.group_id " + 
                    "WHERE loan.loan_status_id = 300 AND sch.duedate = (" + 
                    "  SELECT min(sch1.duedate) " + 
                    "  FROM m_loan_repayment_schedule sch1 " + 
                    "  WHERE sch1.loan_id=loan.id AND sch1.completed_derived = FALSE" + 
                    ")";
        }

But fineractdevprojectformatter won't allows this 😬 and instead its formats is not SQL readable.
as opposed to

            sqlQuery = new StringBuilder().append(
                    "select if(loan.loan_type_enum=1, mclient.office_id, mgroup.office_id) as office_id, loan.loan_type_enum, pcd.criteria_id as criteriaid, loan.product_id,loan.currency_code,")
                    .append("GREATEST(datediff(?")
                    .append(",sch.duedate),0) as numberofdaysoverdue,sch.duedate, pcd.category_id, pcd.provision_percentage,")
                    .append("loan.total_outstanding_derived as outstandingbalance, pcd.liability_account, pcd.expense_account from m_loan_repayment_schedule sch")
                    .append(" LEFT JOIN m_loan loan on sch.loan_id = loan.id")
                    .append(" JOIN m_loanproduct_provisioning_mapping lpm on lpm.product_id = loan.product_id")
                    .append(" JOIN m_provisioning_criteria_definition pcd on pcd.criteria_id = lpm.criteria_id and ")
                    .append("(pcd.min_age <= GREATEST(datediff(?,sch.duedate),0) and GREATEST(datediff(?")
                    .append(",sch.duedate),0) <= pcd.max_age) and ").append("pcd.criteria_id is not null ")
                    .append("LEFT JOIN m_client mclient ON mclient.id = loan.client_id ")
                    .append("LEFT JOIN m_group mgroup ON mgroup.id = loan.group_id ")
                    .append("where loan.loan_status_id=300 and sch.duedate = ")
                    .append("(select MIN(sch1.duedate) from m_loan_repayment_schedule sch1 where sch1.loan_id=loan.id and sch1.completed_derived=false)");

We can open a separate jira vote to fix formatter?

.append(",sch.duedate),0) <= pcd.max_age) and ").append("pcd.criteria_id is not null ")
ptuomola marked this conversation as resolved.
Show resolved Hide resolved
.append("LEFT JOIN m_client mclient ON mclient.id = loan.client_id ")
.append("LEFT JOIN m_group mgroup ON mgroup.id = loan.group_id ")
.append("where loan.loan_status_id=300 and sch.duedate = ")
.append("(select MIN(sch1.duedate) from m_loan_repayment_schedule sch1 where sch1.loan_id=loan.id and sch1.completed_derived=false)");
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -130,46 +130,41 @@ public EmailData retrieveOne(final Long resourceId) {
@Override
public Collection<EmailData> retrieveAllPending(final SearchParameters searchParameters) {
final String sqlPlusLimit = (searchParameters.getLimit() > 0) ? " limit 0, " + searchParameters.getLimit() : "";
final String sql = "select " + this.emailRowMapper.schema() + " where emo.status_enum = "
+ EmailMessageStatusType.PENDING.getValue() + sqlPlusLimit;
final String sql = "select " + this.emailRowMapper.schema() + " where emo.status_enum =? " + sqlPlusLimit;

return this.jdbcTemplate.query(sql, this.emailRowMapper, new Object[] {});
return this.jdbcTemplate.query(sql, this.emailRowMapper, EmailMessageStatusType.PENDING.getValue());
}

@Override
public Collection<EmailData> retrieveAllSent(final SearchParameters searchParameters) {
final String sqlPlusLimit = (searchParameters.getLimit() > 0) ? " limit 0, " + searchParameters.getLimit() : "";
final String sql = "select " + this.emailRowMapper.schema() + " where emo.status_enum = " + EmailMessageStatusType.SENT.getValue()
+ sqlPlusLimit;
final String sql = "select " + this.emailRowMapper.schema() + " where emo.status_enum = ?" + sqlPlusLimit;

return this.jdbcTemplate.query(sql, this.emailRowMapper, new Object[] {});
return this.jdbcTemplate.query(sql, this.emailRowMapper, EmailMessageStatusType.SENT.getValue());
}

@Override
public List<Long> retrieveExternalIdsOfAllSent(final Integer limit) {
final String sqlPlusLimit = (limit > 0) ? " limit 0, " + limit : "";
final String sql = "select external_id from " + this.emailRowMapper.tableName() + " where status_enum = "
+ EmailMessageStatusType.SENT.getValue() + sqlPlusLimit;
final String sql = "select external_id from " + this.emailRowMapper.tableName() + " where status_enum =? " + sqlPlusLimit;

return this.jdbcTemplate.queryForList(sql, Long.class);
return this.jdbcTemplate.queryForList(sql, Long.class, EmailMessageStatusType.SENT.getValue());
}

@Override
public Collection<EmailData> retrieveAllDelivered(final Integer limit) {
final String sqlPlusLimit = (limit > 0) ? " limit 0, " + limit : "";
final String sql = "select " + this.emailRowMapper.schema() + " where emo.status_enum = "
+ EmailMessageStatusType.DELIVERED.getValue() + sqlPlusLimit;
final String sql = "select " + this.emailRowMapper.schema() + " where emo.status_enum = ?" + sqlPlusLimit;

return this.jdbcTemplate.query(sql, this.emailRowMapper, new Object[] {});
return this.jdbcTemplate.query(sql, this.emailRowMapper, EmailMessageStatusType.DELIVERED.getValue());
}

@Override
public Collection<EmailData> retrieveAllFailed(final SearchParameters searchParameters) {
final String sqlPlusLimit = (searchParameters.getLimit() > 0) ? " limit 0, " + searchParameters.getLimit() : "";
final String sql = "select " + this.emailRowMapper.schema() + " where emo.status_enum = " + EmailMessageStatusType.FAILED.getValue()
+ sqlPlusLimit;
final String sql = "select " + this.emailRowMapper.schema() + " where emo.status_enum = ?" + sqlPlusLimit;

return this.jdbcTemplate.query(sql, this.emailRowMapper, new Object[] {});
return this.jdbcTemplate.query(sql, this.emailRowMapper, EmailMessageStatusType.FAILED.getValue());
}

@Override
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -56,12 +56,13 @@ public GlobalConfigurationData retrieveGlobalConfiguration(final boolean survey)

if (survey) {
sql += " JOIN x_registered_table on x_registered_table.registered_table_name = c.name ";
sql += " WHERE x_registered_table.category =" + DataTableApiConstant.CATEGORY_PPI;
sql += " WHERE x_registered_table.category = ?";

}

sql += " order by c.id";
final List<GlobalConfigurationPropertyData> globalConfiguration = this.jdbcTemplate.query(sql, this.rm, new Object[] {});
final List<GlobalConfigurationPropertyData> globalConfiguration = this.jdbcTemplate.query(sql, this.rm,
survey ? new Object[] { DataTableApiConstant.CATEGORY_PPI } : new Object[] {});

return new GlobalConfigurationData(globalConfiguration);
}
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -38,7 +38,6 @@
import java.util.Set;
import javax.sql.DataSource;
import javax.ws.rs.core.StreamingOutput;
import org.apache.commons.lang3.StringUtils;
import org.apache.fineract.infrastructure.core.domain.JdbcSupport;
import org.apache.fineract.infrastructure.core.exception.PlatformDataIntegrityException;
import org.apache.fineract.infrastructure.core.service.RoutingDataSource;
Expand All @@ -51,8 +50,6 @@
import org.apache.fineract.infrastructure.dataqueries.exception.ReportNotFoundException;
import org.apache.fineract.infrastructure.documentmanagement.contentrepository.FileSystemContentRepository;
import org.apache.fineract.infrastructure.security.service.PlatformSecurityContext;
import org.apache.fineract.infrastructure.security.utils.ColumnValidator;
import org.apache.fineract.infrastructure.security.utils.SQLInjectionException;
import org.apache.fineract.useradministration.domain.AppUser;
import org.slf4j.Logger;
import org.slf4j.LoggerFactory;
Expand All @@ -66,22 +63,19 @@
public class ReadReportingServiceImpl implements ReadReportingService {

private static final Logger LOG = LoggerFactory.getLogger(ReadReportingServiceImpl.class);
private static final String REPORT_NAME_REGEX_PATTERN = "^[a-zA-Z][a-zA-Z0-9\\-_\\s]{0,48}[a-zA-Z0-9\\s](\\([a-zA-Z]*\\))?$";

private final JdbcTemplate jdbcTemplate;
private final DataSource dataSource;
private final PlatformSecurityContext context;
private final GenericDataService genericDataService;
private final ColumnValidator columnValidator;

@Autowired
public ReadReportingServiceImpl(final PlatformSecurityContext context, final RoutingDataSource dataSource,
final GenericDataService genericDataService, final ColumnValidator columnValidator) {
final GenericDataService genericDataService) {
this.context = context;
this.dataSource = dataSource;
this.jdbcTemplate = new JdbcTemplate(this.dataSource);
this.genericDataService = genericDataService;
this.columnValidator = columnValidator;
}

@Override
Expand Down Expand Up @@ -204,13 +198,12 @@ private String getSQLtoRun(final String name, final String type, final Map<Strin
}

private String getSql(final String name, final String type) {
final String inputSql = "select " + type + "_sql as the_sql from stretchy_" + type + " where " + type + "_name = '" + name + "'";
validateReportName(name);
final String inputSql = "select " + type + "_sql as the_sql from stretchy_" + type + " where " + type + "_name = ?";

final String inputSqlWrapped = this.genericDataService.wrapSQL(inputSql);

// the return statement contains the exact sql required
final SqlRowSet rs = this.jdbcTemplate.queryForRowSet(inputSqlWrapped);
final SqlRowSet rs = this.jdbcTemplate.queryForRowSet(inputSqlWrapped, name);

if (rs.next() && rs.getString("the_sql") != null) {
return rs.getString("the_sql");
Expand All @@ -220,14 +213,11 @@ private String getSql(final String name, final String type) {

@Override
public String getReportType(final String reportName, final boolean isSelfServiceUserReport) {
final String sql = "SELECT ifnull(report_type,'') as report_type FROM `stretchy_report` where report_name = '" + reportName
+ "' and self_service_user_report = ?";
validateReportName(reportName);
this.columnValidator.validateSqlInjection(sql, reportName);
final String sql = "SELECT ifNull(report_type,'') AS report_type FROM `stretchy_report` WHERE report_name = ? AND self_service_user_report = ?";

final String sqlWrapped = this.genericDataService.wrapSQL(sql);

final SqlRowSet rs = this.jdbcTemplate.queryForRowSet(sqlWrapped, isSelfServiceUserReport);
final SqlRowSet rs = this.jdbcTemplate.queryForRowSet(sqlWrapped, reportName, isSelfServiceUserReport);

if (rs.next()) {
return rs.getString("report_type");
Expand Down Expand Up @@ -323,7 +313,8 @@ private Collection<ReportData> retrieveReports(final Long id) {

final String sql = rm.schema(id);

final Collection<ReportParameterJoinData> rpJoins = this.jdbcTemplate.query(sql, rm);
final Collection<ReportParameterJoinData> rpJoins = this.jdbcTemplate.query(sql, rm,
id != null ? new Object[] { id } : new Object[] {});

final Collection<ReportData> reportList = new ArrayList<>();
if (rpJoins == null || rpJoins.size() == 0) {
Expand Down Expand Up @@ -416,7 +407,7 @@ public String schema(final Long reportId) {
sql += " from stretchy_report r" + " left join stretchy_report_parameter rp on rp.report_id = r.id"
+ " left join stretchy_parameter p on p.id = rp.parameter_id";
if (reportId != null) {
sql += " where r.id = " + reportId;
sql += " where r.id = ?";
} else {
sql += " order by r.id, rp.parameter_id";
}
Expand Down Expand Up @@ -498,7 +489,6 @@ private String sqlToRunForSmsEmailCampaign(final String name, final String type,
final Set<String> keys = queryParams.keySet();
for (String key : keys) {
final String pValue = queryParams.get(key);
// LOG.info("(" + key + " : " + pValue + ")");
key = "${" + key + "}";
sql = this.genericDataService.replace(sql, key, pValue);
}
Expand Down Expand Up @@ -568,10 +558,4 @@ public ByteArrayOutputStream generatePentahoReportAsOutputStream(final String re
*/
return null;
}

private void validateReportName(final String name) {
if (!StringUtils.isBlank(name) && !name.matches(REPORT_NAME_REGEX_PATTERN)) {
throw new SQLInjectionException();
}
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -138,7 +138,7 @@ public FineractPlatformTenant loadTenantById(final String tenantIdentifier, fina

try {
final TenantMapper rm = new TenantMapper(isReport);
final String sql = "select " + rm.schema() + " where t.identifier like ?";
final String sql = "select " + rm.schema() + " where t.identifier = ?";

return this.jdbcTemplate.queryForObject(sql, rm, new Object[] { tenantIdentifier });
} catch (final EmptyResultDataAccessException e) {
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -131,7 +131,7 @@ public FineractPlatformTenant loadTenantById(final String tenantIdentifier) {

try {
final TenantMapper rm = new TenantMapper();
final String sql = "select " + rm.schema() + " where t.identifier like ?";
final String sql = "select " + rm.schema() + " where t.identifier = ?";

return this.jdbcTemplate.queryForObject(sql, rm, new Object[] { tenantIdentifier });
} catch (final EmptyResultDataAccessException e) {
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
--
-- Licensed to the Apache Software Foundation (ASF) under one
-- or more contributor license agreements. See the NOTICE file
-- distributed with this work for additional information
-- regarding copyright ownership. The ASF licenses this file
-- to you under the Apache License, Version 2.0 (the
-- "License"); you may not use this file except in compliance
-- with the License. You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing,
-- software distributed under the License is distributed on an
-- "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
-- KIND, either express or implied. See the License for the
-- specific language governing permissions and limitations
-- under the License.
--

ALTER TABLE tenants ADD UNIQUE (identifier);