August 14, 2009 at 4:22 am
Hi all,
I have a database in SQL Server 2000.
I run this query:
SELECT CODCTB, NOTA.NUMDU, TIPODLI, SOMA, MIN(SGTALIQDATA.CODLIQ) CODLIQ FROM
((SGTALIQDATA INNER JOIN LIQUIDACAO ON SGTALIQDATA.CODLIQ = LIQUIDACAO.CODLIQ)
INNER JOIN (SELECT SUM(IMPTRIB-IMPCOB) SOMA, NUMDU FROM (SGTALIQDATA
INNER JOIN LIQUIDACAO ON SGTALIQDATA.CODLIQ = LIQUIDACAO.CODLIQ)
GROUP BY NUMDU) as NOTA ON NOTA.NUMDU = SGTALIQDATA.NUMDU)
INNER JOIN (SELECT NUMDU, DATAEXPIRACAO_FINAL FROM
(SELECT NUMDU_STUF, MAX(DATAEXPIRACAO) DATAEXPIRACAO_FINAL FROM
( SELECT DISTINCT NUMDU, STUFF(NUMDU, 13, 2, RIGHT(NUMDU, 1))NUMDU_STUF, DATAEXPIRACAO FROM SGTALIQDATA
Where (IsNumeric(SUBSTRING(NUMDU, Len(NUMDU), 1)) = 0)
Union SELECT DISTINCT NUMDU, NUMDU NUMDU_STUF, DATAEXPIRACAO FROM SGTALIQDATA
WHERE (ISNUMERIC(SUBSTRING(NUMDU, LEN(NUMDU), 1))=1) AND DUORIGINAL IS NULL
Union SELECT DISTINCT NUMDU, DUORIGINAL NUMDU_STUF, DATAEXPIRACAO FROM SGTALIQDATA
WHERE (ISNUMERIC(SUBSTRING(NUMDU, LEN(NUMDU), 1))=1) AND LEN(DUORIGINAL)<14
Union SELECT DISTINCT NUMDU, ISNULL(STUFF(DUORIGINAL, LEN(DUORIGINAL)-1, 2, RIGHT(DUORIGINAL, 1)), NUMDU) NUMDU_STUF, DATAEXPIRACAO
FROM SGTALIQDATA WHERE (ISNUMERIC(SUBSTRING(NUMDU, LEN(NUMDU), 1))=1) AND LEN(DUORIGINAL)>=14 ) AS DATA_EXPIRA_DU1
GROUP BY NUMDU_STUF) AS X INNER JOIN (SELECT NUMDU, NUMDU_STUF FROM
( SELECT DISTINCT NUMDU, STUFF(NUMDU, 13, 2, RIGHT(NUMDU, 1))NUMDU_STUF, DATAEXPIRACAO FROM SGTALIQDATA
Where (IsNumeric(SUBSTRING(NUMDU, Len(NUMDU), 1)) = 0)
Union SELECT DISTINCT NUMDU, NUMDU NUMDU_STUF, DATAEXPIRACAO FROM SGTALIQDATA
WHERE (ISNUMERIC(SUBSTRING(NUMDU, LEN(NUMDU), 1))=1) AND DUORIGINAL IS NULL
Union SELECT DISTINCT NUMDU, DUORIGINAL NUMDU_STUF, DATAEXPIRACAO FROM SGTALIQDATA
WHERE (ISNUMERIC(SUBSTRING(NUMDU, LEN(NUMDU), 1))=1) AND LEN(DUORIGINAL)<14
Union SELECT DISTINCT NUMDU, ISNULL(STUFF(DUORIGINAL, LEN(DUORIGINAL)-1, 2, RIGHT(DUORIGINAL, 1)), NUMDU) NUMDU_STUF, DATAEXPIRACAO
FROM SGTALIQDATA WHERE (ISNUMERIC(SUBSTRING(NUMDU, LEN(NUMDU), 1))=1) AND LEN(DUORIGINAL)>=14 ) AS DATA_EXPIRA_DU2) AS Y
ON X.NUMDU_STUF = Y.NUMDU_STUF) AS ULTIMANOTA
ON NOTA.NUMDU = ULTIMANOTA.NUMDU
AND LIQUIDACAO.CodCR IS NULL AND SGTALIQDATA.CodCR IS NULL
AND (LIQUIDACAO.IMPTRIB <> LIQUIDACAO.IMPCOB) AND LIQUIDACAO.CodAnula IS NULL
AND ULTIMANOTA.DATAEXPIRACAO_FINAL < '2009-6-01'
GROUP BY CODCTB, NOTA.NUMDU, TIPODLI, SOMA ORDER BY NOTA.CODLIQ DESC
The query runs sucessfull. when i run it on the same database but in SQL Server 2005 (with the exact same columns and data) i receive this error:
Msg 207, Level 16, State 1, Line 30
Invalid column name 'CODLIQ'.
Can someone help, please?
thank you
August 14, 2009 at 4:34 am
can you post the table definitions for SGTALIQDATA and LIQUIDACAO from both the sql 2000 and the sql 2005 databases
August 14, 2009 at 4:57 am
what do you mean with tables definitions?
The field names and data types?
thank you
August 14, 2009 at 5:04 am
yes, if you use SSMS and go to the table, right click and produce a create script to a new window. then copy and paste that in to a reply on here. do that for both tables on both databases
August 14, 2009 at 7:10 am
SQL Server 2005 (script produced trought management studio):
table SGTALIQDATA:
USE [SGT]
GO
/****** Object: Table [dbo].[SGTALIQDATA] Script Date: 08/14/2009 13:59:52 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[SGTALIQDATA](
[CODLIQ] [int] NOT NULL,
[ANONOTAS] [int] NULL,
[ESTANCIA] [varchar](5) NULL,
[DATAEMISSAO] [datetime] NOT NULL,
[NUMDU] [varchar](20) NOT NULL,
[DATAEXPIRACAO] [datetime] NOT NULL,
[CODCTBIRREG] [int] NULL,
[NOMEFICH] [varchar](20) NULL,
[DUORIGINAL] [varchar](20) NULL,
[TIPOID] [int] NOT NULL CONSTRAINT [DF_SGTALIQDATA_TIPOID] DEFAULT (1),
[CODCR] [int] NULL,
[NUMLIVRE] [varchar](20) NULL,
[DUORIGINAL2] [varchar](20) NULL,
[SEPARADO] [varchar](20) NULL,
[CODDESP] [int] NULL,
[CODAREASERVICO] [int] NULL,
CONSTRAINT [IX_SGTALIQDATA] UNIQUE CLUSTERED
(
[CODLIQ] DESC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Armazena o nº da nota que originou a liquidação adicional' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'SGTALIQDATA', @level2type=N'COLUMN',@level2name=N'DUORIGINAL'
GO
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'ID utilizada na importacao do fich. 1=NIF, 2=RGC' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'SGTALIQDATA', @level2type=N'COLUMN',@level2name=N'TIPOID'
GO
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Armazena o nº da nota que originou a liquidação oficiosa (não adicional)' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'SGTALIQDATA', @level2type=N'COLUMN',@level2name=N'DUORIGINAL2'
GO
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Número do separado de bagagem' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'SGTALIQDATA', @level2type=N'COLUMN',@level2name=N'SEPARADO'
GO
ALTER TABLE [dbo].[SGTALIQDATA] WITH CHECK ADD CONSTRAINT [FK_SGTALIQDATA_AREASERVICO] FOREIGN KEY([CODAREASERVICO])
REFERENCES [dbo].[AREASERVICO] ([CODAREASERVICO])
GO
ALTER TABLE [dbo].[SGTALIQDATA] CHECK CONSTRAINT [FK_SGTALIQDATA_AREASERVICO]
GO
ALTER TABLE [dbo].[SGTALIQDATA] WITH NOCHECK ADD CONSTRAINT [FK_SGTALIQDATA_DESPACHANTES] FOREIGN KEY([CODDESP])
REFERENCES [dbo].[DESPACHANTES] ([codDesp])
GO
ALTER TABLE [dbo].[SGTALIQDATA] CHECK CONSTRAINT [FK_SGTALIQDATA_DESPACHANTES]
table Liquidacao:
/****** Object: Table [dbo].[LIQUIDACAO] Script Date: 08/14/2009 14:02:22 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[LIQUIDACAO](
[CODLIQ] [int] IDENTITY(1,1) NOT NULL,
[NUMLIQ] [varchar](50) NOT NULL,
[LANCLIQ] [int] NOT NULL,
[DATALIQ] [datetime] NOT NULL,
[HORALIQ] [datetime] NOT NULL,
[VALORTRIB] [float] NOT NULL,
[CODCTB] [int] NOT NULL,
[CODRF] [int] NULL,
[CODFUNC] [int] NULL,
[DATALIQANUL] [datetime] NULL,
[HORALIQANUL] [datetime] NULL,
[CODARF] [int] NULL,
[CODAFUNC] [int] NULL,
[DIASJUROS] [float] NULL,
[TAXAMENSALJUROS] [float] NULL,
[CODIMP] [int] NULL,
[ANOLIQ] [varchar](50) NOT NULL,
[DESCPERIODO] [varchar](50) NOT NULL,
[CODPERIODO] [int] NULL,
[CODTLIQ1] [int] NULL,
[CODTLIQ2] [int] NULL,
[TXTRIB] [float] NULL,
[IMPTRIB] [float] NOT NULL,
[VALORJUROS] [float] NULL,
[JUROSPAGAR] [float] NULL,
[MULTAID] [char](50) NULL,
[MULTAVALOR] [float] NULL,
[CUSTAID] [char](50) NULL,
[CUSTAVALOR] [float] NULL,
[IMPCOB] [float] NULL CONSTRAINT [DF__LIQUIDACA__IMPCO__48CFD27E] DEFAULT (0),
[IMPPAGAR] [float] NULL CONSTRAINT [DF__LIQUIDACA__IMPPA__49C3F6B7] DEFAULT (0),
[CODDAR] [int] NULL,
[CODNOTIFICA] [int] NULL,
[CODCR] [int] NULL,
[CODTPAG] [int] NULL,
[PAGEFECT] [float] NOT NULL CONSTRAINT [DF__LIQUIDACA__PAGEF__4AB81AF0] DEFAULT (0),
[CODDLIORIG] [int] NULL,
[TIPODLI] [float] NOT NULL,
[CODCRORIG] [int] NULL,
[CODANULA] [int] NULL,
CONSTRAINT [PK__LIQUIDACAO__46E78A0C] PRIMARY KEY CLUSTERED
(
[CODLIQ] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY],
CONSTRAINT [AK_LIQUIDACAO_LANCLIQ] UNIQUE NONCLUSTERED
(
[LANCLIQ] ASC,
[DATALIQ] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY],
CONSTRAINT [AK_LIQUIDACAO_NUMLIQ] UNIQUE NONCLUSTERED
(
[NUMLIQ] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODAF__3864608B] FOREIGN KEY([CODAFUNC])
REFERENCES [dbo].[FUNCIONARIO] ([CODFUNC])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODAF__3864608B]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODCR__32AB8735] FOREIGN KEY([CODCR])
REFERENCES [dbo].[CRELAXE] ([CODCR])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODCR__32AB8735]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODCR__339FAB6E] FOREIGN KEY([CODCRORIG])
REFERENCES [dbo].[CRELAXE] ([CODCR])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODCR__339FAB6E]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODDL__489AC854] FOREIGN KEY([CODDLIORIG])
REFERENCES [dbo].[LIQUIDACAO] ([CODLIQ])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODDL__489AC854]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODFU__395884C4] FOREIGN KEY([CODFUNC])
REFERENCES [dbo].[FUNCIONARIO] ([CODFUNC])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODFU__395884C4]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODIM__40F9A68C] FOREIGN KEY([CODIMP])
REFERENCES [dbo].[IMPOSTO] ([CODIMP])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODIM__40F9A68C]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODNO__4E53A1AA] FOREIGN KEY([CODNOTIFICA])
REFERENCES [dbo].[NOTIFICACAO] ([CODNOTIFICA])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODNO__4E53A1AA]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODPE__51300E55] FOREIGN KEY([CODPERIODO])
REFERENCES [dbo].[PERIODICIDADE] ([CODPERIODO])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODPE__51300E55]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODTL__531856C7] FOREIGN KEY([CODTLIQ2])
REFERENCES [dbo].[TLIQUIDACAO] ([CODTLIQ])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODTL__531856C7]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODTP__55F4C372] FOREIGN KEY([CODTPAG])
REFERENCES [dbo].[TPAGAMENTO] ([CODTPAG])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODTP__55F4C372]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [CK__LIQUIDACA__CODTL__47DBAE45] CHECK (([CODTLIQ1] = 1 or [CODTLIQ1] = 0))
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [CK__LIQUIDACA__CODTL__47DBAE45]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [CK__LIQUIDACA__PAGEF__4BAC3F29] CHECK (([PAGEFECT] = 1 or [PAGEFECT] = 0))
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [CK__LIQUIDACA__PAGEF__4BAC3F29]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [CK__LIQUIDACA__TIPOD__4CA06362] CHECK (([TIPODLI] = 1 or [TIPODLI] = 0))
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [CK__LIQUIDACA__TIPOD__4CA06362]
Script SQL Server 2000 (trought management studio):
table SGTALIQDATA:
USE [SGT]
GO
/****** Object: Table [dbo].[SGTALIQDATA] Script Date: 08/14/2009 14:07:44 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[SGTALIQDATA](
[CODLIQ] [int] NOT NULL,
[ANONOTAS] [int] NULL,
[ESTANCIA] [varchar](5) NULL,
[DATAEMISSAO] [datetime] NOT NULL,
[NUMDU] [varchar](20) NOT NULL,
[DATAEXPIRACAO] [datetime] NOT NULL,
[CODCTBIRREG] [int] NULL,
[NOMEFICH] [varchar](20) NULL,
[DUORIGINAL] [varchar](20) NULL,
[TIPOID] [int] NOT NULL CONSTRAINT [DF_SGTALIQDATA_TIPOID] DEFAULT (1),
[CODCR] [int] NULL,
[NUMLIVRE] [varchar](20) NULL,
[DUORIGINAL2] [varchar](20) NULL,
[SEPARADO] [varchar](20) NULL,
[CODDESP] [int] NULL,
[CODAREASERVICO] [int] NULL,
CONSTRAINT [IX_SGTALIQDATA] UNIQUE CLUSTERED
(
[CODLIQ] DESC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Armazena o nº da nota que originou a liquidação adicional' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'SGTALIQDATA', @level2type=N'COLUMN',@level2name=N'DUORIGINAL'
GO
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'ID utilizada na importacao do fich. 1=NIF, 2=RGC' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'SGTALIQDATA', @level2type=N'COLUMN',@level2name=N'TIPOID'
GO
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Armazena o nº da nota que originou a liquidação oficiosa (não adicional)' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'SGTALIQDATA', @level2type=N'COLUMN',@level2name=N'DUORIGINAL2'
GO
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Número do separado de bagagem' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'SGTALIQDATA', @level2type=N'COLUMN',@level2name=N'SEPARADO'
GO
ALTER TABLE [dbo].[SGTALIQDATA] WITH CHECK ADD CONSTRAINT [FK_SGTALIQDATA_AREASERVICO] FOREIGN KEY([CODAREASERVICO])
REFERENCES [dbo].[AREASERVICO] ([CODAREASERVICO])
GO
ALTER TABLE [dbo].[SGTALIQDATA] CHECK CONSTRAINT [FK_SGTALIQDATA_AREASERVICO]
GO
ALTER TABLE [dbo].[SGTALIQDATA] WITH NOCHECK ADD CONSTRAINT [FK_SGTALIQDATA_DESPACHANTES] FOREIGN KEY([CODDESP])
REFERENCES [dbo].[DESPACHANTES] ([codDesp])
GO
ALTER TABLE [dbo].[SGTALIQDATA] CHECK CONSTRAINT [FK_SGTALIQDATA_DESPACHANTES]
table liquidacao:
USE [SGT]
GO
/****** Object: Table [dbo].[LIQUIDACAO] Script Date: 08/14/2009 14:08:44 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[LIQUIDACAO](
[CODLIQ] [int] IDENTITY(1,1) NOT NULL,
[NUMLIQ] [varchar](50) NOT NULL,
[LANCLIQ] [int] NOT NULL,
[DATALIQ] [datetime] NOT NULL,
[HORALIQ] [datetime] NOT NULL,
[VALORTRIB] [float] NOT NULL,
[CODCTB] [int] NOT NULL,
[CODRF] [int] NULL,
[CODFUNC] [int] NULL,
[DATALIQANUL] [datetime] NULL,
[HORALIQANUL] [datetime] NULL,
[CODARF] [int] NULL,
[CODAFUNC] [int] NULL,
[DIASJUROS] [float] NULL,
[TAXAMENSALJUROS] [float] NULL,
[CODIMP] [int] NULL,
[ANOLIQ] [varchar](50) NOT NULL,
[DESCPERIODO] [varchar](50) NOT NULL,
[CODPERIODO] [int] NULL,
[CODTLIQ1] [int] NULL,
[CODTLIQ2] [int] NULL,
[TXTRIB] [float] NULL,
[IMPTRIB] [float] NOT NULL,
[VALORJUROS] [float] NULL,
[JUROSPAGAR] [float] NULL,
[MULTAID] [char](50) NULL,
[MULTAVALOR] [float] NULL,
[CUSTAID] [char](50) NULL,
[CUSTAVALOR] [float] NULL,
[IMPCOB] [float] NULL CONSTRAINT [DF__LIQUIDACA__IMPCO__48CFD27E] DEFAULT (0),
[IMPPAGAR] [float] NULL CONSTRAINT [DF__LIQUIDACA__IMPPA__49C3F6B7] DEFAULT (0),
[CODDAR] [int] NULL,
[CODNOTIFICA] [int] NULL,
[CODCR] [int] NULL,
[CODTPAG] [int] NULL,
[PAGEFECT] [float] NOT NULL CONSTRAINT [DF__LIQUIDACA__PAGEF__4AB81AF0] DEFAULT (0),
[CODDLIORIG] [int] NULL,
[TIPODLI] [float] NOT NULL,
[CODCRORIG] [int] NULL,
[CODANULA] [int] NULL,
CONSTRAINT [PK__LIQUIDACAO__46E78A0C] PRIMARY KEY CLUSTERED
(
[CODLIQ] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY],
CONSTRAINT [AK_LIQUIDACAO_LANCLIQ] UNIQUE NONCLUSTERED
(
[LANCLIQ] ASC,
[DATALIQ] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY],
CONSTRAINT [AK_LIQUIDACAO_NUMLIQ] UNIQUE NONCLUSTERED
(
[NUMLIQ] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODAF__3864608B] FOREIGN KEY([CODAFUNC])
REFERENCES [dbo].[FUNCIONARIO] ([CODFUNC])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODAF__3864608B]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODCR__32AB8735] FOREIGN KEY([CODCR])
REFERENCES [dbo].[CRELAXE] ([CODCR])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODCR__32AB8735]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODCR__339FAB6E] FOREIGN KEY([CODCRORIG])
REFERENCES [dbo].[CRELAXE] ([CODCR])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODCR__339FAB6E]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODDL__489AC854] FOREIGN KEY([CODDLIORIG])
REFERENCES [dbo].[LIQUIDACAO] ([CODLIQ])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODDL__489AC854]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODFU__395884C4] FOREIGN KEY([CODFUNC])
REFERENCES [dbo].[FUNCIONARIO] ([CODFUNC])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODFU__395884C4]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODIM__40F9A68C] FOREIGN KEY([CODIMP])
REFERENCES [dbo].[IMPOSTO] ([CODIMP])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODIM__40F9A68C]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODNO__4E53A1AA] FOREIGN KEY([CODNOTIFICA])
REFERENCES [dbo].[NOTIFICACAO] ([CODNOTIFICA])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODNO__4E53A1AA]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODPE__51300E55] FOREIGN KEY([CODPERIODO])
REFERENCES [dbo].[PERIODICIDADE] ([CODPERIODO])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODPE__51300E55]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODTL__531856C7] FOREIGN KEY([CODTLIQ2])
REFERENCES [dbo].[TLIQUIDACAO] ([CODTLIQ])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODTL__531856C7]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [FK__LIQUIDACA__CODTP__55F4C372] FOREIGN KEY([CODTPAG])
REFERENCES [dbo].[TPAGAMENTO] ([CODTPAG])
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [FK__LIQUIDACA__CODTP__55F4C372]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [CK__LIQUIDACA__CODTL__47DBAE45] CHECK (([CODTLIQ1] = 1 or [CODTLIQ1] = 0))
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [CK__LIQUIDACA__CODTL__47DBAE45]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [CK__LIQUIDACA__PAGEF__4BAC3F29] CHECK (([PAGEFECT] = 1 or [PAGEFECT] = 0))
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [CK__LIQUIDACA__PAGEF__4BAC3F29]
GO
ALTER TABLE [dbo].[LIQUIDACAO] WITH NOCHECK ADD CONSTRAINT [CK__LIQUIDACA__TIPOD__4CA06362] CHECK (([TIPODLI] = 1 or [TIPODLI] = 0))
GO
ALTER TABLE [dbo].[LIQUIDACAO] CHECK CONSTRAINT [CK__LIQUIDACA__TIPOD__4CA06362]
thank you
August 14, 2009 at 7:18 am
it's your order by, your are referencing an alias.
change it to "ORDER BY 5 DESC" instead of "ORDER BY NOTA.CODLIQ DESC"
August 14, 2009 at 7:42 am
but why does it funtion in SQL Server 2000 and don't work in 2005?
I don't understand why chande from nota..... to 5
Where is the number 5 in my table definition?
thank you.
August 14, 2009 at 8:11 am
I suspect SQL2005 does better syntax checking.
Your derived table, NOTA, only returns the columns SOMA and NUMDU. so
ORDER BY NOTA.CODLIQ DESC
does not make sense.
SQL2000 must try to find any column called CODLIQ while SQL2005 throws the syntax error.
As ORDER BY 5 DESC will be depreciated in future versions of TSQL, I would use:
ORDER BY CODLIQ DESC
ps ORDER BY 5 means order by the fifth column in the result set.
August 14, 2009 at 8:21 am
ok, thank you very mutch.
I have other question related to the same problem.
I now can run the query, but in SQL Server 2000 this query executes in 2 minutes.
When i run the query in SQL server 2005 the query starts executing , but it don't stops.
It is traing to execute during several time 40 minutes and nothing yet (no results).
Can you help pelase?
thank you
August 14, 2009 at 8:27 am
As ORDER BY 5 DESC will be depreciated in future versions of TSQL, I would use
Didn't know this. Good to know.
ORDER BY CODLIQ DESC
For some reason I was thinking you had to use the non aliased part of the column (which is why I did 5). This makes more sense. Don't do what I said 🙂
August 14, 2009 at 8:34 am
sorry but i dind't undesrtud... 🙁
August 14, 2009 at 9:46 am
The query in 2000 run in 2 minutes.
In SQL Server 2005 (after i repleace to order by codliq or order by 5) executes but it does not finish.
Can you help please?
thank you
August 14, 2009 at 9:52 am
river (8/14/2009)
ok, thank you very mutch.I have other question related to the same problem.
I now can run the query, but in SQL Server 2000 this query executes in 2 minutes.
When i run the query in SQL server 2005 the query starts executing , but it don't stops.
It is traing to execute during several time 40 minutes and nothing yet (no results).
Can you help pelase?
thank you
Given the complexity, I think only you will be able to optimize the query.
All those DISTINCTs and UNIONs look very dodgy. Are you sure it produces the required result?
Looking briefly at the code you may be able to simplify it along the following lines:
SELECT
codctb
,nota.numdu
,tipodli
,soma
,MIN(sgtaliqdata.codliq) AS codliq
FROM sgtaliqdata
JOIN liquidacao
ON sgtaliqdata.codliq = liquidacao.codliq
JOIN
(
SELECT SUM(imptrib - impcob) AS soma
,numdu
FROM sgtaliqdata
JOIN liquidacao
ON sgtaliqdata.codliq = liquidacao.codliq
-- ?????
--WHERE liquidacao.codcr IS NULL
--AND sgtaliqdata.codcr IS NULL
--AND liquidacao.imptrib liquidacao.impcob
--AND liquidacao.codanula IS NULL
--AND ultimanota.dataexpiracao_final < '20090601'
GROUP BY numdu
) AS nota
ON nota.numdu = sgtaliqdata.numdu
JOIN
(
SELECT DISTINCT
numdu
,MAX(dataexpiracao) OVER (PARTITION BY numdu_stuf) AS dataexpiracao_final
FROM
(
SELECT numdu
,CASE
WHEN N.N = 1
THEN STUFF(numdu, 13, 2, RIGHT(numdu,1))
WHEN N.N = 2 AND duoriginal IS NULL
THEN numdu
WHEN N.N = 3 AND LEN(duoriginal) = 14
THEN ISNULL(STUFF(duoriginal,LEN(duoriginal) - 1,2,RIGHT(duoriginal,1)), numdu)
END AS numdu_stuf
,dataexpiracao
FROM sgtaliqdata S
CROSS JOIN
(
SELECT 1 UNION ALL
SELECT 2 UNION ALL
SELECT 3 UNION ALL
SELECT 4
) N(N)
WHERE ISNUMERIC(RIGHT(numdu, 1)) = 1
) D
WHERE numdu_stuf IS NOT NULL
) AS ultimanota
ON nota.numdu = ultimanota.numdu
AND liquidacao.codcr IS NULL
AND sgtaliqdata.codcr IS NULL
AND liquidacao.imptrib liquidacao.impcob
AND liquidacao.codanula IS NULL
AND ultimanota.dataexpiracao_final < '20090601'
GROUP BY codctb,
nota.numdu,
tipodli,
soma
ORDER BY codliq DESC
Good luck...
ps I was assuming that you have updated the STATS in SQL2005. You may want to check that you have.
Viewing 13 posts - 1 through 12 (of 12 total)
You must be logged in to reply to this topic. Login to reply