Foros Club Delphi

Foros Club Delphi (https://www.clubdelphi.com/foros/index.php)
-   Firebird e Interbase (https://www.clubdelphi.com/foros/forumdisplay.php?f=19)
-   -   ¿Consulta correcta con DATEDIFF? (https://www.clubdelphi.com/foros/showthread.php?t=93567)

novato_erick 17-11-2018 00:42:23

¿Consulta correcta con DATEDIFF?
 
Hola Chicos:

Como han estado?

La verdad tenia rato de no consultar en el foro sin embargo tengo un pequeño dolor de cabeza que probablemente lo resolveria con la Aspirina sin embargo creo que voleria porque tengo media hora de estar buscando porque me manda un error en Firebird:
Código:

Invalid token.
Dynamic SQL Error.
SQL error code = -104.
Token unknown - line 17, column 42.
FAC_CREDITO.

en esta Consulta usando la Función DIFFDATE();

Código SQL [-]
select
FAC_CREDITO.ID_CLIENTE,
FAC_CREDITO.ID_FACTURA,
IIF( DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE ) <0 AND (FAC_CREDITO.FECHAFIN_CRE <> '0000-00-00' ), FAC_CREDITO.M_VENTACREDITO,0) AS POR_VENCER,
IIF( DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE )>=0 AND DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE  ) <=15 OR FAC_CREDITO.FECHAFIN_CRE = '00-00-0000', FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOS115, 
IIF( DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE )>=16 AND DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE ) <=30, FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOS1630,
IIF( DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE )>=31 AND DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE ) <=45, FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOS3145,
IIF( DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE )>=46 AND DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE ) <=60, FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOS4660,
IIF( DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE )>=61 AND DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE ) <=90, FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOS6190,
IIF( DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE )>=91 AND DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE ) <=120, FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOS91120,
IIF( DATEDIFF( month, current_date, date FAC_CREDITO.FECHAFIN_CRE )>=121 ,FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOSMAS120
from FAC_CREDITO
ORDER BY FAC_CREDITO.ID_CLIENTE

Ya se pueden imaginar simplemente recibir los monto que estan dentro del rango de días.

Alguna sugerencia
mi tabla es :
Código SQL [-]
CREATE TABLE FAC_CREDITO (
  ID_FACCREDITO INTEGER NOT NULL,
  ID_FACTURA INTEGER NOT NULL,
  ID_CLIENTE INTEGER NOT NULL,
  M_VENTACREDITO DECIMAL(12, 2) DEFAULT 0.0 NOT NULL,
  PENDIENTE CHAR(1) CHARACTER SET ASCII DEFAULT 'S' NOT NULL COLLATE ASCII,
  FECHAINI_CRE TIMESTAMP NOT NULL,
  FECHAFIN_CRE TIMESTAMP NOT NULL,
  DETALLE_FAC_CREDITO VARCHAR(125) CHARACTER SET ASCII NOT NULL COLLATE ASCII,
  CONSECUTIVO_FAC INTEGER NOT NULL);
ALTER TABLE FAC_CREDITO ADD PRIMARY KEY (ID_FACCREDITO);


SET TERM ^ ;

CREATE TRIGGER BI_FAC_CREDITO_ID_FACCREDITO FOR FAC_CREDITO
ACTIVE BEFORE INSERT
POSITION 0
AS
BEGIN
  IF (NEW.ID_FACCREDITO IS NULL) THEN
      NEW.ID_FACCREDITO = GEN_ID(FAC_CREDITO_ID_FACCREDITO_GEN, 1);
END^

SET TERM ;

Agradeciendo su colaboración o algun aporte que mejore mi consulta me despido temporalmente;ç

novato_erick

Casimiro Notevi 17-11-2018 00:57:08

Si es una sola tabla, quita todo lo de FAC_CREDITO.
Código SQL [-]
select
ID_CLIENTE,
ID_FACTURA,
IIF( DATEDIFF( month, current_date, date FECHAFIN_CRE ) <0 AND (FECHAFIN_CRE <> '0000-00-00' ), M_VENTACREDITO,0) AS POR_VENCER,
IIF( DATEDIFF( month, current_date, date FECHAFIN_CRE )>=0 AND DATEDIFF( month, current_date, date FECHAFIN_CRE  ) <=15 OR FECHAFIN_CRE = '00-00-0000', M_VENTACREDITO,0) AS VENCIDOS115, 
IIF( DATEDIFF( month, current_date, date FECHAFIN_CRE )>=16 AND DATEDIFF( month, current_date, date FECHAFIN_CRE ) <=30, M_VENTACREDITO,0) AS VENCIDOS1630,
IIF( DATEDIFF( month, current_date, date FECHAFIN_CRE )>=31 AND DATEDIFF( month, current_date, date FECHAFIN_CRE ) <=45, M_VENTACREDITO,0) AS VENCIDOS3145,
IIF( DATEDIFF( month, current_date, date FECHAFIN_CRE )>=46 AND DATEDIFF( month, current_date, date FECHAFIN_CRE ) <=60, M_VENTACREDITO,0) AS VENCIDOS4660,
IIF( DATEDIFF( month, current_date, date FECHAFIN_CRE )>=61 AND DATEDIFF( month, current_date, date FECHAFIN_CRE ) <=90, M_VENTACREDITO,0) AS VENCIDOS6190,
IIF( DATEDIFF( month, current_date, date FECHAFIN_CRE )>=91 AND DATEDIFF( month, current_date, date FECHAFIN_CRE ) <=120, M_VENTACREDITO,0) AS VENCIDOS91120,
IIF( DATEDIFF( month, current_date, date FECHAFIN_CRE )>=121 ,M_VENTACREDITO,0) AS VENCIDOSMAS120
from FAC_CREDITO
ORDER BY ID_CLIENTE


novato_erick 18-11-2018 19:04:47

Hola Casimiro como has estado?

Agradezco siempre tu colaboración:

Encontré el problema al "Sancocho" (Comida Típica de Panamá en el que consiste la simpleza de sopa de Gallina con un tipo de verdura la cual si no la sabes preparar se te hace el Sancocho.... Problema jajajaj).

en fin usando lo siguiente:
Código SQL [-]
SELECT
   FAC_CREDITO.FECHAFIN_CRE,
   DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
FROM
   FAC_CREDITO

el resultado fueron los dias que han pasado en negativo:
Al usar la consulta necesitaba que los monto fueran correspondiente a la fecha de fin de crédito lo realicé de esta manera:

Código SQL [-]
SELECT
FAC_CREDITO.ID_CLIENTE,
FAC_CREDITO.ID_FACTURA,
CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE) AS FECHAFINALIZA,
   IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
   <=-1 AND DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
     >=-30 OR FAC_CREDITO.FECHAFIN_CRE = CURRENT_DATE, FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOS30,  
    IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
    <=-31 AND DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
     >=-60, FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOS60,
    IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
    <=-61 AND DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
     >=-90, FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOS90,
    IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
    <=-91 AND DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
     >=-120, FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOS120,
    IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
     <=-121 ,FAC_CREDITO.M_VENTACREDITO,0) AS VENCIDOSMAS121
     
FROM
   FAC_CREDITO WHERE FAC_CREDITO.PENDIENTE = 'S'

Logrando esto los resultado en la Tabla FAC_CREDITO me trae el monto de Facturación a crédito ahora trataré de agregar otra tabla llamada ABONOS_CRE en la que aparece el ID_FACTURA con su respectivo campos de abono y saldo final para que me mande en caso que se realizarán Abonos me muestre en realidad el saldo correspondiente no el saldo inicial.

Mando la estructura ahora de la tabla ABONO_CRE en caso que alguien desee colaborar

Código SQL [-]
CREATE TABLE ABONO_CREDI (
  ID_ABONOCRE INTEGER NOT NULL,
  ID_CLIENTE INTEGER NOT NULL,
  ID_FACTURA INTEGER NOT NULL,
  NUM_RECIBO INTEGER NOT NULL,
  MONTO_SALDOANTERIOR DECIMAL(12, 2) DEFAULT 0.0 NOT NULL,
  MONTO_ABONO DECIMAL(12, 2) DEFAULT 0.0 NOT NULL,
  MONTO_SALDONUEVO DECIMAL(12, 2) DEFAULT 0.0 NOT NULL,
  FECHA_ABONO TIMESTAMP NOT NULL,
  ID_CAJA INTEGER NOT NULL,
  ID_USER INTEGER NOT NULL);


ALTER TABLE ABONO_CREDI ADD PRIMARY KEY (ID_ABONOCRE);


SET TERM ^ ;

CREATE TRIGGER BI_ABONO_CREDI_ID_ABONOCRE FOR ABONO_CREDI
ACTIVE BEFORE INSERT
POSITION 0
AS
BEGIN
  IF (NEW.ID_ABONOCRE IS NULL) THEN
      NEW.ID_ABONOCRE = GEN_ID(ABONO_CREDI_ID_ABONOCRE_GEN, 1);
END^

SET TERM ;

Agradezco mucho tu comentario CASIMIRO

Saludos desde Panamá

novato_erick

novato_erick 23-11-2018 01:57:35

Resuelto ¿Consulta Correcta con DATEDIFF?
 
Hola Chicos:
Hace un par de Días encontré la solución a mi problema talvez pueda servir a algún otro la cual necesite hacer una simple consulta en Firebird en la que se requiera saldos en terminos de rango de días 30, 60, 90 , 120 y más de 120.

Aquí está lo que realicé:
Basada en la condicción IFF de Firebird mostrando un valor Booland realicé en el resultado otra subconsulta ejemplo:

Código SQL [-]
SELECT
      FAC_CREDITO.ID_CLIENTE,
      FAC_CREDITO.ID_FACTURA,
      CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE) AS FECHAFINALIZA,
      IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
      >=1 AND (FAC_CREDITO.FECHAFIN_CRE <> CURRENT_DATE ),
     ( SELECT IIF( COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0) = 0, /*Realizo Condición nuevamente con Subconsulta a la tabla Abonos*/
      (select FAC_CREDITO.M_VENTACREDITO from FAC_CREDITO
      where  FAC_CREDITO.ID_CLIENTE = :ID_C AND 
      FAC_CREDITO.ID_FACTURA =:ID_F AND PENDIENTE = 'S' ),
      COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0))
      FROM ABONO_CREDI WHERE 
      ABONO_CREDI.ID_CLIENTE = :ID_C AND ABONO_CREDI.ID_FACTURA = :ID_F),0)
      AS SALDO_CORRIENTE,
      
       IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
       <=-1 AND DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
       >=-30 OR FAC_CREDITO.FECHAFIN_CRE = CURRENT_DATE,
      ( SELECT IIF( COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0) = 0,
      (select FAC_CREDITO.M_VENTACREDITO from FAC_CREDITO
      where  FAC_CREDITO.ID_CLIENTE = :ID_C AND 
      FAC_CREDITO.ID_FACTURA =:ID_F AND PENDIENTE = 'S' ),
      COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0))
      FROM ABONO_CREDI WHERE 
      ABONO_CREDI.ID_CLIENTE = :ID_C AND ABONO_CREDI.ID_FACTURA = :ID_F),0)
      AS VENCIDOS30,  
      
      IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
      <=-31 AND DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
      >=-60,  ( SELECT IIF( COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0) = 0,
      (select FAC_CREDITO.M_VENTACREDITO from FAC_CREDITO
      where  FAC_CREDITO.ID_CLIENTE = :ID_C AND 
      FAC_CREDITO.ID_FACTURA =:ID_F AND PENDIENTE = 'S' ),
      COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0))
      FROM ABONO_CREDI WHERE 
      ABONO_CREDI.ID_CLIENTE = :ID_C AND ABONO_CREDI.ID_FACTURA = :ID_F),0) AS VENCIDOS60,
      
      IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
      <=-61 AND DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
      >=-90, ( SELECT IIF( COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0) = 0,
      (select FAC_CREDITO.M_VENTACREDITO from FAC_CREDITO
      where  FAC_CREDITO.ID_CLIENTE = :ID_C AND 
      FAC_CREDITO.ID_FACTURA =:ID_F AND PENDIENTE = 'S' ),
      COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0))
      FROM ABONO_CREDI WHERE 
      ABONO_CREDI.ID_CLIENTE = :ID_C AND ABONO_CREDI.ID_FACTURA = :ID_F),0) AS VENCIDOS90,
    
      IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
      <=-91 AND DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
      >=-120,( SELECT IIF( COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0) = 0,
      (select FAC_CREDITO.M_VENTACREDITO from FAC_CREDITO
      where  FAC_CREDITO.ID_CLIENTE = :ID_C AND 
      FAC_CREDITO.ID_FACTURA =:ID_F AND PENDIENTE = 'S' ),
      COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0))
      FROM ABONO_CREDI WHERE 
      ABONO_CREDI.ID_CLIENTE = :ID_C AND ABONO_CREDI.ID_FACTURA = :ID_F),0) AS VENCIDOS120,
      
      IIF( DATEDIFF(DAY FROM CURRENT_DATE TO CAST(FAC_CREDITO.FECHAFIN_CRE AS DATE))
      <=-121 , ( SELECT IIF( COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0) = 0,
      (select FAC_CREDITO.M_VENTACREDITO from FAC_CREDITO
      where  FAC_CREDITO.ID_CLIENTE = :ID_C AND 
      FAC_CREDITO.ID_FACTURA =:ID_F AND PENDIENTE = 'S' ),
      COALESCE(MIN(ABONO_CREDI.MONTO_SALDONUEVO),0))
      FROM ABONO_CREDI WHERE 
      ABONO_CREDI.ID_CLIENTE = :ID_C AND ABONO_CREDI.ID_FACTURA = :ID_F),0) AS VENCIDOSMAS121   
      
      FROM
              FAC_CREDITO
                          WHERE FAC_CREDITO.PENDIENTE = 'S' AND
                          FAC_CREDITO.ID_CLIENTE = :IDCLIENTECREDITO AND 
                          FAC_CREDITO.ID_FACTURA = :IDFACTURACREDITO

En fin el resultado fue el requerido por el momento. la optimizacion vendrá más adelante la cual me tomaré una par de hora para ejecutarla
tambien más adelante haré mejoras en la consulta ya que esta solamente está basada en una factura especifica con numero de factura y cliente trayendo detalles de los abonos en respectiva a esa factura lo que probablemente aya a realizar es en caso que se encuentren mas de dos facturas creditos y cada factura tiene sus respectivos movimientos y sus respectivos saldo con cada numero de factura.

Bueno hasta aquí por el momento he resuelto mi interrogante.

Saludos a Todos

novato_erick

ecfisa 23-11-2018 02:58:05

Hola.

Gracias por publicar tu solución ^\||/

Saludos :)


La franja horaria es GMT +2. Ahora son las 16:01:42.

Powered by vBulletin® Version 3.6.8
Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
Traducción al castellano por el equipo de moderadores del Club Delphi