December 14, 2017 at 8:26 am
Dear colleagues,
I got a very peculiar situation. Here is my code:
Declare @startdate as datetime
Declare @enddate as datetime
Declare @newfee as money
DeclaRE @oldfee as money
Set @startdate = '2014-09-01'
Set @enddate = '2017-08-31'
Set @newfee = 595.00
Set @oldfee = 795.00
select
n.ID as IndID,
n.FULL_NAME,
u.YAB,
CASE WHEN n.MEMBER_TYPE IN('NLS','SFI','SFINL','SI','SIF') THEN 'Sponsor' ELSE 'Nonsponsor' END as Sponsor,
CASE WHEN ((select SUM(TOTAL_PAYMENTS) from Orders where ST_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) < 0) THEN 0 ELSE (select SUM(TOTAL_PAYMENTS) from Orders where ST_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) END as "3-Year Spending",
CASE
WHEN DATEDIFF(YEAR, CAST(ISNULL(u.YAB,'2000') As Datetime), @enddate) < 3
THEN (select SUM(TOTAL_PAYMENTS) from Orders where ST_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) / (DATEDIFF(YEAR,CAST(ISNULL(u.YAB,'2000') As Datetime),@enddate))
ELSE (select SUM(TOTAL_PAYMENTS) from Orders where BT_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) / 3 END as average_annual,
n.WORK_PHONE,
n.EMAIL
from Name as n --inner join Orders as o on n.ID = o.BT_ID
/*
CROSS APPLY (SELECT TOP 1 *
FROM BM_OnlinePass_Subscription_Archive ba
WHERE ba.ClientID = n.ID
ORDER BY StartDate DESC) as b --on n.ID = b.clientID
*/
INNER JOIN UD_Indiv_Data as u on n.ID = u.ID
--LEFT OUTER JOIN BM_OnlinePass_Subscription_Archive as b on n.ID = b.clientID
where n.COMPANY_RECORD = 0
and Len(RTrim(LTrim(n.Full_Name))) > 0
and n.MEMBER_TYPE IN('NLS','SFI','SFINL','SI','SIF','NI','NIF','NL','SYSI','WEB')
and n.Status = 'A'
and (n.ID NOT IN(Select ClientID from BM_OnlinePass_Subscription) OR n.ID NOT IN(Select ClientID from BM_OnlinePass_Subscription_Archive))
In my case u.YAB has varchar datatype and sometimes has NULL value. What is peculiar this date conversion error I got when removed BM_OnlinePass_Subscription_Archive table. When this table was in a query I did not get any error.
Any idea why? Thank you.
December 14, 2017 at 8:39 am
rkordonsky 63916 - Thursday, December 14, 2017 8:26 AMDear colleagues,
I got a very peculiar situation. Here is my code:
Declare @startdate as datetime
Declare @enddate as datetime
Declare @newfee as money
DeclaRE @oldfee as money
Set @startdate = '2014-09-01'
Set @enddate = '2017-08-31'
Set @newfee = 595.00
Set @oldfee = 795.00select
n.ID as IndID,
n.FULL_NAME,
u.YAB,
CASE WHEN n.MEMBER_TYPE IN('NLS','SFI','SFINL','SI','SIF') THEN 'Sponsor' ELSE 'Nonsponsor' END as Sponsor,
CASE WHEN ((select SUM(TOTAL_PAYMENTS) from Orders where ST_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) < 0) THEN 0 ELSE (select SUM(TOTAL_PAYMENTS) from Orders where ST_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) END as "3-Year Spending",
CASE
WHEN DATEDIFF(YEAR, CAST(ISNULL(u.YAB,'2000') As Datetime), @enddate) < 3
THEN (select SUM(TOTAL_PAYMENTS) from Orders where ST_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) / (DATEDIFF(YEAR,CAST(ISNULL(u.YAB,'2000') As Datetime),@enddate))
ELSE (select SUM(TOTAL_PAYMENTS) from Orders where BT_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) / 3 END as average_annual,
n.WORK_PHONE,
n.EMAIL
from Name as n --inner join Orders as o on n.ID = o.BT_ID
/*
CROSS APPLY (SELECT TOP 1 *
FROM BM_OnlinePass_Subscription_Archive ba
WHERE ba.ClientID = n.ID
ORDER BY StartDate DESC) as b --on n.ID = b.clientID
*/
INNER JOIN UD_Indiv_Data as u on n.ID = u.ID
--LEFT OUTER JOIN BM_OnlinePass_Subscription_Archive as b on n.ID = b.clientID
where n.COMPANY_RECORD = 0
and Len(RTrim(LTrim(n.Full_Name))) > 0
and n.MEMBER_TYPE IN('NLS','SFI','SFINL','SI','SIF','NI','NIF','NL','SYSI','WEB')
and n.Status = 'A'
and (n.ID NOT IN(Select ClientID from BM_OnlinePass_Subscription) OR n.ID NOT IN(Select ClientID from BM_OnlinePass_Subscription_Archive))
In my case u.YAB has varchar datatype and sometimes has NULL value. What is peculiar this date conversion error I got when removed BM_OnlinePass_Subscription_Archive table. When this table was in a query I did not get any error.
Any idea why? Thank you.
Here is the error I got:
Msg 241, Level 16, State 1, Line 10
Conversion failed when converting date and/or time from character string.
December 14, 2017 at 9:01 am
What happens if you run the following query?
SELECT YAB
FROM UD_Indiv_Data
WHERE YAB IS NOT NULL
AND TRY_CAST( YAB AS DATETIME) IS NULL;
If you get rows, then those rows are not valid dates.
December 14, 2017 at 9:14 am
Luis Cazares - Thursday, December 14, 2017 9:01 AMWhat happens if you run the following query?
SELECT YAB
FROM UD_Indiv_Data
WHERE YAB IS NOT NULL
AND TRY_CAST( YAB AS DATETIME) IS NULL;
If you get rows, then those rows are not valid dates.
I got the following error:
Msg 242, Level 16, State 3, Line 1
The conversion of a varchar data type to a datetime data type resulted in an out-of-range value.
December 14, 2017 at 9:22 am
Luis Cazares - Thursday, December 14, 2017 9:01 AMWhat happens if you run the following query?
SELECT YAB
FROM UD_Indiv_Data
WHERE YAB IS NOT NULL
AND TRY_CAST( YAB AS DATETIME) IS NULL;
If you get rows, then those rows are not valid dates.
Some of Rows contain empty string.
December 14, 2017 at 9:36 am
rkordonsky 63916 - Thursday, December 14, 2017 9:22 AMLuis Cazares - Thursday, December 14, 2017 9:01 AMWhat happens if you run the following query?
SELECT YAB
FROM UD_Indiv_Data
WHERE YAB IS NOT NULL
AND TRY_CAST( YAB AS DATETIME) IS NULL;
If you get rows, then those rows are not valid dates.Some of Rows contain empty string.
Technically, that's not an empty string. It might contain a blank character like CHAR(0).
Here's an example:
WITH UD_Indiv_Data AS(
SELECT '' YAB UNION ALL
SELECT ' ' YAB UNION ALL
SELECT '20170115' YAB UNION ALL
SELECT '156431564' YAB UNION ALL
SELECT '20171301' YAB UNION ALL
SELECT '20171211 12:23' YAB UNION ALL
SELECT CHAR(0)
)
SELECT YAB,
ASCII(YAB) AS FirstCharASCII,
TRY_CAST( YAB AS DATETIME) AS DatetimeYAB
FROM UD_Indiv_Data
--WHERE YAB IS NOT NULL
--AND TRY_CAST( YAB AS DATETIME) IS NULL;
December 21, 2017 at 8:23 am
rkordonsky 63916 - Thursday, December 14, 2017 8:26 AMDear colleagues,
I got a very peculiar situation. Here is my code:
Declare @startdate as datetime
Declare @enddate as datetime
Declare @newfee as money
DeclaRE @oldfee as money
Set @startdate = '2014-09-01'
Set @enddate = '2017-08-31'
Set @newfee = 595.00
Set @oldfee = 795.00select
n.ID as IndID,
n.FULL_NAME,
u.YAB,
CASE WHEN n.MEMBER_TYPE IN('NLS','SFI','SFINL','SI','SIF') THEN 'Sponsor' ELSE 'Nonsponsor' END as Sponsor,
CASE WHEN ((select SUM(TOTAL_PAYMENTS) from Orders where ST_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) < 0) THEN 0 ELSE (select SUM(TOTAL_PAYMENTS) from Orders where ST_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) END as "3-Year Spending",
CASE
WHEN DATEDIFF(YEAR, CAST(ISNULL(u.YAB,'2000') As Datetime), @enddate) < 3
THEN (select SUM(TOTAL_PAYMENTS) from Orders where ST_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) / (DATEDIFF(YEAR,CAST(ISNULL(u.YAB,'2000') As Datetime),@enddate))
ELSE (select SUM(TOTAL_PAYMENTS) from Orders where BT_ID = n.ID and ORDER_DATE BETWEEN @startdate and @enddate) / 3 END as average_annual,
n.WORK_PHONE,
n.EMAIL
from Name as n --inner join Orders as o on n.ID = o.BT_ID
/*
CROSS APPLY (SELECT TOP 1 *
FROM BM_OnlinePass_Subscription_Archive ba
WHERE ba.ClientID = n.ID
ORDER BY StartDate DESC) as b --on n.ID = b.clientID
*/
INNER JOIN UD_Indiv_Data as u on n.ID = u.ID
--LEFT OUTER JOIN BM_OnlinePass_Subscription_Archive as b on n.ID = b.clientID
where n.COMPANY_RECORD = 0
and Len(RTrim(LTrim(n.Full_Name))) > 0
and n.MEMBER_TYPE IN('NLS','SFI','SFINL','SI','SIF','NI','NIF','NL','SYSI','WEB')
and n.Status = 'A'
and (n.ID NOT IN(Select ClientID from BM_OnlinePass_Subscription) OR n.ID NOT IN(Select ClientID from BM_OnlinePass_Subscription_Archive))
In my case u.YAB has varchar datatype and sometimes has NULL value. What is peculiar this date conversion error I got when removed BM_OnlinePass_Subscription_Archive table. When this table was in a query I did not get any error.
Any idea why? Thank you.
I'm pretty sure that the cause of the problem is that back when the CROSS APPLY was part of the query, it was effectively eliminating any rows where the YAB value was something other than a valid datetime string. You'll either have to update those "offending values", or use TRY_CAST or TRY_CONVERT instead, and move the ISNULL function outside of that cast or convert.
Steve (aka sgmunson) 🙂 🙂 🙂
Rent Servers for Income (picks and shovels strategy)
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply