August 26, 2012 at 4:40 pm
Need to create view with no outer joins so I can index the view. Here is the query I use to create the view. Does anyone no of a better way?
SELECT c.cts_app_fkey AS APP_NUMBER, a.CREDIT_AMOUNT, REPLACE(d.DLR_REFERENCE_NUM, '.', '') AS DEALER_NUM, c.cts_contract_number AS APP_CONTRACT_NUMBER,
CASE co.CO_UD_APP_STATUS_TBDESC WHEN 'PO Issued' THEN CASE a.APP_DECISION_CODE WHEN 7 THEN 'Booked' ELSE 'PO Issued' END WHEN 'Approved' THEN
CASE co.CO_LESSOR WHEN '421' THEN 'Approved - SFP' WHEN '423' THEN 'Approved - SFP' WHEN '424' THEN 'Approved - SFP' ELSE 'Approved' END ELSE co.CO_UD_APP_STATUS_TBDESC
END AS APPLICATION_STATUS, CONVERT(VARCHAR, co.CO_BOOKING_DATE, 101) AS BOOKING_DATE, CONVERT(XML, a.APP_DATA,
0 ).value('(//CUST.NAME/node())[1]', 'VARCHAR(50)') AS CUSTOMER, CONVERT(XML, a.APP_DATA, 0 ).value('(//DBA/node())[1]', 'VARCHAR(50)') AS CUSTOMER_DBA,
CASE WHEN LEN(CONVERT(XML, a.APP_DATA, 0 ).value('(//CUST.CREDIT.ACCT/node())[1]', 'VARCHAR(50)')) < 8 THEN CONVERT(XML, a.APP_DATA,
0 ).value('(//CUST.CREDIT.ACCT/node())[1]', 'VARCHAR(50)') ELSE NULL END AS CCAN, CONVERT(VARCHAR, CONVERT(DATE, CONVERT(XML, a.APP_DATA,
0 ).value('(//UD_DATE_ENTERED/node())[1]', 'VARCHAR(10)')), 101) AS DATE_ENTERED, CONVERT(XML, a.APP_DATA, 0 ).value('(//FED.ID/node())[1]', 'VARCHAR(50)')
AS FEDERAL_ID
FROM dbo.APPLICATION AS a LEFT OUTER JOIN
dbo.RPT_CO AS co ON a.APP_KEY = co.APP_FKEY LEFT OUTER JOIN
dbo.DEALER AS d ON CONVERT(XML, a.APP_DATA, 0 ).value('(//DEALER/node())[1]', 'VARCHAR(50)') = d.DLR_KEY LEFT OUTER JOIN
dbo.Contract_Setup AS c on a.app_key = c.cts_app_fkey
WHERE (DATEDIFF(MINUTE, c.CTS_LAST_SAVED_DATE, GETDATE()) < 50) AND (DATEDIFF(MINUTE, c.CTS_LAST_SAVED_DATE, GETDATE()) > 30)
August 27, 2012 at 8:03 am
jdbrown239 (8/26/2012)
Need to create view with no outer joins so I can index the view. Here is the query I use to create the view. Does anyone no of a better way?SELECT c.cts_app_fkey AS APP_NUMBER, a.CREDIT_AMOUNT, REPLACE(d.DLR_REFERENCE_NUM, '.', '') AS DEALER_NUM, c.cts_contract_number AS APP_CONTRACT_NUMBER,
CASE co.CO_UD_APP_STATUS_TBDESC WHEN 'PO Issued' THEN CASE a.APP_DECISION_CODE WHEN 7 THEN 'Booked' ELSE 'PO Issued' END WHEN 'Approved' THEN
CASE co.CO_LESSOR WHEN '421' THEN 'Approved - SFP' WHEN '423' THEN 'Approved - SFP' WHEN '424' THEN 'Approved - SFP' ELSE 'Approved' END ELSE co.CO_UD_APP_STATUS_TBDESC
END AS APPLICATION_STATUS, CONVERT(VARCHAR, co.CO_BOOKING_DATE, 101) AS BOOKING_DATE, CONVERT(XML, a.APP_DATA,
0 ).value('(//CUST.NAME/node())[1]', 'VARCHAR(50)') AS CUSTOMER, CONVERT(XML, a.APP_DATA, 0 ).value('(//DBA/node())[1]', 'VARCHAR(50)') AS CUSTOMER_DBA,
CASE WHEN LEN(CONVERT(XML, a.APP_DATA, 0 ).value('(//CUST.CREDIT.ACCT/node())[1]', 'VARCHAR(50)')) < 8 THEN CONVERT(XML, a.APP_DATA,
0 ).value('(//CUST.CREDIT.ACCT/node())[1]', 'VARCHAR(50)') ELSE NULL END AS CCAN, CONVERT(VARCHAR, CONVERT(DATE, CONVERT(XML, a.APP_DATA,
0 ).value('(//UD_DATE_ENTERED/node())[1]', 'VARCHAR(10)')), 101) AS DATE_ENTERED, CONVERT(XML, a.APP_DATA, 0 ).value('(//FED.ID/node())[1]', 'VARCHAR(50)')
AS FEDERAL_ID
FROM dbo.APPLICATION AS a LEFT OUTER JOIN
dbo.RPT_CO AS co ON a.APP_KEY = co.APP_FKEY LEFT OUTER JOIN
dbo.DEALER AS d ON CONVERT(XML, a.APP_DATA, 0 ).value('(//DEALER/node())[1]', 'VARCHAR(50)') = d.DLR_KEY LEFT OUTER JOIN
dbo.Contract_Setup AS c on a.app_key = c.cts_app_fkey
WHERE (DATEDIFF(MINUTE, c.CTS_LAST_SAVED_DATE, GETDATE()) < 50) AND (DATEDIFF(MINUTE, c.CTS_LAST_SAVED_DATE, GETDATE()) > 30)
Nobody knows what your tables look like or your data looks like. We also don't know the requirements. There is absolutely no way anybody has chance at answering your question unless you provide some details. Take a look at the first link in my signature about best practices when posting questions.
I took the liberty of formatting your query so people can read it. If you use the IFCode shortcuts (over on the left when posting), you can wrap your code in these blocks and it will maintain the formatting. ๐
SELECT c.cts_app_fkey AS APP_NUMBER
,a.CREDIT_AMOUNT
,REPLACE(d.DLR_REFERENCE_NUM, '.', '') AS DEALER_NUM
,c.cts_contract_number AS APP_CONTRACT_NUMBER
,CASE co.CO_UD_APP_STATUS_TBDESC
WHEN 'PO Issued'
THEN CASE a.APP_DECISION_CODE
WHEN 7
THEN 'Booked'
ELSE 'PO Issued'
END
WHEN 'Approved'
THEN CASE co.CO_LESSOR
WHEN '421'
THEN 'Approved - SFP'
WHEN '423'
THEN 'Approved - SFP'
WHEN '424'
THEN 'Approved - SFP'
ELSE 'Approved'
END
ELSE co.CO_UD_APP_STATUS_TBDESC
END AS APPLICATION_STATUS
,CONVERT(VARCHAR, co.CO_BOOKING_DATE, 101) AS BOOKING_DATE
,CONVERT(XML, a.APP_DATA, 0).value('(//CUST.NAME/node())[1]', 'VARCHAR(50)') AS CUSTOMER
,CONVERT(XML, a.APP_DATA, 0).value('(//DBA/node())[1]', 'VARCHAR(50)') AS CUSTOMER_DBA
,CASE
WHEN LEN(CONVERT(XML, a.APP_DATA, 0).value('(//CUST.CREDIT.ACCT/node())[1]', 'VARCHAR(50)')) < 8
THEN CONVERT(XML, a.APP_DATA, 0).value('(//CUST.CREDIT.ACCT/node())[1]', 'VARCHAR(50)')
ELSE NULL
END AS CCAN
,CONVERT(VARCHAR, CONVERT(DATE, CONVERT(XML, a.APP_DATA, 0).value('(//UD_DATE_ENTERED/node())[1]', 'VARCHAR(10)')), 101) AS DATE_ENTERED
,CONVERT(XML, a.APP_DATA, 0).value('(//FED.ID/node())[1]', 'VARCHAR(50)') AS FEDERAL_ID
FROM dbo.APPLICATION AS a
LEFT JOIN dbo.RPT_CO AS co ON a.APP_KEY = co.APP_FKEY
LEFT JOIN dbo.DEALER AS d ON CONVERT(XML, a.APP_DATA, 0).value('(//DEALER/node())[1]', 'VARCHAR(50)') = d.DLR_KEY
LEFT JOIN dbo.Contract_Setup AS c ON a.app_key = c.cts_app_fkey
WHERE (DATEDIFF(MINUTE, c.CTS_LAST_SAVED_DATE, GETDATE()) < 50)
AND (DATEDIFF(MINUTE, c.CTS_LAST_SAVED_DATE, GETDATE()) > 30)
_______________________________________________________________
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/
August 27, 2012 at 8:30 am
jdbrown239 (8/26/2012)
Need to create view with no outer joins so I can index the view.
I can't find a restriction for indexed views that involves outer joins http://msdn.microsoft.com/en-us/library/ms191432.aspx. Are you sure that's the reason? and that's what you need?
OUTER JOINS have a very specific function and can't be really replaced by something else without changing the results (OUTER APPLY is similar but I don't believe it'll solve your problem).
August 27, 2012 at 8:37 am
an indexed view cannot have functions applied to any of the columns,right? so the CASE and CONVERT statements in the query you posted will disqualify the view from being indexed, but you can certainly index the underlying tables for performance.
Lowell
August 27, 2012 at 8:38 am
Luis Cazares (8/27/2012)
jdbrown239 (8/26/2012)
Need to create view with no outer joins so I can index the view.I can't find a restriction for indexed views that involves outer joins http://msdn.microsoft.com/en-us/library/ms191432.aspx. Are you sure that's the reason? and that's what you need?
OUTER JOINS have a very specific function and can't be really replaced by something else without changing the results (OUTER APPLY is similar but I don't believe it'll solve your problem).
Indexed views must be deterministic. The link here will show you a number on things not allowed in an indexed view.
http://msdn.microsoft.com/en-us/library/ms191432%28v=sql.105%29.aspx
_______________________________________________________________
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/
August 27, 2012 at 9:04 am
I guess it was wrong for me to read the 2012 version as it is less explicit.
But I still believe the OP won't have an option on creating the indexed view with this query. At least it won't give the same output.
August 27, 2012 at 9:07 am
Luis Cazares (8/27/2012)
I guess it was wrong for me to read the 2012 version as it is less explicit.But I still believe the OP won't have an option on creating the indexed view with this query. At least it won't give the same output.
I would agree. I think that properly indexing the base tables as Lowell suggested is the most likely path to a solid solution in this case. With no more details to work with though it is hard to say.
_______________________________________________________________
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/
August 27, 2012 at 12:00 pm
Sean Lange (8/27/2012)
Luis Cazares (8/27/2012)
I guess it was wrong for me to read the 2012 version as it is less explicit.But I still believe the OP won't have an option on creating the indexed view with this query. At least it won't give the same output.
I would agree. I think that properly indexing the base tables as Lowell suggested is the most likely path to a solid solution in this case. With no more details to work with though it is hard to say.
The XQUERY references (i.e. the stuff in the .value() constructs) will preclude this from being deterministic, so you won't be able to mark it schemabound. Without schema-bound you won't be able to index it.
It's actually one of the restrictions in the article mentioned above.
----------------------------------------------------------------------------------
Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?
August 27, 2012 at 3:40 pm
Sorry for the initial messy post.
I think you guys are right. I have tried writing the view without joins and the result set is never the same. I will look at indexing the tables.
Thanks!
August 28, 2012 at 2:11 am
jdbrown239 (8/27/2012)
Sorry for the initial messy post.I think you guys are right. I have tried writing the view without joins and the result set is never the same. I will look at indexing the tables.
Thanks!
Indexing won't help the WHERE clause, it isn't SARGable (the datetime functions prevent SQL Server from using any index on c.CTS_LAST_SAVED_DATE). If you remove those functions from c.CTS_LAST_SAVED_DATE, you may get a welcome performance boost:
WHERE c.CTS_LAST_SAVED_DATE > DATEADD(MINUTE,-50,GETDATE()) AND c.CTS_LAST_SAVED_DATE < DATEADD(MINUTE,-30,GETDATE())
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
August 28, 2012 at 8:00 am
jdbrown239 (8/27/2012)
I think you guys are right. I have tried writing the view without joins and the result set is never the same. I will look at indexing the tables.
Yeah, whether or not to use OUTER JOINs as opposed to INNER is often not a implementation choice, per se - it's usually driven by requirements.
If your schema is such that, say, dbo.Application.AppKey can contain NULLS (or a value that has no correspondent in dbo.RPT_CO.AppKey), and the requirements are to bring ALL rows from dbo.Application, then you can't use an INNER JOIN to JOIN those tables. Doing so will change the result set (i.e fewer rows returned).
As noted by other posters, there are still opportunities to increase performance through indexes on the base table. I would definitely second ChrisM's recommendation that you refactor your date filters to remove the function calls from the table data in order to make that filter SARGable.
August 28, 2012 at 1:47 pm
Sean Lange (8/27/2012)
Luis Cazares (8/27/2012)
jdbrown239 (8/26/2012)
Need to create view with no outer joins so I can index the view.I can't find a restriction for indexed views that involves outer joins http://msdn.microsoft.com/en-us/library/ms191432.aspx. Are you sure that's the reason? and that's what you need?
OUTER JOINS have a very specific function and can't be really replaced by something else without changing the results (OUTER APPLY is similar but I don't believe it'll solve your problem).
Indexed views must be deterministic. The link here will show you a number on things not allowed in an indexed view.
http://msdn.microsoft.com/en-us/library/ms191432%28v=sql.105%29.aspx
Indeed. I just skimmed the OP's proposed view definition and instantly knew it could not indexed when I spotted GETDATE(). GETDATE() is a nondeterministic function, and expressions in indexed views cannot refer to nondeterministic functions.
Jason Wolfkill
August 29, 2012 at 8:36 am
Thanks for the education. I will change the where clause and give it a try.
August 29, 2012 at 9:03 am
Chris..That worked great, thanks and thank all you guys for the input.
August 29, 2012 at 9:07 am
jdbrown239 (8/29/2012)
Chris..That worked great, thanks and thank all you guys for the input.
You're welcome jd, thanks for the feedback.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Viewing 15 posts - 1 through 15 (of 17 total)
You must be logged in to reply to this topic. Login to reply