|
|
@ -4,14 +4,28 @@ import java.math.BigDecimal; |
|
|
import java.sql.Connection; |
|
|
import java.sql.Connection; |
|
|
import java.sql.PreparedStatement; |
|
|
import java.sql.PreparedStatement; |
|
|
import java.sql.ResultSet; |
|
|
import java.sql.ResultSet; |
|
|
|
|
|
import java.util.ArrayList; |
|
|
import java.util.List; |
|
|
import java.util.List; |
|
|
import java.util.stream.Collectors; |
|
|
import java.util.stream.Collectors; |
|
|
|
|
|
|
|
|
import javax.sql.DataSource; |
|
|
import javax.sql.DataSource; |
|
|
|
|
|
|
|
|
|
|
|
import io.micronaut.data.annotation.Query; |
|
|
|
|
|
import io.micronaut.data.jdbc.annotation.JdbcRepository; |
|
|
|
|
|
import io.micronaut.data.model.query.builder.sql.Dialect; |
|
|
|
|
|
import io.micronaut.data.repository.CrudRepository; |
|
|
import io.micronaut.transaction.annotation.Transactional; |
|
|
import io.micronaut.transaction.annotation.Transactional; |
|
|
|
|
|
import jakarta.inject.Singleton; |
|
|
|
|
|
import jumapacelaya.gob.mx.infowall.dto.cobFacVtaDiaDTO; |
|
|
|
|
|
import jumapacelaya.gob.mx.infowall.dto.compCvDTO; |
|
|
|
|
|
import jumapacelaya.gob.mx.infowall.dto.otReconexDiaDTO; |
|
|
|
|
|
import jumapacelaya.gob.mx.infowall.dto.otSuspensionDTO; |
|
|
|
|
|
import jumapacelaya.gob.mx.infowall.dto.totalCobrosHoyDTO; |
|
|
import jumapacelaya.gob.mx.infowall.dto.totalPagosHoyDTO; |
|
|
import jumapacelaya.gob.mx.infowall.dto.totalPagosHoyDTO; |
|
|
|
|
|
import jumapacelaya.gob.mx.infowall.dto.totalPagosMesDTO; |
|
|
|
|
|
import jumapacelaya.gob.mx.infowall.repositorio.InfowallRepositorio; |
|
|
|
|
|
|
|
|
|
|
|
@Singleton |
|
|
public class InfowallServicio { |
|
|
public class InfowallServicio { |
|
|
|
|
|
|
|
|
private final DataSource dataSource; |
|
|
private final DataSource dataSource; |
|
|
@ -58,4 +72,271 @@ public class InfowallServicio { |
|
|
} |
|
|
} |
|
|
} |
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
@Transactional |
|
|
|
|
|
public totalCobrosHoyDTO obtenerTotalCobrosHoy(List<Integer> entidadIds, List<Integer> puntoIds) { |
|
|
|
|
|
String query = "SELECT SUM(total) AS totalcobrado, COUNT(total) AS numerocobros " + |
|
|
|
|
|
"FROM cobrosenc c " + |
|
|
|
|
|
"INNER JOIN lotesenc l USING (numloteid) " + |
|
|
|
|
|
"WHERE fechacob BETWEEN TRUNC(SYSDATE) AND TRUNC(SYSDATE + 1) " + |
|
|
|
|
|
"AND entidadid IN (%s) AND puntoid IN (%s)"; |
|
|
|
|
|
|
|
|
|
|
|
String entidadPlaceholders = entidadIds.stream().map(id -> "?").collect(Collectors.joining(",")); |
|
|
|
|
|
String puntoPlaceholders = puntoIds.stream().map(id -> "?").collect(Collectors.joining(",")); |
|
|
|
|
|
|
|
|
|
|
|
query = String.format(query, entidadPlaceholders, puntoPlaceholders); |
|
|
|
|
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
|
|
PreparedStatement stmt = connection.prepareStatement(query)) { |
|
|
|
|
|
|
|
|
|
|
|
int index = 1; |
|
|
|
|
|
for (Integer id : entidadIds) { |
|
|
|
|
|
stmt.setInt(index++, id); |
|
|
|
|
|
} |
|
|
|
|
|
for (Integer id : puntoIds) { |
|
|
|
|
|
stmt.setInt(index++, id); |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
|
|
if (rs.next()) { |
|
|
|
|
|
BigDecimal total = rs.getBigDecimal("totalcobrado"); |
|
|
|
|
|
int count = rs.getInt("numerocobros"); |
|
|
|
|
|
return new totalCobrosHoyDTO(total != null ? total : BigDecimal.ZERO, count); |
|
|
|
|
|
} else { |
|
|
|
|
|
return new totalCobrosHoyDTO(BigDecimal.ZERO, 0); |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
|
|
throw new RuntimeException("Error al obtener total de cobros de hoy", e); |
|
|
|
|
|
} |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
@Transactional |
|
|
|
|
|
public List<totalPagosMesDTO> obtenerTotalPagosAnualPorMes() { |
|
|
|
|
|
String query = "SELECT TO_CHAR(fechapag, 'mm') AS mes, " + |
|
|
|
|
|
"SUM(total) AS totalpagado, COUNT(total) AS numeropagos " + |
|
|
|
|
|
"FROM pagosenc p " + |
|
|
|
|
|
"INNER JOIN lotesenc l USING (numloteid) " + |
|
|
|
|
|
"WHERE TO_CHAR(fechapag, 'yyyy') = TO_CHAR(SYSDATE, 'yyyy') " + |
|
|
|
|
|
"AND entidadid = 1 AND puntoid IN (1, 2, 3, 5, 7) " + |
|
|
|
|
|
"GROUP BY TO_CHAR(fechapag, 'mm') " + |
|
|
|
|
|
"ORDER BY TO_CHAR(fechapag, 'mm')"; |
|
|
|
|
|
|
|
|
|
|
|
List<totalPagosMesDTO> lista = new ArrayList<>(); |
|
|
|
|
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
|
|
PreparedStatement stmt = connection.prepareStatement(query); |
|
|
|
|
|
ResultSet rs = stmt.executeQuery()) { |
|
|
|
|
|
|
|
|
|
|
|
while (rs.next()) { |
|
|
|
|
|
String mes = rs.getString("mes"); |
|
|
|
|
|
BigDecimal total = rs.getBigDecimal("totalpagado"); |
|
|
|
|
|
int count = rs.getInt("numeropagos"); |
|
|
|
|
|
|
|
|
|
|
|
lista.add(new totalPagosMesDTO( |
|
|
|
|
|
mes, |
|
|
|
|
|
total != null ? total : BigDecimal.ZERO, |
|
|
|
|
|
count |
|
|
|
|
|
)); |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
|
|
throw new RuntimeException("Error al obtener pagos anuales por mes", e); |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
return lista; |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
@Transactional |
|
|
|
|
|
public List<otSuspensionDTO> obtenerOtSuspension() { |
|
|
|
|
|
String query = """ |
|
|
|
|
|
SELECT COUNT(otid) AS ots, motivoid, descripcion FROM ( |
|
|
|
|
|
SELECT predioid, otid, motivoid, m.descripcion, fecha, fechaprecierre, dictamenid, latitud, longitud, |
|
|
|
|
|
RANK() OVER (PARTITION BY predioid ORDER BY otid DESC) AS orden |
|
|
|
|
|
FROM ordentrabajoenc o |
|
|
|
|
|
INNER JOIN ot_cortesfisicos f USING (motivoid) |
|
|
|
|
|
INNER JOIN ot_motivos m USING (motivoid) |
|
|
|
|
|
INNER JOIN predioslatlon l USING (predioid) |
|
|
|
|
|
WHERE fechaprecierre IS NOT NULL |
|
|
|
|
|
) |
|
|
|
|
|
WHERE orden = 1 |
|
|
|
|
|
AND REGEXP_LIKE(dictamenid, 'SRC') |
|
|
|
|
|
AND otid NOT IN ( |
|
|
|
|
|
SELECT otipadre FROM ordentrabajoenc |
|
|
|
|
|
WHERE otipadre IS NOT NULL |
|
|
|
|
|
AND REGEXP_LIKE(dictamenid, 'SRR') |
|
|
|
|
|
) |
|
|
|
|
|
GROUP BY motivoid, descripcion |
|
|
|
|
|
ORDER BY motivoid |
|
|
|
|
|
"""; |
|
|
|
|
|
|
|
|
|
|
|
List<otSuspensionDTO> lista = new ArrayList<>(); |
|
|
|
|
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
|
|
PreparedStatement stmt = connection.prepareStatement(query); |
|
|
|
|
|
ResultSet rs = stmt.executeQuery()) { |
|
|
|
|
|
|
|
|
|
|
|
while (rs.next()) { |
|
|
|
|
|
int ots = rs.getInt("ots"); |
|
|
|
|
|
int motivoid = rs.getInt("motivoid"); |
|
|
|
|
|
String descripcion = rs.getString("descripcion"); |
|
|
|
|
|
|
|
|
|
|
|
lista.add(new otSuspensionDTO(ots, motivoid, descripcion)); |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
|
|
throw new RuntimeException("Error al obtener OTs de suspensión", e); |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
return lista; |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
@Transactional |
|
|
|
|
|
public otReconexDiaDTO obtenerOtsReconexDia() { |
|
|
|
|
|
String query = """ |
|
|
|
|
|
SELECT COUNT(otid) AS reconexdia |
|
|
|
|
|
FROM ordentrabajoenc o |
|
|
|
|
|
WHERE TRUNC(fechaprecierre) = TRUNC(SYSDATE) |
|
|
|
|
|
AND motivoid IN ( |
|
|
|
|
|
SELECT motivoid FROM ot_motivos WHERE origenid = 'REC' |
|
|
|
|
|
) |
|
|
|
|
|
AND REGEXP_LIKE(dictamenid, 'SRR') |
|
|
|
|
|
"""; |
|
|
|
|
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
|
|
PreparedStatement stmt = connection.prepareStatement(query); |
|
|
|
|
|
ResultSet rs = stmt.executeQuery()) { |
|
|
|
|
|
|
|
|
|
|
|
if (rs.next()) { |
|
|
|
|
|
return new otReconexDiaDTO(rs.getInt("reconexdia")); |
|
|
|
|
|
} else { |
|
|
|
|
|
return new otReconexDiaDTO(0); |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
|
|
throw new RuntimeException("Error al obtener OTs de reconexión del día", e); |
|
|
|
|
|
} |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
@Transactional |
|
|
|
|
|
public List<cobFacVtaDiaDTO> obtenerCobFacVtaDia(String tipoFacVta) { |
|
|
|
|
|
String query = """ |
|
|
|
|
|
WITH reconexiones AS ( |
|
|
|
|
|
SELECT facvtaencid, tipofacvtaid, nombre, cobroencid, cd.total, predioid, usoid |
|
|
|
|
|
FROM cobrosdet cd |
|
|
|
|
|
INNER JOIN cobrosenc ce USING (cobroencid) |
|
|
|
|
|
INNER JOIN facturavtaenc fe USING (facvtaencid) |
|
|
|
|
|
INNER JOIN tipofacturaventa USING (tipofacvtaid) |
|
|
|
|
|
INNER JOIN predios p USING (predioid) |
|
|
|
|
|
WHERE TRUNC(ce.fechacob) = TRUNC(SYSDATE) |
|
|
|
|
|
AND REGEXP_LIKE(nombre, ?) |
|
|
|
|
|
AND activo = 'S' |
|
|
|
|
|
AND ce.fechaanu IS NULL |
|
|
|
|
|
) |
|
|
|
|
|
SELECT usoid, u.nombre AS uso, COUNT(cobroencid) AS cobros, SUM(total) AS total |
|
|
|
|
|
FROM reconexiones |
|
|
|
|
|
INNER JOIN usos u USING (usoid) |
|
|
|
|
|
GROUP BY usoid, u.nombre |
|
|
|
|
|
ORDER BY usoid |
|
|
|
|
|
"""; |
|
|
|
|
|
|
|
|
|
|
|
List<cobFacVtaDiaDTO> lista = new ArrayList<>(); |
|
|
|
|
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
|
|
PreparedStatement stmt = connection.prepareStatement(query)) { |
|
|
|
|
|
|
|
|
|
|
|
stmt.setString(1, tipoFacVta); |
|
|
|
|
|
|
|
|
|
|
|
ResultSet rs = stmt.executeQuery(); |
|
|
|
|
|
while (rs.next()) { |
|
|
|
|
|
String usoid = rs.getString("usoid"); |
|
|
|
|
|
String uso = rs.getString("uso"); |
|
|
|
|
|
int cobros = rs.getInt("cobros"); |
|
|
|
|
|
BigDecimal total = rs.getBigDecimal("total"); |
|
|
|
|
|
|
|
|
|
|
|
lista.add(new cobFacVtaDiaDTO(usoid, uso, cobros, total != null ? total : BigDecimal.ZERO)); |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
|
|
throw new RuntimeException("Error al obtener cobros por tipo de factura de venta", e); |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
return lista; |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
@Transactional(readOnly = true) |
|
|
|
|
|
public compCvDTO obtenerCompCv() { |
|
|
|
|
|
String query = """ |
|
|
|
|
|
select |
|
|
|
|
|
sum(saldovencido) saldovencido, sum(saldonovencido) saldonovencido, |
|
|
|
|
|
sum(vr11+vr12+vr13+vr14+vr15+vr16+vr17+vr112+vr116+vr118+vr21+vr22+vr122) vencrezago, |
|
|
|
|
|
sum(va11+va12+va13+va14+va15+va16+va17+va112+va116+va118+va21+va22+va122) vencactual, |
|
|
|
|
|
sum(nv11+nv12+nv13+nv14+nv15+nv16+nv17+nv112+nv116+nv118+nv21+nv22+nv122) novencido, |
|
|
|
|
|
sum(vr5+vr6+vr7+vr8) recvencrezago, |
|
|
|
|
|
sum(va5+va6+va7+va8) recvencactual, |
|
|
|
|
|
sum(nv5+nv6+nv7+nv8) recnovencido, |
|
|
|
|
|
sum(saldototal) saldototal, sum(saldogescob) saldogescob, |
|
|
|
|
|
sum(vr11) vr11, sum(va11) va11, sum(nv11) nv11, |
|
|
|
|
|
sum(vr12) vr12, sum(va12) va12, sum(nv12) nv12, |
|
|
|
|
|
sum(vr13) vr13, sum(va13) va13, sum(nv13) nv13, |
|
|
|
|
|
sum(vr14) vr14, sum(va14) va14, sum(nv14) nv14, |
|
|
|
|
|
sum(vr15) vr15, sum(va15) va15, sum(nv15) nv15, |
|
|
|
|
|
sum(vr16) vr16, sum(va16) va16, sum(nv16) nv16, |
|
|
|
|
|
sum(vr17) vr17, sum(va17) va17, sum(nv17) nv17, |
|
|
|
|
|
sum(vr112) vr112, sum(va112) va112, sum(nv112) nv112, |
|
|
|
|
|
sum(vr116) vr116, sum(va116) va116, sum(nv116) nv116, |
|
|
|
|
|
sum(vr118) vr118, sum(va118) va118, sum(nv118) nv118, |
|
|
|
|
|
sum(vr21) vr21, sum(va21) va21, sum(nv21) nv21, |
|
|
|
|
|
sum(vr22) vr22, sum(va22) va22, sum(nv22) nv22, |
|
|
|
|
|
sum(vr122) vr122, sum(va122) va122, sum(nv122) nv122, |
|
|
|
|
|
sum(vr5) vr5, sum(va5) va5, sum(nv5) nv5, |
|
|
|
|
|
sum(vr6) vr6, sum(va6) va6, sum(nv6) nv6, |
|
|
|
|
|
sum(vr7) vr7, sum(va7) va7, sum(nv7) nv7, |
|
|
|
|
|
sum(vr8) vr8, sum(va8) va8, sum(nv8) nv8 |
|
|
|
|
|
from cobranza.tblcvlive |
|
|
|
|
|
"""; |
|
|
|
|
|
|
|
|
|
|
|
try (Connection connection = dataSource.getConnection(); |
|
|
|
|
|
PreparedStatement stmt = connection.prepareStatement(query); |
|
|
|
|
|
ResultSet rs = stmt.executeQuery(query)) { |
|
|
|
|
|
|
|
|
|
|
|
if (rs.next()) { |
|
|
|
|
|
compCvDTO dto = new compCvDTO(); |
|
|
|
|
|
dto.setSaldovencido(rs.getBigDecimal("saldovencido")); |
|
|
|
|
|
dto.setSaldonovencido(rs.getBigDecimal("saldonovencido")); |
|
|
|
|
|
dto.setVencrezago(rs.getBigDecimal("vencrezago")); |
|
|
|
|
|
dto.setVencactual(rs.getBigDecimal("vencactual")); |
|
|
|
|
|
dto.setNovencido(rs.getBigDecimal("novencido")); |
|
|
|
|
|
dto.setRecvencrezago(rs.getBigDecimal("recvencrezago")); |
|
|
|
|
|
dto.setRecvencactual(rs.getBigDecimal("recvencactual")); |
|
|
|
|
|
dto.setRecnovencido(rs.getBigDecimal("recnovencido")); |
|
|
|
|
|
dto.setSaldototal(rs.getBigDecimal("saldototal")); |
|
|
|
|
|
dto.setSaldogescob(rs.getBigDecimal("saldogescob")); |
|
|
|
|
|
dto.setVr5(rs.getBigDecimal("vr5")); dto.setVa5(rs.getBigDecimal("va5")); dto.setNv5(rs.getBigDecimal("nv5")); |
|
|
|
|
|
dto.setVr6(rs.getBigDecimal("vr6")); dto.setVa6(rs.getBigDecimal("va6")); dto.setNv6(rs.getBigDecimal("nv6")); |
|
|
|
|
|
dto.setVr7(rs.getBigDecimal("vr7")); dto.setVa7(rs.getBigDecimal("va7")); dto.setNv7(rs.getBigDecimal("nv7")); |
|
|
|
|
|
dto.setVr8(rs.getBigDecimal("vr8")); dto.setVa8(rs.getBigDecimal("va8")); dto.setNv8(rs.getBigDecimal("nv8")); |
|
|
|
|
|
dto.setVr11(rs.getBigDecimal("vr11")); dto.setVa11(rs.getBigDecimal("va11")); dto.setNv11(rs.getBigDecimal("nv11")); |
|
|
|
|
|
dto.setVr12(rs.getBigDecimal("vr12")); dto.setVa12(rs.getBigDecimal("va12")); dto.setNv12(rs.getBigDecimal("nv12")); |
|
|
|
|
|
dto.setVr13(rs.getBigDecimal("vr13")); dto.setVa13(rs.getBigDecimal("va13")); dto.setNv13(rs.getBigDecimal("nv13")); |
|
|
|
|
|
dto.setVr14(rs.getBigDecimal("vr14")); dto.setVa14(rs.getBigDecimal("va14")); dto.setNv14(rs.getBigDecimal("nv14")); |
|
|
|
|
|
dto.setVr15(rs.getBigDecimal("vr15")); dto.setVa15(rs.getBigDecimal("va15")); dto.setNv15(rs.getBigDecimal("nv15")); |
|
|
|
|
|
dto.setVr16(rs.getBigDecimal("vr16")); dto.setVa16(rs.getBigDecimal("va16")); dto.setNv16(rs.getBigDecimal("nv16")); |
|
|
|
|
|
dto.setVr17(rs.getBigDecimal("vr17")); dto.setVa17(rs.getBigDecimal("va17")); dto.setNv17(rs.getBigDecimal("nv17")); |
|
|
|
|
|
dto.setVr21(rs.getBigDecimal("vr21")); dto.setVa21(rs.getBigDecimal("va21")); dto.setNv21(rs.getBigDecimal("nv21")); |
|
|
|
|
|
dto.setVr22(rs.getBigDecimal("vr22")); dto.setVa22(rs.getBigDecimal("va22")); dto.setNv22(rs.getBigDecimal("nv22")); |
|
|
|
|
|
dto.setVr112(rs.getBigDecimal("vr112")); dto.setVa112(rs.getBigDecimal("va112")); dto.setNv112(rs.getBigDecimal("nv112")); |
|
|
|
|
|
dto.setVr116(rs.getBigDecimal("vr116")); dto.setVa116(rs.getBigDecimal("va116")); dto.setNv116(rs.getBigDecimal("nv116")); |
|
|
|
|
|
dto.setVr118(rs.getBigDecimal("vr118")); dto.setVa118(rs.getBigDecimal("va118")); dto.setNv118(rs.getBigDecimal("nv118")); |
|
|
|
|
|
dto.setVr122(rs.getBigDecimal("vr122")); dto.setVa122(rs.getBigDecimal("va122")); dto.setNv122(rs.getBigDecimal("nv122")); |
|
|
|
|
|
|
|
|
|
|
|
return dto; |
|
|
|
|
|
} else { |
|
|
|
|
|
throw new RuntimeException("No se obtuvo información de la tabla cobranza.tblcvlive"); |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
|
|
|
} catch (Exception e) { |
|
|
|
|
|
throw new RuntimeException("Error al obtener comparativo de cartera vencida", e); |
|
|
|
|
|
} |
|
|
|
|
|
} |
|
|
|
|
|
|
|
|
} |
|
|
} |