How to replace two values from a single table

  • nadarajan_v

    You more than likely will get a tested T-SQL block of code if you posted your table definitions, some sample data following the instructions and using the T-SQL given in the article whose link is the first entry in my signature block.

    If everything seems to be going well, you have obviously overlooked something.

    Ron

    Please help us, help you -before posting a question please read[/url]
    Before posting a performance problem please read[/url]

  • I am working on assumptions about your table designs based on your description.

    Your query is asking for screen names this way:

    U.ScreenName AS OriginalPostBy

    U.ScreenName AS LastPostBy

    Where U = the TBS_UserDetails table.

    If TBS_UserDetails is designed the way I think it is, one e-mail address per

    EmailID value, and ScreenName appears to be coming from TBS_UserDetails, then

    your query will always return just one screen name.

    I think you need to have subqueries directly on the SELECT list like the

    following code...

    CREATE TABLE TBS_UserDetails

    (EmailID NVARCHAR(320)

    ,ScreenName NVARCHAR(32)

    ,CONSTRAINT pk_EmailID PRIMARY KEY (EmailID)

    )

    go

    INSERT INTO TBS_UserDetails

    (EmailID

    ,ScreenName

    )

    SELECT 'a@a.com', 'SQL Questions' UNION

    SELECT 'b@b.com', 'SQL Answers'

    go

    CREATE TABLE TBS_Posts

    (PostID INTEGER

    ,ParentPostID INTEGER

    ,OriginalPostBy NVARCHAR(320)

    ,LastPostBy NVARCHAR(320)

    ,LastPostDate DATETIME

    ,Title NVARCHAR(100)

    ,Body TEXT

    ,CONSTRAINT pk_TBS_Posts PRIMARY KEY (PostID)

    ,CONSTRAINT fk_TBS_Posts_TBS_Posts_ParentPostID

    FOREIGN KEY (ParentPostID)

    REFERENCES TBS_Posts (PostID)

    ,CONSTRAINT fk_TBS_Posts_TBS_UserDetails_EmailID_1

    FOREIGN KEY (OriginalPostBy)

    REFERENCES TBS_UserDetails (EmailID)

    ,CONSTRAINT fk_TBS_Posts_TBS_UserDetails_EmailID_2

    FOREIGN KEY (LastPostBy)

    REFERENCES TBS_UserDetails (EmailID)

    )

    go

    INSERT INTO TBS_Posts

    (PostID

    ,ParentPostID

    ,OriginalPostBy

    ,LastPostBy

    ,LastPostDate

    ,Title

    ,Body

    )

    SELECT 1, 1, 'a@a.com', 'a@a.com', '2011-02-01 00:00:00.000', 'My query', 'My query need help.' UNION

    SELECT 2, 1, 'a@a.com', 'b@b.com', '2011-02-01 00:10:00.000', 'My query', 'Post your ddl, data, and query so far.'

    go

    SELECT P1.PostID

    ,(SELECT U01.ScreenName

    FROM TBS_UserDetails as U01

    WHERE U01.EmailID = P1.OriginalPostBy) AS OriginalPostBy

    ,P1.ParentPostID

    ,P1.Title

    ,P1.Body

    ,P1.LastPostDate

    ,(SELECT U02.ScreenName

    FROM TBS_UserDetails as U02

    WHERE U02.EmailID = P1.LastPostBy) AS LastPostBy

    FROM TBS_Posts AS P1

    1 SQL Questions 1 My query My query need help. 2011-02-01 00:00:00.000 SQL Questions

    2 SQL Questions 1 My query Post your ddl, data, and query so far. 2011-02-01 00:10:00.000 SQL Answers

    These results do appear to return different e-mail addresses when the TBS_Posts table contains different e-mail addresses in the two columns in question, OriginalPostBy and LastPostBy.

    I apologize for any mistaken assumptions on my part on the design of your tables and nature of the date in question.

    Notes:

    By the way, I do not personally think it is a good idea to be storing an

    e-mail address in the TBS_Posts table, much less two different e-mail

    addresses. The tables should be Posters (or UserDetails, whatever name)

    and Posts. The Posts table would have a foreign key pointing at the primary

    key of the Posters table, which is where the e-mail address (and screen name)

    of each poster would be located.

  • Hello Chris_n_Osborne,

    Your assumption is correct and thank you so much for your code snippet. I was able to solve my issue. I agree with you that the table structure needs to be normalized properly. Since I am working on an existing project, unfortunately, I don't have much leeway :crying:

    Thanks

  • nadarajan_v (2/15/2011)


    Hello Chris_n_Osborne,

    Your assumption is correct and thank you so much for your code snippet. I was able to solve my issue.

    You're welcome. 😀

    nadarajan_v (2/15/2011)


    I agree with you that the table structure needs to be normalized properly. Since I am working on an existing project, unfortunately, I don't have much leeway :crying:

    Thanks

    It's usually that way.

Viewing 4 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply