SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to use NOT IN or Not Exist custom in Datetime?


How to use NOT IN or Not Exist custom in Datetime?

Author
Message
ppc493
ppc493
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 47
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. Smile
Eugene Elutin
Eugene Elutin
SSCertifiable
SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)

Group: General Forum Members
Points: 5034 Visits: 5478
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!":-D
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
ppc493
ppc493
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 47
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. :-P
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search