November 1, 2012 at 12:32 pm
I have the need to create a view for one of my applications to look at. The problem is, when I write the query to get the data I need, the only way I know how to do it is by using a temp table; however, I know that temp tables are not allowed in view. Is there anyway to write the below script in a manner that I could put it in a view without using temp tables?
SELECT A.COMPKEY, B.HYDR_ID, B.DATE, B.hydr_gpm, B.gpm_20, B.gpm_10, B.gpm_0, B.staff_id, B.shift,
B.static, B.residual, B.pitot, B.pitot2, coeff, A.Shape, C.not_in_srv, A.FLOWTEST,
Rank() over (Partition BY B.HYDR_ID order by B.DTTM DESC) AS RANK
INTO #FLOWTEST
FROM GISOWNER.WATHYDRANT A
LEFT JOIN S_4.FH.dbo.hyd_actv B
ON A.COMPKEY = B.HYDR_ID
LEFT JOIN S_4.FH.dbo.hyd_main C
ON A.COMPKEY = C.HYDR_ID
WHERE A.FIREZONE IN ('FZ1', 'FZ2', 'FZ3', 'FZ4', 'FZ5', 'FZ6', 'FZ7') AND (B.FLOWTEST = '1' OR C.not_in_srv = '1')
SELECT * FROM #FLOWTEST WHERE RANK = '1'
DROP TABLE #FLOWTEST
Thank you for any help that you can give!
Jordon
November 1, 2012 at 12:50 pm
You can use a cte in a view so this should work for you.
;with FLOWTEST as
(
SELECT A.COMPKEY, B.HYDR_ID, B.DATE, B.hydr_gpm, B.gpm_20, B.gpm_10, B.gpm_0, B.staff_id, B.shift,
B.static, B.residual, B.pitot, B.pitot2, coeff, A.Shape, C.not_in_srv, A.FLOWTEST,
Rank() over (Partition BY B.HYDR_ID order by B.DTTM DESC) AS RANK
FROM GISOWNER.WATHYDRANT A
LEFT JOIN S_4.FH.dbo.hyd_actv B
ON A.COMPKEY = B.HYDR_ID
LEFT JOIN S_4.FH.dbo.hyd_main C
ON A.COMPKEY = C.HYDR_ID
WHERE A.FIREZONE IN ('FZ1', 'FZ2', 'FZ3', 'FZ4', 'FZ5', 'FZ6', 'FZ7') AND (B.FLOWTEST = '1' OR C.not_in_srv = '1')
)
SELECT * FROM FLOWTEST WHERE RANK = 1
_______________________________________________________________
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/
November 1, 2012 at 1:35 pm
That worked perfectly! I always forget about CTEs.
Thanks!!!!
November 1, 2012 at 1:38 pm
You're welcome. Glad that worked for you.
_______________________________________________________________
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/
November 2, 2012 at 7:26 pm
You could use a simpler method than cte: subquery. This basic technique exists from sql2000 (and probably even earlier)
and is worth to be learned:
SELECT *
FROM
(
SELECT A.COMPKEY, B.HYDR_ID, B.DATE, B.hydr_gpm, B.gpm_20, B.gpm_10, B.gpm_0, B.staff_id, B.shift,
B.static, B.residual, B.pitot, B.pitot2, coeff, A.Shape, C.not_in_srv, A.FLOWTEST,
Rank() over (Partition BY B.HYDR_ID order by B.DTTM DESC) AS RANK
FROM GISOWNER.WATHYDRANT A
LEFT JOIN S_4.FH.dbo.hyd_actv B
ON A.COMPKEY = B.HYDR_ID
LEFT JOIN S_4.FH.dbo.hyd_main C
ON A.COMPKEY = C.HYDR_ID
WHERE A.FIREZONE IN ('FZ1', 'FZ2', 'FZ3', 'FZ4', 'FZ5', 'FZ6', 'FZ7') AND (B.FLOWTEST = '1' OR C.not_in_srv = '1')
) FLOWTEST
WHERE RANK = 1
CTE is required only if you want to use a subquery more than once, or in a recursion.
November 4, 2012 at 9:19 pm
I've come to use CTE's rather than subqueries, as in the last example, simply because it is easier for me to read from the top down than from inside out.
__________________________________________________
Against stupidity the gods themselves contend in vain. -- Friedrich Schiller
Stop, children, what's that sound? Everybody look what's going down. -- Stephen Stills
November 5, 2012 at 7:18 am
The decision to use a cte or a subquery boils down to preference. This type of query has been presented both ways time and time again with tons and tons of performance evaluation and the two will almost always produce identical execution plans. There truly is no performance between the two, just use whichever version is easier for you to use/understand.
_______________________________________________________________
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 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply