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


Logic to check for empty table before joining


Logic to check for empty table before joining

Author
Message
Anjan Wahwar
Anjan Wahwar
SSC Eights!
SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)

Group: General Forum Members
Points: 879 Visits: 256
Hi All,

I have a requirement which requires me to display report as per the dimension access to the user trying to pull the report. Just to give an example.. My dimension "Dimension.Sites" can have more than 20 sites. But a user has allowed access to only 5 sites. Accordingly they need to have the information presented to them when they request a report.

Sites that the user has access to I am getting though a security module to my temp table #Sites(SiteKey) (It got records only if user has limited access. In case of full access this table wont contain any record) and I have written below query to have join to my fact table.

SELECT SiteKey, SiteName, ...FROM fact.Sales f
INNER JOIN Dimension.Sites s ON f.SiteKey = s.SiteKey
WHERE (@SiteFullAccessFlag = 1 OR
(s.SiteKey IN (Select SiteKey FROM #Sites)))

@SiteFullAccessFlag = 1 in case of full access on the site dimension.

The problem with this approach is performance. As my fact table has huge set of rows and its getting joined with multiple dimensions hence performance is very poor.

When I remove "s.SiteKey IN (Select SiteKey FROM #Sites)" from the query performance improves by 50%. Fact and dimension got index created on all the key column.

So, need your suggestion if there is any better approach to write this join. I cant directly join with this temp table as they may or may not have security filtered records. What I am trying to achive is join fact with temp table if got record else join with actual sites dimension.

Hope I have put my query in appropriate way :-)

Thanks,
Anjan Wahwar

__________________________________________
---------------------------------------------------
Save our mother Earth. Go Green !!!
Grant Fritchey
Grant Fritchey
SSC Guru
SSC Guru (221K reputation)SSC Guru (221K reputation)SSC Guru (221K reputation)SSC Guru (221K reputation)SSC Guru (221K reputation)SSC Guru (221K reputation)SSC Guru (221K reputation)SSC Guru (221K reputation)

Group: General Forum Members
Points: 221082 Visits: 33551
Instead of using an IN clause, use another JOIN to retrieve that data. You would have to build a dynamic statement to perform a count before you tried to JOIN, requiring two different queries. That's an option, but not always a good one. Also, to help with performance, capturing and post the actual execution plan makes it easier to understand how your structures and query are working within the optimizer.

----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
Anjan Wahwar
Anjan Wahwar
SSC Eights!
SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)SSC Eights! (879 reputation)

Group: General Forum Members
Points: 879 Visits: 256
Thank Grant. I will try your suggestion. Just wanted to make sure I' doing it in a correct way.

__________________________________________
---------------------------------------------------
Save our mother Earth. Go Green !!!
sgmunson
sgmunson
SSC-Forever
SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)

Group: General Forum Members
Points: 43212 Visits: 5422
Just wondering why you would populate said temp table with 0 records when the user has access to ALL sites. If you simply copied all the PK values for the site dimension into your temp table when a user has access to all, and only the sites they have access to when their access is limited, into such temp table; and then index that temp table; I'm not sure why you'd have a problem. Also, have you tried the alternate form of an IN, which is to use EXISTS ? Sometimes that performs better.

Post an execution plan as a .sqlplan file and someone here can probably help you figure out where the problem is.

EDIT: grammar fix for clarity.

Steve
‌(aka sgmunson)
Smile Smile Smile
Health & Nutrition
ScottPletcher
ScottPletcher
SSC-Forever
SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)

Group: General Forum Members
Points: 46311 Visits: 8033
Be sure to create a unique clustered key / primary clustered key on SiteKey in the #Sites tables. With only ~20+ rows it may not matter, but it can't hurt.

SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (223K reputation)SSC Guru (223K reputation)SSC Guru (223K reputation)SSC Guru (223K reputation)SSC Guru (223K reputation)SSC Guru (223K reputation)SSC Guru (223K reputation)SSC Guru (223K reputation)

Group: General Forum Members
Points: 223132 Visits: 40398
Or something like this as only one of the queries will return data:


SELECT
SiteKey
, SiteName
, ...
FROM
fact.Sales f
INNER JOIN Dimension.Sites s
ON f.SiteKey = s.SiteKey
WHERE
@SiteFullAccessFlag = 1
UNION ALL
SELECT
SiteKey
, SiteName
, ...
FROM
fact.Sales f
INNER JOIN Dimension.Sites s
ON f.SiteKey = s.SiteKey
INNER JOIN #Sites ss
ON f.SiteKey = ss.SiteKey;


Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
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