I have used this query in SSMS and get correct Result
select EntityId,EntityName,WellType,ProductionDate,EffectiveDate,Field,CondyMeasured,OilMeasured,WaterMeasured,CGRComponentRatio,WGRComponentRatio from
(select EntityId,EntityName,WellType,ProductionDate,EffectiveDate,Field,CondyMeasured,OilMeasured,WaterMeasured,CGRComponentRatio,WGRComponentRatio
,row_number() over(partition by EntityId,ProductionDate order by EntityId,ProductionDate,EffectiveDate desc) as roworder from
(select * from (SELECT FDCWellRecords.EntityId,FDCWellRecords.WellType,FDCWellRecords.ProductionDate,FDCWellRecords.EntityName,Field,CondyMeasured,OilMeasured,WaterMeasured,EffectiveDate,CGRComponentRatio,
WGRComponentRatio FROM FDCWellRecords inner Join FDCComponentRatio on FDCWellRecords.EntityId = FDCComponentRatio.EntityId ) temp where temp.EffectiveDate is not null and temp.WellType = ‘Effluent’) temp1 where ProductionDate >= EffectiveDate) temp2 where roworder = 1
The SQL in the profile is different from what you supplied in the comments. Please run the below query in Dremio and in SSMS and include a screenshot of the results with the rownumber, ProductionDate and EffectiveDate clearly visible in each.
select
EntityId,
EntityName,
WellType,
ProductionDate,
EffectiveDate,
Field,
CondyMeasured,
OilMeasured,
WaterMeasured,
CGRComponentRatio,
WGRComponentRatio
from
(select
EntityId,
EntityName,
WellType,
ProductionDate,
EffectiveDate,
Field,
CondyMeasured,
OilMeasured,
WaterMeasured,
CGRComponentRatio,
WGRComponentRatio ,
row_number() over(partition
by
EntityId,
ProductionDate
order by
EntityId,
ProductionDate,
EffectiveDate desc) as roworder
from
(select
*
from
(SELECT
FDCWellRecords.EntityId,
FDCWellRecords.WellType,
FDCWellRecords.ProductionDate,
FDCWellRecords.EntityName,
Field,
CondyMeasured,
OilMeasured,
WaterMeasured,
EffectiveDate,
CGRComponentRatio,
WGRComponentRatio
FROM
FDCWellRecords
inner Join
FDCComponentRatio
on FDCWellRecords.EntityId = FDCComponentRatio.EntityId ) temp
where
temp.EffectiveDate is not null
and temp.WellType = ‘Effluent’
) temp1
where
ProductionDate >= EffectiveDate) temp2
where
roworder = 1
This is the query that Dremio is pushing down into the MSSQL source:
SELECT
[EntityId] COLLATE LATIN1_GENERAL_BIN2 AS [EntityId],
[EntityName] COLLATE LATIN1_GENERAL_BIN2 AS [EntityName],
CAST('Effluent' COLLATE LATIN1_GENERAL_BIN2 AS VARCHAR(8000)) AS [WellType],
[ProductionDate],
[EffectiveDate],
[Field] COLLATE LATIN1_GENERAL_BIN2 AS [Field],
[CondyMeasured],
[OilMeasured],
[WaterMeasured],
[CGRComponentRatio],
[WGRComponentRatio]
FROM
(SELECT
[EntityId] COLLATE LATIN1_GENERAL_BIN2 AS [EntityId],
[EntityName] COLLATE LATIN1_GENERAL_BIN2 AS [EntityName],
CAST('Effluent' COLLATE LATIN1_GENERAL_BIN2 AS VARCHAR(8000)) AS [WellType],
[ProductionDate],
[EffectiveDate],
[Field] COLLATE LATIN1_GENERAL_BIN2 AS [Field],
[CondyMeasured],
[OilMeasured],
[WaterMeasured],
[CGRComponentRatio],
[WGRComponentRatio],
ROW_NUMBER() OVER (PARTITION
BY
[EntityId] COLLATE LATIN1_GENERAL_BIN2,
[ProductionDate]
ORDER BY
CASE
WHEN [EntityId] COLLATE LATIN1_GENERAL_BIN2 IS NULL THEN 1
ELSE 0
END,
[EntityId] COLLATE LATIN1_GENERAL_BIN2,
CASE
WHEN [ProductionDate] IS NULL THEN 1
ELSE 0
END,
[ProductionDate],
CASE
WHEN [EffectiveDate] IS NULL THEN 1
ELSE 0
END DESC,
[EffectiveDate]) AS [roworder]
FROM
(SELECT
[EntityId] COLLATE LATIN1_GENERAL_BIN2 AS [EntityId],
CAST('Effluent' COLLATE LATIN1_GENERAL_BIN2 AS VARCHAR(8000)) AS [WellType],
[ProductionDate],
[EntityName] COLLATE LATIN1_GENERAL_BIN2 AS [EntityName],
[Field] COLLATE LATIN1_GENERAL_BIN2 AS [Field],
[CondyMeasured],
[OilMeasured],
[WaterMeasured],
[EffectiveDate],
[CGRComponentRatio],
[WGRComponentRatio]
FROM
(SELECT
[FDCWellRecords].[EntityId] COLLATE LATIN1_GENERAL_BIN2 AS [EntityId],
[FDCWellRecords].[WellType] COLLATE LATIN1_GENERAL_BIN2 AS [WellType],
[FDCWellRecords].[ProductionDate],
[FDCWellRecords].[EntityName] COLLATE LATIN1_GENERAL_BIN2 AS [EntityName],
[FDCWellRecords].[Field] COLLATE LATIN1_GENERAL_BIN2 AS [Field],
[FDCWellRecords].[CondyMeasured],
[FDCWellRecords].[OilMeasured],
[FDCWellRecords].[WaterMeasured],
[FDCComponentRatio].[EffectiveDate],
[FDCComponentRatio].[CGRComponentRatio],
[FDCComponentRatio].[WGRComponentRatio]
FROM
[tourmalineqadb].[dbo].[FDCWellRecords]
INNER JOIN
[tourmalineqadb].[dbo].[FDCComponentRatio]
ON [FDCWellRecords].[EntityId] COLLATE LATIN1_GENERAL_BIN2 = [FDCComponentRatio].[EntityId] COLLATE LATIN1_GENERAL_BIN2) AS [t]
WHERE
[t].[WellType] COLLATE LATIN1_GENERAL_BIN2 = 'Effluent' COLLATE LATIN1_GENERAL_BIN2
AND [t].[EffectiveDate] IS NOT NULL
) AS [t]
WHERE
[ProductionDate] >= [EffectiveDate]) AS [t]
WHERE
[roworder] = 1
Does this give the same results as Dremio when you submit it with SSMS (I’m assuming it will).
Do you have any special options set, like “Enable legacy dialect”?
Hi @Vikash_Singh, apologies for the very late response here.
Dremio orders the null values differently than SQL Server; Dremio ranks them “highest” while MSSQL ranks them lowest. So when Dremio pushes down a query into the MSSQL source, it changes the query to make sure the records sent back are ordered as Dremio would order them.