Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««12

passing a variable to CTE in a view Expand / Collapse
Author
Message
Posted Wednesday, January 22, 2014 5:57 PM


SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Today @ 12:10 AM
Points: 652, Visits: 3,017

...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



Read this article for best practices on asking questions.
Need to split a string? Try this (Jeff Moden)
Need a pattern-based string spitter? Try this (Dwain Camps)

"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

My blog
Post #1533889
Posted Wednesday, January 22, 2014 6:33 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 6:37 PM
Points: 1,817, Visits: 5,919
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


  • MMGrid Addin
  • MMNose Addin


  • 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

  • Post #1533894
    Posted Thursday, January 23, 2014 3:29 AM
    SSC Eights!

    SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

    Group: General Forum Members
    Last Login: Wednesday, December 24, 2014 7:00 AM
    Points: 828, Visits: 1,440
    hi magoo,

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

    Thanks
    Post #1533974
    Posted Thursday, January 23, 2014 3:55 AM
    SSC Eights!

    SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

    Group: General Forum Members
    Last Login: Wednesday, December 24, 2014 7:00 AM
    Points: 828, Visits: 1,440
    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
    Post #1533985
    Posted Thursday, January 23, 2014 9:39 AM


    SSCommitted

    SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

    Group: General Forum Members
    Last Login: Yesterday @ 6:37 PM
    Points: 1,817, Visits: 5,919
    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


  • MMGrid Addin
  • MMNose Addin


  • 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

  • Post #1534168
    Posted Friday, January 24, 2014 8:19 AM


    SSC-Addicted

    SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

    Group: General Forum Members
    Last Login: Today @ 12:25 AM
    Points: 496, Visits: 2,072
    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.
    Post #1534512
    « Prev Topic | Next Topic »

    Add to briefcase ««12

    Permissions Expand / Collapse