Query help

  • Hi,

    I have a query that returns a ProposalId a RiskId and RiskTaken bit flag. I've setup some test data below:

    DECLARE @table TABLE

    (

    ProposalId INT,

    RiskId INT,

    RiskTaken BIT

    )

    INSERT INTO @table

    SELECT 1, 1, 1

    UNION ALL SELECT 1,2,0

    UNION ALL SELECT 1,3,0

    UNION ALL SELECT 2,1,0

    UNION ALL SELECT 2,2,0

    UNION ALL SELECT 2,3,0

    SELECT

    t.[ProposalId],

    t.[RiskId],

    t.[RiskTaken]

    FROM

    @table t

    Now, what'd i'd like is another column called ProposalTaken that should be a 1 where there is a risk for that proposal that has a risktaken flag of 1. Example results shown in the attachment.

    Is there a way to achieve this?

    Thanks,

    Simon



    MCSE: Data Platform
    MCSE: Business Intelligence
    Follow me on Twitter: @WazzTheBadger
    LinkedIn Profile: Simon Osborne

  • DECLARE @table TABLE

    (

    ProposalId INT,

    RiskId INT,

    RiskTaken BIT

    )

    INSERT INTO @table

    SELECT 1, 1, 1

    UNION ALL SELECT 1,2,0

    UNION ALL SELECT 1,3,0

    UNION ALL SELECT 2,1,0

    UNION ALL SELECT 2,2,0

    UNION ALL SELECT 2,3,0

    ;

    WITH ProposalRisk

    AS

    (SELECT DISTINCT ProposalId FROM @table WHERE RiskTaken = 1

    )

    SELECT

    t.[ProposalId],

    t.[RiskId],

    t.[RiskTaken],

    CASE

    WHEN pr.ProposalId IS NOT NULL THEN 1

    ELSE

    0

    END AS ProposalTaken

    FROM

    @table t

    LEFT OUTER JOIN ProposalRisk pr ON t.ProposalId = pr.ProposalId

    Looks like it should work

  • Hi,

    Thanks for you help.

    I've been playing with this, and you're right it does work but doesn't give me the solution to the problem i have. I've given @table as an example here to illustrate the problem. In my real world problem @table is actually the result of a complex query and isn't stored in a table (temporary or otherwise). I have many more columns than outlined above and the query returns ~40k rows.

    I was hoping to be able to do something in-line with a CROSS APPLY type solution but haven't been able to crack it. I could write the result of the query to a temporary or even a persisted table and then use the CTE as you suggest but there's write overhead invovled with that, that i'd like to avoid if possible.

    Is there a way to do this without a CTE or am I hoping for a solution that simply isn't possible?

    Thanks,

    Simon



    MCSE: Data Platform
    MCSE: Business Intelligence
    Follow me on Twitter: @WazzTheBadger
    LinkedIn Profile: Simon Osborne

  • s_osborne2 (1/23/2013)


    Hi,

    Thanks for you help.

    I've been playing with this, and you're right it does work but doesn't give me the solution to the problem i have. I've given @table as an example here to illustrate the problem. In my real world problem @table is actually the result of a complex query and isn't stored in a table (temporary or otherwise). I have many more columns than outlined above and the query returns ~40k rows.

    I was hoping to be able to do something in-line with a CROSS APPLY type solution but haven't been able to crack it. I could write the result of the query to a temporary or even a persisted table and then use the CTE as you suggest but there's write overhead invovled with that, that i'd like to avoid if possible.

    Is there a way to do this without a CTE or am I hoping for a solution that simply isn't possible?

    Thanks,

    Simon

    Actually the way you describe this a CTE is exactly what you want. If you use a cross apply you would have to requery your data anyway. This is exactly what CTEs were designed for.

    Here is the same solution but instead of selecting directly from the table variable I setup a CTE. You would just replace the first CTE query with your complex query.

    DECLARE @table TABLE

    (

    ProposalId INT,

    RiskId INT,

    RiskTaken BIT

    )

    INSERT INTO @table

    SELECT 1, 1, 1

    UNION ALL SELECT 1,2,0

    UNION ALL SELECT 1,3,0

    UNION ALL SELECT 2,1,0

    UNION ALL SELECT 2,2,0

    UNION ALL SELECT 2,3,0

    ;with CTE_AsQueryReplacement as

    (

    select * from @table --replace this with your complex query

    )

    ,

    ProposalRisk AS

    (SELECT DISTINCT ProposalId FROM CTE_AsQueryReplacement WHERE RiskTaken = 1

    )

    SELECT

    t.[ProposalId],

    t.[RiskId],

    t.[RiskTaken],

    CASE

    WHEN pr.ProposalId IS NOT NULL THEN 1

    ELSE

    0

    END AS ProposalTaken

    FROM

    CTE_AsQueryReplacement t

    LEFT OUTER JOIN ProposalRisk pr ON t.ProposalId = pr.ProposalId

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Absolutely spot on. Nice one Sean.

    Thanks,

    Simon



    MCSE: Data Platform
    MCSE: Business Intelligence
    Follow me on Twitter: @WazzTheBadger
    LinkedIn Profile: Simon Osborne

  • The kudos belongs to Michael Higgins. He provided the solution. I just suggested a way for you to fit it in with your system. 😀

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

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

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