further sql fixes
This commit is contained in:
parent
b1d46c1057
commit
e53f865210
5 changed files with 41 additions and 22 deletions
|
|
@ -412,7 +412,11 @@ public class NodeRepository {
|
||||||
(%s) <= ?
|
(%s) <= ?
|
||||||
""", dialectProvider.getBooleanFalse(), haversineFormula);
|
""", dialectProvider.getBooleanFalse(), haversineFormula);
|
||||||
|
|
||||||
return jdbcTemplate.query(query, new NodeMapper(), node.getGeoLat(), node.getGeoLng(), regionRadius);
|
return jdbcTemplate.query(query, new NodeMapper(),
|
||||||
|
node.getGeoLat(), // for COS(RADIANS(?))
|
||||||
|
node.getGeoLng(), // for COS(RADIANS(?) - RADIANS(geo_lng))
|
||||||
|
node.getGeoLat(), // for SIN(RADIANS(?))
|
||||||
|
regionRadius); // for <= ?
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|
||||||
|
|
@ -422,7 +426,12 @@ public class NodeRepository {
|
||||||
(%s) <= ?
|
(%s) <= ?
|
||||||
""", dialectProvider.getBooleanFalse(), haversineFormula);
|
""", dialectProvider.getBooleanFalse(), haversineFormula);
|
||||||
|
|
||||||
return jdbcTemplate.query(query, new NodeMapper(), node.getId(), node.getGeoLat(), node.getGeoLng(), regionRadius);
|
return jdbcTemplate.query(query, new NodeMapper(),
|
||||||
|
node.getId(), // for id != ?
|
||||||
|
node.getGeoLat(), // for COS(RADIANS(?))
|
||||||
|
node.getGeoLng(), // for COS(RADIANS(?) - RADIANS(geo_lng))
|
||||||
|
node.getGeoLat(), // for SIN(RADIANS(?))
|
||||||
|
regionRadius); // for <= ?
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|
||||||
|
|
@ -468,7 +477,7 @@ public class NodeRepository {
|
||||||
|
|
||||||
public Optional<Node> getByDestinationId(Integer id) {
|
public Optional<Node> getByDestinationId(Integer id) {
|
||||||
|
|
||||||
String query = "SELECT node.* FROM node INNER JOIN premise_destination WHERE node.id = premise_destination.destination_node_id AND premise_destination.id = ?";
|
String query = "SELECT node.* FROM node INNER JOIN premise_destination ON node.id = premise_destination.destination_node_id WHERE premise_destination.id = ?";
|
||||||
|
|
||||||
var node = jdbcTemplate.query(query, new NodeMapper(), id);
|
var node = jdbcTemplate.query(query, new NodeMapper(), id);
|
||||||
|
|
||||||
|
|
|
||||||
|
|
@ -23,7 +23,7 @@ public class NomenclatureRepository {
|
||||||
public List<String> searchHsCode(String search) {
|
public List<String> searchHsCode(String search) {
|
||||||
String concatExpression = dialectProvider.buildConcat("?", "'%'");
|
String concatExpression = dialectProvider.buildConcat("?", "'%'");
|
||||||
String sql = String.format(
|
String sql = String.format(
|
||||||
"SELECT hs_code FROM nomenclature WHERE hs_code LIKE %s %s",
|
"SELECT hs_code FROM nomenclature WHERE hs_code LIKE %s ORDER BY hs_code %s",
|
||||||
concatExpression,
|
concatExpression,
|
||||||
dialectProvider.buildPaginationClause(10, 0)
|
dialectProvider.buildPaginationClause(10, 0)
|
||||||
);
|
);
|
||||||
|
|
|
||||||
|
|
@ -37,10 +37,10 @@ public class BulkOperationRepository {
|
||||||
|
|
||||||
removeOld(operation.getUserId());
|
removeOld(operation.getUserId());
|
||||||
|
|
||||||
String sql = """
|
String sql = String.format("""
|
||||||
INSERT INTO bulk_operation (user_id, bulk_file_type, bulk_processing_type, state, file, validity_period_id)
|
INSERT INTO bulk_operation (user_id, bulk_file_type, bulk_processing_type, state, %s, validity_period_id)
|
||||||
VALUES (?, ?, ?, ?, ?, ?)
|
VALUES (?, ?, ?, ?, ?, ?)
|
||||||
""";
|
""", dialectProvider.escapeIdentifier("file"));
|
||||||
|
|
||||||
GeneratedKeyHolder keyHolder = new GeneratedKeyHolder();
|
GeneratedKeyHolder keyHolder = new GeneratedKeyHolder();
|
||||||
|
|
||||||
|
|
@ -158,11 +158,11 @@ public class BulkOperationRepository {
|
||||||
|
|
||||||
@Transactional
|
@Transactional
|
||||||
public Optional<BulkOperation> getOperationById(Integer id) {
|
public Optional<BulkOperation> getOperationById(Integer id) {
|
||||||
String sql = """
|
String sql = String.format("""
|
||||||
SELECT id, user_id, bulk_file_type, bulk_processing_type, state, file, created_at, validity_period_id
|
SELECT id, user_id, bulk_file_type, bulk_processing_type, state, %s, created_at, validity_period_id
|
||||||
FROM bulk_operation
|
FROM bulk_operation
|
||||||
WHERE id = ?
|
WHERE id = ?
|
||||||
""";
|
""", dialectProvider.escapeIdentifier("file"));
|
||||||
|
|
||||||
List<BulkOperation> results = jdbcTemplate.query(sql, new BulkOperationRowMapper(false), id);
|
List<BulkOperation> results = jdbcTemplate.query(sql, new BulkOperationRowMapper(false), id);
|
||||||
|
|
||||||
|
|
@ -171,11 +171,11 @@ public class BulkOperationRepository {
|
||||||
|
|
||||||
@Transactional
|
@Transactional
|
||||||
public void update(BulkOperation op) {
|
public void update(BulkOperation op) {
|
||||||
String sql = """
|
String sql = String.format("""
|
||||||
UPDATE bulk_operation
|
UPDATE bulk_operation
|
||||||
SET user_id = ?, bulk_file_type = ?, state = ?, file = ?, validity_period_id = ?
|
SET user_id = ?, bulk_file_type = ?, state = ?, %s = ?, validity_period_id = ?
|
||||||
WHERE id = ?
|
WHERE id = ?
|
||||||
""";
|
""", dialectProvider.escapeIdentifier("file"));
|
||||||
|
|
||||||
jdbcTemplate.update(sql,
|
jdbcTemplate.update(sql,
|
||||||
op.getUserId(),
|
op.getUserId(),
|
||||||
|
|
|
||||||
|
|
@ -251,15 +251,16 @@ public class ContainerRateRepository {
|
||||||
@Transactional
|
@Transactional
|
||||||
public boolean hasMainRun(Integer nodeId) {
|
public boolean hasMainRun(Integer nodeId) {
|
||||||
String query = """
|
String query = """
|
||||||
SELECT EXISTS(
|
SELECT CASE WHEN EXISTS(
|
||||||
SELECT 1 FROM container_rate
|
SELECT 1 FROM container_rate
|
||||||
WHERE (from_node_id = ? OR to_node_id = ?)
|
WHERE (from_node_id = ? OR to_node_id = ?)
|
||||||
AND (container_rate_type = ? OR container_rate_type = ?)
|
AND (container_rate_type = ? OR container_rate_type = ?)
|
||||||
)
|
) THEN 1 ELSE 0 END
|
||||||
""";
|
""";
|
||||||
|
|
||||||
return Boolean.TRUE.equals(jdbcTemplate.queryForObject(query, Boolean.class,
|
Integer result = jdbcTemplate.queryForObject(query, Integer.class,
|
||||||
nodeId, nodeId, TransportType.SEA.name(), TransportType.RAIL.name()));
|
nodeId, nodeId, TransportType.SEA.name(), TransportType.RAIL.name());
|
||||||
|
return result != null && result > 0;
|
||||||
}
|
}
|
||||||
|
|
||||||
@Transactional
|
@Transactional
|
||||||
|
|
|
||||||
|
|
@ -49,6 +49,7 @@ public class UserNodeRepository {
|
||||||
queryBuilder.append(" AND is_deprecated = ").append(dialectProvider.getBooleanFalse());
|
queryBuilder.append(" AND is_deprecated = ").append(dialectProvider.getBooleanFalse());
|
||||||
}
|
}
|
||||||
|
|
||||||
|
queryBuilder.append(" ORDER BY id");
|
||||||
queryBuilder.append(" ").append(dialectProvider.buildPaginationClause(limit, 0));
|
queryBuilder.append(" ").append(dialectProvider.buildPaginationClause(limit, 0));
|
||||||
|
|
||||||
Object[] paginationParams = dialectProvider.getPaginationParameters(limit, 0);
|
Object[] paginationParams = dialectProvider.getPaginationParameters(limit, 0);
|
||||||
|
|
@ -145,11 +146,19 @@ public class UserNodeRepository {
|
||||||
|
|
||||||
@Transactional
|
@Transactional
|
||||||
public void checkOwner(List<Integer> userNodeIds, Integer userId) {
|
public void checkOwner(List<Integer> userNodeIds, Integer userId) {
|
||||||
String query = """
|
if (userNodeIds.isEmpty()) {
|
||||||
SELECT id FROM sys_user_node WHERE id IN (?) AND user_id <> ?
|
return;
|
||||||
""";
|
}
|
||||||
|
|
||||||
var otherIds = jdbcTemplate.queryForList(query, Integer.class, userNodeIds, userId);
|
String placeholders = String.join(",", Collections.nCopies(userNodeIds.size(), "?"));
|
||||||
|
String query = """
|
||||||
|
SELECT id FROM sys_user_node WHERE id IN (""" + placeholders + ") AND user_id <> ?";
|
||||||
|
|
||||||
|
// Combine userNodeIds and userId into a single parameter array
|
||||||
|
List<Object> params = new ArrayList<>(userNodeIds);
|
||||||
|
params.add(userId);
|
||||||
|
|
||||||
|
var otherIds = jdbcTemplate.queryForList(query, Integer.class, params.toArray());
|
||||||
|
|
||||||
if(!otherIds.isEmpty()) {
|
if(!otherIds.isEmpty()) {
|
||||||
throw new ForbiddenException("Access violation. Cannot open user nodes with ids = " + otherIds);
|
throw new ForbiddenException("Access violation. Cannot open user nodes with ids = " + otherIds);
|
||||||
|
|
|
||||||
Loading…
Add table
Reference in a new issue