|
|
@ -0,0 +1,845 @@ |
|
|
|
package jumapacelaya.gob.mx.appmovcom.servicio; |
|
|
|
|
|
|
|
import io.micronaut.transaction.annotation.ReadOnly; |
|
|
|
import io.micronaut.transaction.annotation.Transactional; |
|
|
|
import jakarta.inject.Singleton; |
|
|
|
import jumapacelaya.gob.mx.appmovcom.dto.adeudoDTO; |
|
|
|
import jumapacelaya.gob.mx.appmovcom.dto.adeudoTotalDTO; |
|
|
|
import jumapacelaya.gob.mx.appmovcom.dto.asociarServicioDTO; |
|
|
|
import jumapacelaya.gob.mx.appmovcom.dto.autentificaDTO; |
|
|
|
import jumapacelaya.gob.mx.appmovcom.dto.referenciaDTO; |
|
|
|
import jumapacelaya.gob.mx.appmovcom.dto.historialConsumoDTO; |
|
|
|
import jumapacelaya.gob.mx.appmovcom.dto.mostrarServicioRequest; |
|
|
|
import jumapacelaya.gob.mx.appmovcom.dto.predioInfoDTO; |
|
|
|
import jumapacelaya.gob.mx.appmovcom.dto.servicioAsociadoDTO; |
|
|
|
import oracle.jdbc.OraclePreparedStatement; |
|
|
|
|
|
|
|
import javax.sql.DataSource; |
|
|
|
|
|
|
|
import java.math.BigDecimal; |
|
|
|
import java.math.RoundingMode; |
|
|
|
import java.sql.CallableStatement; |
|
|
|
import java.sql.Connection; |
|
|
|
import java.sql.PreparedStatement; |
|
|
|
import java.sql.ResultSet; |
|
|
|
import java.sql.SQLException; |
|
|
|
import java.sql.Statement; |
|
|
|
import java.sql.Timestamp; |
|
|
|
import java.text.SimpleDateFormat; |
|
|
|
import java.time.LocalDateTime; |
|
|
|
import java.time.format.DateTimeFormatter; |
|
|
|
import java.util.ArrayList; |
|
|
|
import java.util.Collections; |
|
|
|
import java.util.Date; |
|
|
|
import java.util.HashMap; |
|
|
|
import java.util.List; |
|
|
|
import java.util.Map; |
|
|
|
|
|
|
|
@Singleton |
|
|
|
public class AppMovComServicio { |
|
|
|
|
|
|
|
private final DataSource dataSource; |
|
|
|
|
|
|
|
public AppMovComServicio(DataSource dataSource) { |
|
|
|
this.dataSource = dataSource; |
|
|
|
} |
|
|
|
|
|
|
|
@ReadOnly |
|
|
|
public referenciaDTO validarReferencia(String referencia) { |
|
|
|
String sql = """ |
|
|
|
SELECT DECODE(COUNT(*), 1, 'TRUE', 'FALSE') AS VALIDACION |
|
|
|
FROM facturacomenc |
|
|
|
WHERE predioid = SUBSTR(?, 22, 8) |
|
|
|
AND faccomencid = SUBSTR(?, 5, 8) |
|
|
|
"""; |
|
|
|
|
|
|
|
boolean validacion = false; |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setString(1, referencia); |
|
|
|
stmt.setString(2, referencia); |
|
|
|
|
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
if (rs.next()) { |
|
|
|
validacion = "TRUE".equalsIgnoreCase(rs.getString("VALIDACION")); |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al validar la referencia: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return new referenciaDTO(referencia, validacion); |
|
|
|
} |
|
|
|
|
|
|
|
@ReadOnly |
|
|
|
public List<historialConsumoDTO> obtenerHistorialConsumo(Long predioid, Integer numperiodos) { |
|
|
|
String sql = """ |
|
|
|
SELECT periodoid, fechalec, metodo, observacion, lectura, consumo, fechafac, fechavcto, importe |
|
|
|
FROM ( |
|
|
|
SELECT |
|
|
|
periodoid, |
|
|
|
TO_CHAR(TRUNC(fechalec), 'dd/mm/yyyy') AS fechalec, |
|
|
|
metodo, |
|
|
|
NVL(ol.nombre, 'Sin Observacion') AS observacion, |
|
|
|
NVL(lectura, 0) AS lectura, |
|
|
|
NVL(consfact, 0) AS consumo, |
|
|
|
NVL(TO_CHAR(TRUNC(fechafac), 'dd/mm/yyyy'), 'Sin Fecha') AS fechafac, |
|
|
|
NVL(TO_CHAR(TRUNC(fechavcto), 'dd/mm/yyyy'), 'Sin Fecha') AS fechavcto, |
|
|
|
NVL(total_real, 0) AS importe, |
|
|
|
RANK() OVER (PARTITION BY predioid ORDER BY periodoid DESC) AS orden |
|
|
|
FROM facturacomenc fe |
|
|
|
LEFT JOIN observalect ol USING (obslectid) |
|
|
|
WHERE predioid = ? |
|
|
|
AND fechafac IS NOT NULL |
|
|
|
AND factsust IS NULL |
|
|
|
) |
|
|
|
WHERE (? IS NULL OR orden <= ?) |
|
|
|
"""; |
|
|
|
|
|
|
|
List<historialConsumoDTO> resultados = new ArrayList<>(); |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setLong(1, predioid); |
|
|
|
stmt.setObject(2, numperiodos); |
|
|
|
stmt.setObject(3, numperiodos); |
|
|
|
|
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
while (rs.next()) { |
|
|
|
historialConsumoDTO dto = new historialConsumoDTO(); |
|
|
|
dto.setPeriodo(rs.getString("periodoid")); |
|
|
|
dto.setFechalec(rs.getString("fechalec")); |
|
|
|
dto.setMetodo(rs.getString("metodo")); |
|
|
|
dto.setObservacion(rs.getString("observacion")); |
|
|
|
dto.setLectura(rs.getInt("lectura")); |
|
|
|
dto.setConsumo(rs.getInt("consumo")); |
|
|
|
dto.setFechafac(rs.getString("fechafac")); |
|
|
|
dto.setFechavcto(rs.getString("fechavcto")); |
|
|
|
dto.setImporte(rs.getBigDecimal("importe")); |
|
|
|
|
|
|
|
resultados.add(dto); |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al obtener historial de consumo: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return resultados; |
|
|
|
} |
|
|
|
|
|
|
|
@ReadOnly |
|
|
|
public List<servicioAsociadoDTO> obtenerServiciosAsociados(String usuarioid) { |
|
|
|
/*boolean coincide = credenciales.stream() |
|
|
|
.anyMatch(c -> c.getUsr().trim().equalsIgnoreCase(usuarioid.trim())); |
|
|
|
|
|
|
|
if (!coincide) { |
|
|
|
throw new RuntimeException("No se pudo validar el usuario: " + usuarioid); |
|
|
|
}*/ |
|
|
|
|
|
|
|
String sql = """ |
|
|
|
SELECT usuarioid, predioid, s.clienteid, s.contrato, mostrar, favorito, |
|
|
|
fn_get_direccion(p.direcid) AS direccionmostrar |
|
|
|
FROM appmovcom.usuarios_servicios s |
|
|
|
LEFT JOIN predios p USING (predioid) |
|
|
|
WHERE TRIM(usuarioid) = TRIM(?) AND mostrar = 'S' |
|
|
|
ORDER BY favorito DESC, predioid ASC, s.clienteid ASC |
|
|
|
"""; |
|
|
|
|
|
|
|
List<servicioAsociadoDTO> resultados = new ArrayList<>(); |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setString(1, usuarioid); |
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
|
|
|
|
while (rs.next()) { |
|
|
|
servicioAsociadoDTO dto = new servicioAsociadoDTO(); |
|
|
|
dto.setUsuarioid(rs.getString("usuarioid")); |
|
|
|
dto.setPredioid(rs.getLong("predioid")); |
|
|
|
dto.setClienteid(rs.getLong("clienteid")); |
|
|
|
dto.setContrato(rs.getString("contrato")); |
|
|
|
dto.setMostrar(rs.getString("mostrar")); |
|
|
|
dto.setFavorito(rs.getString("favorito")); |
|
|
|
dto.setDireccionmostrar(rs.getString("direccionmostrar")); |
|
|
|
resultados.add(dto); |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al obtener servicios asociados: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return resultados; |
|
|
|
} |
|
|
|
|
|
|
|
@ReadOnly |
|
|
|
public autentificaDTO autenticarUsuario(String usr, String pswd) { |
|
|
|
String query = """ |
|
|
|
select * from |
|
|
|
( |
|
|
|
select validausuario, usuarioid, nivel, email, nombre, fechora, rank() over (order by fechora) orden |
|
|
|
from |
|
|
|
( |
|
|
|
select appmovcom.pk_vigilante.fn_validausuario(?, ?, ?) validausuario, |
|
|
|
usuarioid, nivel, email, nombre, fechora |
|
|
|
from appmovcom.usuarios |
|
|
|
left join appmovcom.usuarios_seguridad using (usuarioid) |
|
|
|
where trim(usuarioid)=trim(?) |
|
|
|
union all |
|
|
|
select 'N', ?, null, null, 'No se encontró el Usuario ' || ?, null from dual |
|
|
|
) |
|
|
|
) |
|
|
|
where orden=1 |
|
|
|
"""; |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn. prepareStatement(query)) { |
|
|
|
|
|
|
|
stmt.setString(1, usr); |
|
|
|
stmt.setString(2, pswd); |
|
|
|
stmt.setString(3, usr); |
|
|
|
stmt.setString(4, usr); |
|
|
|
stmt.setString(5, usr); |
|
|
|
stmt.setString(6, usr); |
|
|
|
|
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
|
|
|
|
if (rs.next()) { |
|
|
|
autentificaDTO response = new autentificaDTO(); |
|
|
|
response.setValidausuario(rs.getString("validausuario")); |
|
|
|
response.setUsuarioid(rs.getString("usuarioid")); |
|
|
|
response.setNivel(rs.getString("nivel")); |
|
|
|
response.setEmail(rs.getString("email")); |
|
|
|
response.setNombre(rs.getString("nombre")); |
|
|
|
Timestamp timestamp = rs.getTimestamp("fechora"); |
|
|
|
response.setFechora(timestamp != null ? timestamp.toLocalDateTime() : null); |
|
|
|
return response; |
|
|
|
} else { |
|
|
|
throw new RuntimeException("No se pudo autenticar al usuario"); |
|
|
|
} |
|
|
|
} catch (SQLException e) { |
|
|
|
throw new RuntimeException("Error en auntenticación: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
} |
|
|
|
|
|
|
|
@ReadOnly |
|
|
|
public List<predioInfoDTO> getPredioInfo(Long predioid) { |
|
|
|
String sql = """ |
|
|
|
SELECT usuarioid, predioid, contrato, mostrar |
|
|
|
FROM appmovcom.usuarios_servicios |
|
|
|
WHERE predioid = ? |
|
|
|
"""; |
|
|
|
|
|
|
|
List<predioInfoDTO> resultados = new ArrayList<>(); |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setLong(1, predioid); |
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
|
|
|
|
while (rs.next()) { |
|
|
|
predioInfoDTO dto = new predioInfoDTO(); |
|
|
|
dto.setUsuarioid(rs.getString("usuarioid")); |
|
|
|
dto.setPredioid(rs.getLong("predioid")); |
|
|
|
dto.setContrato(rs.getString("contrato")); |
|
|
|
dto.setMostrar(rs.getString("mostrar")); |
|
|
|
resultados.add(dto); |
|
|
|
} |
|
|
|
|
|
|
|
} catch (SQLException e) { |
|
|
|
throw new RuntimeException("Error al obtener la información del predio: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return resultados; |
|
|
|
} |
|
|
|
|
|
|
|
@Transactional |
|
|
|
public Map<String, Object> mostrarServicio(String usuarioid, mostrarServicioRequest request) { |
|
|
|
String sql = "BEGIN appmovcom.pk_servicios.sp_actualizaservicio(?, ?, ?, ?, 'S'); END;"; |
|
|
|
Map<String, Object> respuesta = new HashMap<>(); |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setString(1, usuarioid); |
|
|
|
stmt.setLong(2, request.getPredioid()); |
|
|
|
stmt.setLong(3, request.getClienteid()); |
|
|
|
stmt.setString(4, request.getContrato()); |
|
|
|
|
|
|
|
stmt.execute(); |
|
|
|
|
|
|
|
respuesta.put("status", "200"); |
|
|
|
respuesta.put("message", "Servicio visible: " + usuarioid); |
|
|
|
respuesta.put("data", request.getPredioid() + " predio visible, ya lo podrás visualizar en el Dashboard."); |
|
|
|
|
|
|
|
} catch (SQLException e) { |
|
|
|
throw new RuntimeException("Error al actualizar visibilidad del servicio: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return respuesta; |
|
|
|
} |
|
|
|
|
|
|
|
@ReadOnly |
|
|
|
public List<adeudoDTO> obtenerAdeudo(Long predioid) { |
|
|
|
String query = """ |
|
|
|
select d.*, sum(adeudo) over(order by ordenid) total from |
|
|
|
( |
|
|
|
with ordenaplica as |
|
|
|
( |
|
|
|
select * from ordenconsultaadeudo where origenid='W' |
|
|
|
) |
|
|
|
select ordenid, descripcion descid, |
|
|
|
decode( |
|
|
|
descripcion, |
|
|
|
'CONVFV', 'Convenio Accesorios.', |
|
|
|
'CONVFM', 'Convenio Medidores.', |
|
|
|
'CONVFC', 'Convenio Servicios', |
|
|
|
'ADEFV', 'Adeudo Accesorios', |
|
|
|
'REZFC', 'Rezago Servicios', |
|
|
|
'ACTFC', 'Adeudo Servicios '||to_char(sysdate,'yyyy'), |
|
|
|
'ADEFP', 'Adeudo Fte. Propia', |
|
|
|
'ADEAT', 'Adeudo Agua Tratada', |
|
|
|
'ADEREC', 'Adeudo Reconexiones', |
|
|
|
'ANUAL', 'Pago Anual', |
|
|
|
'CRM', 'Cruz Roja Mexicana', |
|
|
|
'SUSPRG', 'Suspension de Servicio Programada en Curso, favor de acercarse a ventanilla o intentar mas tarde.', |
|
|
|
0 |
|
|
|
) descripcion, |
|
|
|
decode( |
|
|
|
descripcion, |
|
|
|
'CONVFV', appmovcom.pk_epay.fn_getAdeudoConvenio(?, 'V'), |
|
|
|
'CONVFM', 0, --appmovcom.pk_epay.fn_getAdeudoConvenio(?, 'M'), |
|
|
|
'CONVFC', appmovcom.pk_epay.fn_getAdeudoConvenio(?, 'S'), |
|
|
|
'ADEFV', appmovcom.pk_epay.fn_getAdeudoFV(?, null), |
|
|
|
'REZFC', (select nvl(sum(saldototal),0) saldototal from table(pk_edocta.fn_getadeudorez( ?, to_char(sysdate,'dd/mm/yyyy hh24:mi'), null, '17¬16¬116¬8', 'N'))), |
|
|
|
'ACTFC', (select nvl(sum(saldototal),0) saldototal from table(pk_edocta.fn_getadeudoact( ?, to_char(sysdate,'dd/mm/yyyy hh24:mi'), null, '17¬16¬116¬8', 'N'))), |
|
|
|
'ADEFP', (select nvl(sum(saldototal),0) saldototal from table(pk_edocta.fn_getadeudofact( ?, to_char(sysdate,'dd/mm/yyyy hh24:mi'), '17¬16¬116¬8', null, 'N'))), |
|
|
|
'ADEAT', (select nvl(sum(saldototal),0) saldototal from table(pk_edocta.fn_getadeudofact( ?, to_char(sysdate,'dd/mm/yyyy hh24:mi'), '21¬22¬122¬5¬6', null, 'N'))), |
|
|
|
'ADEREC', ( |
|
|
|
with cortes as |
|
|
|
( |
|
|
|
select nvl(sum(total),0) saldototal |
|
|
|
from |
|
|
|
( |
|
|
|
Select nvl(sum(total),0) total |
|
|
|
from table(cobranza.pk_carven.fn_getadeudocortes(? , sysdate)) a |
|
|
|
inner join ordentrabajoenc o using (otid) |
|
|
|
inner join predios p on (o.predioid=p.predioid) |
|
|
|
where total>0 |
|
|
|
and edopredioid in ('NO') |
|
|
|
) |
|
|
|
) |
|
|
|
select * from cortes |
|
|
|
), |
|
|
|
'ANUAL', (select nvl(sum(total),0) from table(appmovcom.pk_epay.fn_getadeudoccanualepay(?,to_char(sysdate,'dd/mm/yyyy')))), |
|
|
|
'CRM', (select sum(adeudofv) from table(cobranza.pk_carven.fn_getadeudofvcrm(?))), |
|
|
|
'SUSPRG', decode( |
|
|
|
( |
|
|
|
select m.descripcion |
|
|
|
from ordentrabajoenc |
|
|
|
inner join ot_motivos m using (motivoid) |
|
|
|
where |
|
|
|
predioid=? |
|
|
|
and motivoid in (select motivoid from ot_cortesfisicos) |
|
|
|
and trunc(fechaprog)=trunc(sysdate) |
|
|
|
and fechaanulacion is null |
|
|
|
and fechaprecierre is null |
|
|
|
), null, 0, 1 |
|
|
|
), |
|
|
|
0 |
|
|
|
) adeudo |
|
|
|
from ordenaplica |
|
|
|
order by ordenid |
|
|
|
) d |
|
|
|
where |
|
|
|
( |
|
|
|
adeudo>0 |
|
|
|
--or |
|
|
|
--ordenid=11 |
|
|
|
) |
|
|
|
order by ordenid |
|
|
|
"""; |
|
|
|
|
|
|
|
List<adeudoDTO> adeudos = new ArrayList<>(); |
|
|
|
|
|
|
|
String query2 = query.replace("?", String.valueOf(predioid)); |
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
Statement stmt = connection.createStatement(); |
|
|
|
ResultSet rs = stmt.executeQuery(query2)) { |
|
|
|
|
|
|
|
while (rs.next()) { |
|
|
|
adeudoDTO dto = new adeudoDTO(); |
|
|
|
dto.setOrdenid(rs.getInt("ordenid")); |
|
|
|
dto.setDescid(rs.getString("descid")); |
|
|
|
dto.setDescripcion(rs.getString("descripcion")); |
|
|
|
dto.setAdeudo(rs.getBigDecimal("adeudo")); |
|
|
|
dto.setTotal(rs.getBigDecimal("total")); |
|
|
|
adeudos.add(dto); |
|
|
|
} |
|
|
|
|
|
|
|
} catch (SQLException e) { |
|
|
|
throw new RuntimeException("Error al obtener adeudos por tipo: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return adeudos; |
|
|
|
} |
|
|
|
|
|
|
|
@ReadOnly |
|
|
|
public Map<String, Object> recuperarUsuario(String email, String pswd) { |
|
|
|
String sql = "begin appmovcom.pk_vigilante.sp_recuperausuario(?, ?); end;"; |
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = connection.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setString(1, email); |
|
|
|
stmt.setString(2, pswd); |
|
|
|
stmt.execute(); |
|
|
|
|
|
|
|
Map<String, Object> response = new HashMap<>(); |
|
|
|
response.put("status", "200"); |
|
|
|
response.put("message", "Recuperar Usuario: " + email); |
|
|
|
response.put("data", "Por favor revisa tu email " + email + " para ver tu usuario registrado."); |
|
|
|
return response; |
|
|
|
|
|
|
|
} catch (SQLException e) { |
|
|
|
throw new RuntimeException("Error al recuperar usuario: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
} |
|
|
|
|
|
|
|
@Transactional |
|
|
|
public Map<String, Object> actualizarPredio(Long predioid, String usuarioid) { |
|
|
|
Map<String, Object> resultado = new HashMap<>(); |
|
|
|
String query = "UPDATE APPMOVCOM.usuarios_servicios SET mostrar = 'S' WHERE predioid = ? AND usuarioid = ?"; |
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
PreparedStatement ps = connection.prepareStatement(query)) { |
|
|
|
|
|
|
|
ps.setLong(1, predioid); |
|
|
|
ps.setString(2, usuarioid); |
|
|
|
int updatedRows = ps.executeUpdate(); |
|
|
|
|
|
|
|
if (updatedRows > 0) { |
|
|
|
resultado.put("status", "200"); |
|
|
|
resultado.put("message", "El predio " + predioid + " se agregó correctamente."); |
|
|
|
} else { |
|
|
|
resultado.put("status", "500"); |
|
|
|
resultado.put("message", "No se pudo agregar el predio " + predioid + "."); |
|
|
|
} |
|
|
|
|
|
|
|
} catch (SQLException e) { |
|
|
|
throw new RuntimeException("Error al actualizar el predio: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return resultado; |
|
|
|
} |
|
|
|
|
|
|
|
@ReadOnly |
|
|
|
public void eliminarServicio(String usuarioid, Integer predioid, Integer clienteid, String contrato) { |
|
|
|
String query = "begin appmovcom.pk_servicios.sp_actualizaservicio(:usuarioid, :predioid, :clienteid, :contrato, 'E'); end;"; |
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
CallableStatement stmt = connection.prepareCall(query)) { |
|
|
|
|
|
|
|
stmt.setString("usuarioid", usuarioid); |
|
|
|
stmt.setInt("predioid", predioid); |
|
|
|
stmt.setInt("clienteid", clienteid); |
|
|
|
stmt.setString("contrato", contrato); |
|
|
|
|
|
|
|
stmt.execute(); |
|
|
|
|
|
|
|
} catch (SQLException e) { |
|
|
|
throw new RuntimeException("Error al eliminar servicio: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
} |
|
|
|
|
|
|
|
@ReadOnly |
|
|
|
public Map<String, Object> asociarServicio(asociarServicioDTO dto) { |
|
|
|
Map<String, Object> respuesta = new HashMap<>(); |
|
|
|
try (Connection conn = dataSource.getConnection()) { |
|
|
|
try (CallableStatement stmt = conn.prepareCall("begin appmovcom.pk_servicios.sp_asociaservicio(?, ?, ?); end;")) { |
|
|
|
stmt.setString(1, dto.getUsuarioid()); |
|
|
|
stmt.setInt(2, dto.getPredioid()); |
|
|
|
stmt.setString(3, dto.getContrato()); |
|
|
|
|
|
|
|
stmt.execute(); |
|
|
|
|
|
|
|
respuesta.put("status", "200"); |
|
|
|
respuesta.put("message", "Servicio asociado: " + dto.getUsuarioid()); |
|
|
|
respuesta.put("data", dto.getPredioid() + " predio asociado al usuario " + dto.getUsuarioid() + ", ahora podrás visualizarlo en el Dashboard."); |
|
|
|
} |
|
|
|
} catch (SQLException e) { |
|
|
|
respuesta.put("status", "500"); |
|
|
|
respuesta.put("message", "Error al asociar el servicio"); |
|
|
|
respuesta.put("data", e.getMessage()); |
|
|
|
} |
|
|
|
return respuesta; |
|
|
|
} |
|
|
|
|
|
|
|
public Map<String, Object> nuevoUsuario(String usuarioid, String email, String pswd, String nombre) { |
|
|
|
String query = "begin appmovcom.pk_vigilante.sp_nuevousuario(:p_NomUsu, :p_Email, :p_Pswd, :p_Nombre); end;"; |
|
|
|
Map<String, Object> response = new HashMap<>(); |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
CallableStatement stmt = conn.prepareCall(query)) { |
|
|
|
|
|
|
|
stmt.setString("p_NomUsu", usuarioid); |
|
|
|
stmt.setString("p_Email", email); |
|
|
|
stmt.setString("p_Pswd", pswd); |
|
|
|
stmt.setString("p_Nombre", nombre); |
|
|
|
|
|
|
|
stmt.execute(); |
|
|
|
|
|
|
|
response.put("status", "200"); |
|
|
|
response.put("message", "Usuario Agregado: " + usuarioid); |
|
|
|
response.put("data", nombre + " por favor revisa tu email " + email + " para activar la cuenta."); |
|
|
|
|
|
|
|
} catch (SQLException e) { |
|
|
|
response.put("status", "500"); |
|
|
|
response.put("message", "Error al agregar usuario: " + e.getMessage()); |
|
|
|
response.put("data", Collections.emptyMap()); |
|
|
|
} |
|
|
|
|
|
|
|
return response; |
|
|
|
} |
|
|
|
|
|
|
|
public Map<String, Object> cambiarPassword(String email, String nuevaPassword) { |
|
|
|
Map<String, Object> respuesta = new HashMap<>(); |
|
|
|
|
|
|
|
String query = "begin appmovcom.pk_vigilante.sp_cambiapswd(:p_Email, :p_Pswd); end;"; |
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
OraclePreparedStatement stmt = (OraclePreparedStatement) connection.prepareStatement(query)) { |
|
|
|
|
|
|
|
stmt.setStringAtName("p_Email", email); |
|
|
|
stmt.setStringAtName("p_Pswd", nuevaPassword); |
|
|
|
|
|
|
|
stmt.execute(); |
|
|
|
|
|
|
|
respuesta.put("status", "200"); |
|
|
|
respuesta.put("message", "Password cambiado: " + email); |
|
|
|
respuesta.put("data", "Por favor revisa tu email " + email + " para activar la cuenta."); |
|
|
|
|
|
|
|
} catch (SQLException e) { |
|
|
|
respuesta.put("status", "500"); |
|
|
|
respuesta.put("message", "Error al cambiar password: " + e.getMessage()); |
|
|
|
} |
|
|
|
|
|
|
|
return respuesta; |
|
|
|
} |
|
|
|
|
|
|
|
@ReadOnly |
|
|
|
public adeudoTotalDTO obtenerAdeudoTotal(Long predioid) { |
|
|
|
BigDecimal vAdeReconexion = getAdeudoReconexiones(predioid); |
|
|
|
BigDecimal vAdeComercialTotal = getAdeudoComercialTotal(predioid); |
|
|
|
BigDecimal vAdeComercialActual = getAdeudoComercialActual(predioid); |
|
|
|
BigDecimal adeudoFV = getAdeudoFV(predioid); |
|
|
|
BigDecimal adeConvenioFV = getConvenioFV(predioid); |
|
|
|
BigDecimal adeConvenioFC = getConvenioFC(predioid); |
|
|
|
BigDecimal adeFtePropia = getAdeudoFtePropia(predioid); |
|
|
|
BigDecimal adeAguaTratada = getAdeudoAguaTratada(predioid); |
|
|
|
|
|
|
|
BigDecimal total = vAdeReconexion |
|
|
|
.add(vAdeComercialTotal) |
|
|
|
.add(vAdeComercialActual) |
|
|
|
.add(adeudoFV) |
|
|
|
.add(adeConvenioFV) |
|
|
|
.add(adeConvenioFC) |
|
|
|
.add(adeFtePropia) |
|
|
|
.add(adeAguaTratada); |
|
|
|
|
|
|
|
String direccion = getDireccionPredio(predioid); |
|
|
|
|
|
|
|
adeudoTotalDTO dto = new adeudoTotalDTO(); |
|
|
|
dto.setPredioid(predioid); |
|
|
|
dto.setDireccion(direccion); |
|
|
|
dto.setTotal(total); |
|
|
|
|
|
|
|
return dto; |
|
|
|
|
|
|
|
/*String mensaje = String.format("El predio: %d con dirección: %s tiene un adeudo de: %.2f", |
|
|
|
dto.getPredioid(),dto.getDireccion(),dto.getTotal()); |
|
|
|
|
|
|
|
Map<String, String> response = new HashMap<>(); |
|
|
|
response.put("message", mensaje); |
|
|
|
return response;*/ |
|
|
|
} |
|
|
|
|
|
|
|
private BigDecimal getAdeudoReconexiones(Long predioid) { |
|
|
|
String sql = """ |
|
|
|
WITH cortes AS ( |
|
|
|
SELECT predioid, otid, |
|
|
|
descripcion, conceptoid, precio, iva, total, |
|
|
|
fechaprecierre, dictamenid, |
|
|
|
DECODE(dictamenid, NULL, estado, 'R') estado |
|
|
|
FROM ( |
|
|
|
SELECT o.predioid, otid, |
|
|
|
a.descripcion, conceptoid, precio, iva, total, |
|
|
|
fechaprecierre, dictamenid, |
|
|
|
DECODE(SIGN(TRUNC(fechaprog) - TRUNC(SYSDATE)), 0, 'P', -1, 'R', 1, 'S', 'N') estado |
|
|
|
FROM TABLE(cobranza.pk_carven.fn_getadeudocortes(?, SYSDATE)) a |
|
|
|
INNER JOIN ordentrabajoenc o USING (otid) |
|
|
|
INNER JOIN predios p ON o.predioid = p.predioid |
|
|
|
WHERE total > 0 AND edopredioid IN ('NO') |
|
|
|
) |
|
|
|
) |
|
|
|
SELECT SUM(total) AS total_reconexiones FROM cortes |
|
|
|
"""; |
|
|
|
|
|
|
|
BigDecimal total = BigDecimal.ZERO; |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setLong(1, predioid); |
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
|
|
|
|
if (rs.next()) { |
|
|
|
total = rs.getBigDecimal("total_reconexiones"); |
|
|
|
if (total == null) total = BigDecimal.ZERO; |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al obtener el adeudo por reconexiones: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return total.setScale(2, RoundingMode.HALF_UP); |
|
|
|
} |
|
|
|
|
|
|
|
private BigDecimal getAdeudoComercialTotal(Long predioid) { |
|
|
|
String sql = """ |
|
|
|
SELECT NVL(SUM(NVL(saldototal, 0)), 0) AS saldototal |
|
|
|
FROM TABLE(rest.pk_atms.fn_getadeudofact(?, NULL, NULL, NULL, 'N')) |
|
|
|
"""; |
|
|
|
|
|
|
|
BigDecimal total = BigDecimal.ZERO; |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setLong(1, predioid); |
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
|
|
|
|
if (rs.next()) { |
|
|
|
total = rs.getBigDecimal("saldototal"); |
|
|
|
if (total == null) total = BigDecimal.ZERO; |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al obtener adeudo comercial total: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return total.setScale(2, RoundingMode.HALF_UP); |
|
|
|
} |
|
|
|
|
|
|
|
private BigDecimal getAdeudoComercialActual(Long predioid) { |
|
|
|
String sql = """ |
|
|
|
SELECT NVL(SUM(NVL(saldototal, 0)), 0) AS saldototal |
|
|
|
FROM TABLE(rest.pk_atms.fn_getadeudoact(?, NULL, NULL, NULL, 'N')) |
|
|
|
"""; |
|
|
|
|
|
|
|
BigDecimal total = BigDecimal.ZERO; |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setLong(1, predioid); |
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
|
|
|
|
if (rs.next()) { |
|
|
|
total = rs.getBigDecimal("saldototal"); |
|
|
|
if (total == null) total = BigDecimal.ZERO; |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al obtener adeudo comercial actual: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return total.setScale(2, RoundingMode.HALF_UP); |
|
|
|
} |
|
|
|
|
|
|
|
private BigDecimal getAdeudoFV(Long predioid) { |
|
|
|
String sql = """ |
|
|
|
SELECT CEIL(adeudofv) AS totalredondeo |
|
|
|
FROM ( |
|
|
|
SELECT DISTINCT fv.facvtaencid, |
|
|
|
(SELECT comercial.fn_getadeudo_fv(fv.facvtaencid) FROM dual) adeudofv |
|
|
|
FROM facturavtaenc fv |
|
|
|
JOIN facturavtadet fd ON fv.facvtaencid = fd.facvtaencid |
|
|
|
JOIN tipofacturaventa tfv ON tfv.tipofacvtaid = fv.tipofacvtaid |
|
|
|
WHERE fv.predioid = ? |
|
|
|
AND (SELECT comercial.fn_getadeudo_fv(fv.facvtaencid) FROM dual) > 0 |
|
|
|
AND convencid IS NULL |
|
|
|
AND fechaanu IS NULL |
|
|
|
) |
|
|
|
"""; |
|
|
|
|
|
|
|
BigDecimal total = BigDecimal.ZERO; |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setLong(1, predioid); |
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
|
|
|
|
while (rs.next()) { |
|
|
|
BigDecimal parcial = rs.getBigDecimal("totalredondeo"); |
|
|
|
if (parcial != null) { |
|
|
|
total = total.add(parcial); |
|
|
|
} |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al obtener adeudo FV: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return total.setScale(2, RoundingMode.HALF_UP); |
|
|
|
} |
|
|
|
|
|
|
|
private BigDecimal getConvenioFV(Long predioid) { |
|
|
|
BigDecimal convenioFV = getAdeudoConvenio(predioid, "V"); |
|
|
|
return convenioFV; |
|
|
|
} |
|
|
|
|
|
|
|
private BigDecimal getConvenioFC(Long predioid) { |
|
|
|
BigDecimal convenioFC = getAdeudoConvenio(predioid, "S"); |
|
|
|
return convenioFC; |
|
|
|
} |
|
|
|
|
|
|
|
private BigDecimal getAdeudoConvenio(Long predioid, String tipoConvenio) { |
|
|
|
String sql = """ |
|
|
|
SELECT CEIL(impplazo) AS importe, NVL(imppagado, 0) AS pagado |
|
|
|
FROM ( |
|
|
|
SELECT convencid, descripcion, fechaalt, impdeuda, NVL(impdcto,0) descuento, |
|
|
|
impconve, pagoini, numplazos, obsgrales, d.periodoid, |
|
|
|
impplazo, NVL(imppagado,0) imppagado |
|
|
|
FROM conveniosenc e |
|
|
|
LEFT JOIN conveniosdet d USING (convencid) |
|
|
|
LEFT JOIN convenio_factura f USING (convencid) |
|
|
|
WHERE predioid = ? |
|
|
|
AND tipoconvenio LIKE ? |
|
|
|
AND (fechaanu IS NULL AND usuanu IS NULL AND motanuid IS NULL) |
|
|
|
AND (impplazo - NVL(imppagado, 0)) > 0 |
|
|
|
AND fechacum IS NULL |
|
|
|
GROUP BY convencid, descripcion, fechaalt, impdeuda, NVL(impdcto,0), |
|
|
|
impconve, pagoini, numplazos, obsgrales, d.periodoid, |
|
|
|
impplazo, NVL(imppagado, 0) |
|
|
|
ORDER BY convencid, d.periodoid |
|
|
|
) |
|
|
|
WHERE ROWNUM = 1 |
|
|
|
"""; |
|
|
|
|
|
|
|
BigDecimal total = BigDecimal.ZERO; |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setLong(1, predioid); |
|
|
|
stmt.setString(2, tipoConvenio); // 'V' para FV o 'S' para Comercial |
|
|
|
|
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
while (rs.next()) { |
|
|
|
BigDecimal importe = rs.getBigDecimal("importe"); |
|
|
|
BigDecimal pagado = rs.getBigDecimal("pagado"); |
|
|
|
|
|
|
|
if (importe != null && pagado != null) { |
|
|
|
total = total.add(importe.subtract(pagado)); |
|
|
|
} |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al obtener adeudo por convenio tipo " + tipoConvenio + ": " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return total.setScale(2, RoundingMode.HALF_UP); |
|
|
|
} |
|
|
|
|
|
|
|
private BigDecimal getAdeudoFtePropia(Long predioid) { |
|
|
|
String sql = """ |
|
|
|
SELECT NVL(SUM(saldototal), 0) AS saldototal |
|
|
|
FROM TABLE(pk_edocta.fn_getadeudofact(?, ?, '17¬16¬116¬8', NULL, 'N')) |
|
|
|
"""; |
|
|
|
|
|
|
|
BigDecimal total = BigDecimal.ZERO; |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
String nowFormatted = LocalDateTime.now().format(DateTimeFormatter.ofPattern("dd/MM/yyyy HH:mm")); |
|
|
|
stmt.setString(1, predioid.toString()); |
|
|
|
stmt.setString(2, nowFormatted); |
|
|
|
|
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
if (rs.next()) { |
|
|
|
total = rs.getBigDecimal("saldototal"); |
|
|
|
if (total == null) total = BigDecimal.ZERO; |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al obtener adeudo fuente propia: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return total.setScale(2, RoundingMode.HALF_UP); |
|
|
|
} |
|
|
|
|
|
|
|
private BigDecimal getAdeudoAguaTratada(Long predioid) { |
|
|
|
String sql = """ |
|
|
|
SELECT NVL(SUM(saldototal), 0) AS saldototal |
|
|
|
FROM TABLE(pk_edocta.fn_getadeudofact(?, ?, '21¬22¬122¬5¬6', NULL, 'N')) |
|
|
|
"""; |
|
|
|
|
|
|
|
BigDecimal total = BigDecimal.ZERO; |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
String nowFormatted = LocalDateTime.now().format(DateTimeFormatter.ofPattern("dd/MM/yyyy HH:mm")); |
|
|
|
stmt.setString(1, predioid.toString()); |
|
|
|
stmt.setString(2, nowFormatted); |
|
|
|
|
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
if (rs.next()) { |
|
|
|
total = rs.getBigDecimal("saldototal"); |
|
|
|
if (total == null) total = BigDecimal.ZERO; |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al obtener adeudo por agua tratada: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return total.setScale(2, RoundingMode.HALF_UP); |
|
|
|
} |
|
|
|
|
|
|
|
private String getDireccionPredio(Long predioid) { |
|
|
|
String sql = """ |
|
|
|
SELECT direccion |
|
|
|
FROM direcciones |
|
|
|
WHERE direcid = ( |
|
|
|
SELECT direcid FROM predios WHERE predioid = ? |
|
|
|
) |
|
|
|
"""; |
|
|
|
|
|
|
|
String direccion = ""; |
|
|
|
|
|
|
|
try (Connection conn = dataSource.getConnection(); |
|
|
|
PreparedStatement stmt = conn.prepareStatement(sql)) { |
|
|
|
|
|
|
|
stmt.setLong(1, predioid); |
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
|
|
|
|
if (rs.next()) { |
|
|
|
direccion = rs.getString("direccion"); |
|
|
|
} |
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
throw new RuntimeException("Error al obtener la dirección del predio: " + e.getMessage(), e); |
|
|
|
} |
|
|
|
|
|
|
|
return direccion != null ? direccion : ""; |
|
|
|
} |
|
|
|
|
|
|
|
} |