December 8, 2008 at 11:21 pm
I have 2 tables in a one to many relationship, they are subscriber, and SEND_COLLEAGUE_CONTACTS.
one subscriber has many contacts.
using the query below i get the userid and the amount of contacts they have.
SELECT subscribers.userid, Count(SEND_COLLEAGUE_CONTACTS.colleagueID) AS numOfColleagues
FROM subscribers
LEFT JOIN SEND_COLLEAGUE_CONTACTS ON SEND_COLLEAGUE_CONTACTS.User_ID = subscribers.userid
GROUP BY subscribers.userid
What i want to do is record this number in the subscribers table in a column called ColleagueLimit.
the query im looking for is basically :
update subscribers set ColleagueLimit = numOfColleagues where userid is common
but this is turning out to be more difficult that i thought.
December 9, 2008 at 12:22 am
Either of these would do it. My preference is for the second style because it's easier to test.
UPDATE s SET ColleagueLimit = (SELECT Count(c.colleagueID) AS numOfColleagues
FROM SEND_COLLEAGUE_CONTACTS c
WHERE c.[User_ID] = s.userid)
FROM subscribers s
UPDATE s SET ColleagueLimit = d.numOfColleagues
FROM subscribers s
LEFT JOIN (SELECT [User_ID], Count(c.colleagueID) AS numOfColleagues
FROM SEND_COLLEAGUE_CONTACTS
GROUP BY [User_ID]
) d ON d.[User_ID] = s.userid
Cheers
ChrisM
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
December 9, 2008 at 12:29 am
Thanks for the quick response and the help.
๐
Viewing 3 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply