Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

How to use NOT IN or Not Exist custom in Datetime? Expand / Collapse
Author
Message
Posted Monday, December 10, 2012 10:53 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, April 29, 2013 9:44 AM
Points: 14, Visits: 46
i use 2 table, i want first table not data in table two of show on to database.

Ex.
"filesTA"


EmpNo | ChkDate
00001 | 2012-10-01 00:00:00.000
00001 | 2012-10-02 00:00:00.000
00001 | 2012-10-03 00:00:00.000
00001 | 2012-10-04 00:00:00.000
00001 | 2012-10-05 00:00:00.000


"SalaryDay2"
sEmpNo | sDate
00001 | 2012-10-01 00:00:00.000
00001 | 2012-10-02 00:00:00.000


When i select datetime between 2012-10-01 and 2012-10-05
i need output:


sEmpNo | sDate
00001 | 2012-10-03 00:00:00.000
00001 | 2012-10-04 00:00:00.000
00001 | 2012-10-05 00:00:00.000


this code:

SELECT tf.EmpNo,tf.ChkDate
FROM filesTA tf
WHERE tf.ChkDate NOT IN(
SELECT sd2.sDate
FROM SalaryDay2 sd2
WHERE Convert(nvarchar(10),sd2.sDate,126) Between '2012-10-01' and '2012-10-05'
)


please help me. thanks you for you time. :)
Post #1394711
Posted Monday, December 10, 2012 11:16 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Friday, July 4, 2014 3:55 AM
Points: 2,836, Visits: 5,062
Hope that following should help you:


SELECT tf.EmpNo, tf.ChkDate
FROM filesTA tf
WHERE tf.ChkDate BETWEEN '20121001' AND '20121005'
AND NOT EXISTS (SELECT 1 FROM SalaryDay2 sd2
WHERE sd2.sEmpNo = tf.EmpNo
AND sd2.sDate = tf.ChkDate)



Please note:
1. Never convert datetime to anything else (varchar or int) for datetime comparison.
If your SalaryDay2.sDate is varchar, convert it to datetime instead (or it will be properly implicitly converted if it's in ISO)
2. Note the format I've used - it's one of possible ISO variations: Year then Month then Day. You can use '1 Oct 2012', it will also work perfectly as month is explicitly known.
3. Used BETWEEN will only work properly if your datetime values do not contain time part. Otherwise, you should use greater-than-or-equal-to and less-than in WHERE clause for datetime filtering:

WHERE tf.ChkDate >= '20121001' AND tf.ChkDate < '20121006' --note the "to" boundary...


_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!"
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Post #1394718
Posted Monday, December 10, 2012 12:26 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, April 29, 2013 9:44 AM
Points: 14, Visits: 46
Eugene Elutin (12/10/2012)
Hope that following should help you:


SELECT tf.EmpNo, tf.ChkDate
FROM filesTA tf
WHERE tf.ChkDate BETWEEN '20121001' AND '20121005'
AND NOT EXISTS (SELECT 1 FROM SalaryDay2 sd2
WHERE sd2.sEmpNo = tf.EmpNo
AND sd2.sDate = tf.ChkDate)



Please note:
1. Never convert datetime to anything else (varchar or int) for datetime comparison.
If your SalaryDay2.sDate is varchar, convert it to datetime instead (or it will be properly implicitly converted if it's in ISO)
2. Note the format I've used - it's one of possible ISO variations: Year then Month then Day. You can use '1 Oct 2012', it will also work perfectly as month is explicitly known.
3. Used BETWEEN will only work properly if your datetime values do not contain time part. Otherwise, you should use greater-than-or-equal-to and less-than in WHERE clause for datetime filtering:

WHERE tf.ChkDate >= '20121001' AND tf.ChkDate < '20121006' --note the "to" boundary...



Oh, thanks so much! i'm learnings this news.
Post #1394751
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse