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


passing a variable to CTE in a view


passing a variable to CTE in a view

Author
Message
Alan.B
Alan.B
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13268 Visits: 8001

...but just came to know that our application/framework does not support procedures of functions


Just a thought...

This might not help with the hierarchy situation but may help you get around your application's function limitation (which is terrible) in the future. You said the application limits you to views but can those views contain functions? You can use functions in a view. Using Jeff's suggestion: If you had a parameter table you could use a function like this:


CREATE VIEW dbo.sneakyWayToUseAFunction
AS

SELECT iTVF.*
FROM dbo.parameter
CROSS APPLY dbo.<usefulFunction>(parameter.val) AS iTVF



-- Alan Burstein



Best practices for getting help on SQLServerCentral
Need to split a string? Try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL 2012+)
Need a pattern-based splitter? Try PatternSplitCM
Need to remove or replace those unwanted characters? Try PatExclude8K and PatReplace8K.

"I can't stress enough the importance of switching from a 'sequential files' mindset to 'set-based' thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. " -- Itzek Ben-Gan 2001
mister.magoo
mister.magoo
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10525 Visits: 7891
pmadhavapeddi22 (1/21/2014)
Hi ,

I have a view which contains a CTE and I need to pass the parameter inside the CTE.
our application is not accepting sps or functions. Please help me



You don't actually need to do anything special other than make sure your party_id is passed through untouched in the cte/view...

All you need to do is include party_id in the anchor and the union, you can alias it, but make sure it is present in both parts of the rCTE.

Here is your code again , with that change:


create view yourView
as

WITH PartyHierarchy( party_id,reporting_to_party_id,level,base_id)AS
(
select party_id,reporting_to_party_id, 0, party_id as base_id
from table_a
union all
select a.party_id,a.reporting_to_party_id,level+1, b.base_id
from table_a a
inner join PartyHierarchy b ON b.party_id=a.reporting_to_party_id
)
select H.party_id
,H.reporting_to_party_id
,pp.last_name as 'SourceParty'
,ppb.last_name as businessEntity
,prt.code as RelationshipType
,ps.name as state
,ppt.ID as toPartyId
,ppt.last_name as destinationParty
,pstat.display_name as status
,ppr.effective_date as effectiveDate
--,level
--,party_id_from
--,party_id_to
, base_id
from PartyHierarchy H
inner join table_a W ON H.party_id=W.party_id
INNER JOIN table_b ppr ON ppr.party_id_from=H.party_id
INNER JOIN table_c pp ON ppr.party_id_from=pp.id
INNER JOIN table_c ppb ON ppr.party_id_from=ppb.id
WHERE table_b.is_deleted=0



Now you can select from the View in your application like this:


SELECT * -- I don't want to write out the columns, but you should...
FROM yourView
WHERE base_id = @party_id



You should get the appropriate filtering on the base table now - the same as having the WHERE clause in the anchor.

edit: I had left the variable in the anchor which was very wrong and misleading!!!

MM


select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);




  • Forum Etiquette: How to post Reporting Services problems
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • How to Post Performance Problems - by Gail Shaw

  • pmadhavapeddi22
    pmadhavapeddi22
    SSCrazy
    SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)

    Group: General Forum Members
    Points: 2004 Visits: 1870
    hi magoo,

    This is really a good solution, base_id is getting eliminated.

    Thanks
    pmadhavapeddi22
    pmadhavapeddi22
    SSCrazy
    SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)

    Group: General Forum Members
    Points: 2004 Visits: 1870
    magoo,

    small correction to my previous post,

    This is a good solution. In the query output, base_id is getting eliminated,but I need to get the the base_id record also

    regards
    mister.magoo
    mister.magoo
    SSChampion
    SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

    Group: General Forum Members
    Points: 10525 Visits: 7891
    Well. if you need help with that, could you please post some table creation scripts and sample data, along with the new view definition.

    MM


    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);




  • Forum Etiquette: How to post Reporting Services problems
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • How to Post Performance Problems - by Gail Shaw

  • sqldriver
    sqldriver
    SSCrazy
    SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

    Group: General Forum Members
    Points: 2160 Visits: 2536
    You don't happen to be working with a Redshift dB? I am currently, and running into all sorts of nasty surprises with its feature set. Sick
    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