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


View not working since moving database from SQL 2000 to SQL 2008


View not working since moving database from SQL 2000 to SQL 2008

Author
Message
Douglasjbell
Douglasjbell
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 70
Hi All

I moved a simple database from SQL Server 2000 to SQL server 2008. It has a couple of Tables and a couple of views.

I have a view using the following statement.


SELECT DISTINCT
TOP (100) PERCENT PERSONID AS EmpID, CONVERT(numeric, PERSONNUM) AS ClockNo, FIRSTNM + ' ' + LASTNM AS EmpName, EMPLOYMENTSTATUS,
HOMELABORLEVELNAME3
FROM KronosWFC.dbo.VP_EMPLOYEE
WHERE (EMPLOYMENTSTATUS = 'Active')
ORDER BY ClockNo



The above works perfectly, however if I modify it slightly like below.


SELECT DISTINCT
TOP (100) PERCENT PERSONID AS EmpID, CONVERT(numeric, PERSONNUM) AS ClockNo, FIRSTNM + ' ' + LASTNM AS EmpName, EMPLOYMENTSTATUS,
HOMELABORLEVELNAME3
FROM KronosWFC.dbo.VP_EMPLOYEE
WHERE (EMPLOYMENTSTATUS = 'Active') AND (CONVERT(numeric, PERSONNUM) = 722)
ORDER BY ClockNo



I get an SQL error "Error converting data type nvarchar to numeric"

Now the above view worked perfectly in SQL 2000 but not in SQL 2008, I just cant figure out what it is. At first I thought maybe it was because one of the rows could not be converted to a numer but I would have assumed the first view wouldnt work either. Also I have checked all the rows and they are all numbers.

Any help would be appreciated.

Regards

Douglas Bell
anthony.green
anthony.green
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: 10037 Visits: 6303
That is a funny one, as the convert is the same in the select and the where, so both should fail.

Would it be possible to post the DDL (CREATE TABLE script) form VP_EMPLOYEE and also some dummy data, to see if I can repro the error.



Want an answer fast? Try here
How to post data/code for the best help - Jeff Moden
When a question, really isn't a question - Jeff Smith
Need a string splitter, try this - Jeff Moden
How to post performance problems - Gail Shaw
CrossTabs-Part1 & Part2 - Jeff Moden
SQL Server Backup, Integrity Check, and Index and Statistics Maintenance - Ola Hallengren
Managing Transaction Logs - Gail Shaw
Troubleshooting SQL Server: A Guide for the Accidental DBA - Jonathan Kehayias and Ted Krueger


Grant Fritchey
Grant Fritchey
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39143 Visits: 32616
It's probably because the SELECT criteria only converts the information returned, but the WHERE clause, since it's a function on a column which means a complete scan of the table (and a very bad idea), it must resolve the values. So you may not see the error from the SELECT, but you're guaranteed to always see it in the WHERE.

----------------------------------------------------
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
OTF
OTF
Mr or Mrs. 500
Mr or Mrs. 500 (500 reputation)Mr or Mrs. 500 (500 reputation)Mr or Mrs. 500 (500 reputation)Mr or Mrs. 500 (500 reputation)Mr or Mrs. 500 (500 reputation)Mr or Mrs. 500 (500 reputation)Mr or Mrs. 500 (500 reputation)Mr or Mrs. 500 (500 reputation)

Group: General Forum Members
Points: 500 Visits: 4128
Sorry to possibly add to your troubles but you may have more than one problem with your View.

The "Select Top 100 Percent" method was commonly used in previous versions of sql server to retrieve ordered
results from Views. I don't believe this works in newer versions of Sql Server as the optimizer seems to just ignore the request to Sort.
You can easily test it by viewing the plan of a call to your View.
If the order of rows is important, you may need to order the rows in an outer query as you retrieve them from the View.
Orlando Colamatteo
Orlando Colamatteo
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14825 Visits: 14396
What is the datatype of PERSONNUM?

You can change this in the WHERE clause:

WHERE     (EMPLOYMENTSTATUS = 'Active') AND (CONVERT(numeric, PERSONNUM) = 722)



to this, where DATATYPE is the datatype of PERSONNUM, e.g. VARCHAR(20) or NVARCHAR(50), which will make that part a SARG:

WHERE     (EMPLOYMENTSTATUS = 'Active') AND (PERSONNUM = CAST('722' AS DATATYPE))



__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
Ed Wagner
Ed Wagner
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16429 Visits: 10050
Grant is right - you need to check your data types.

Also, you cannot have an ORDER BY clause in a view. SQL 2000 tolerated it but the later versions do not.
If you need one, you have to include the TOP n clause in the SELECT statement.


Tally Tables - Performance Personified
String Splitting with True Performance
Best practices on how to ask questions
Orlando Colamatteo
Orlando Colamatteo
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14825 Visits: 14396
Ed Wagner (1/14/2013)
If you need one, you have to include the TOP n clause in the SELECT statement.

...or TOP (n) PERCENT

__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)

Group: General Forum Members
Points: 25819 Visits: 17509
Ed Wagner (1/14/2013)
Grant is right - you need to check your data types.

Also, you cannot have an ORDER BY clause in a view. SQL 2000 tolerated it but the later versions do not.
If you need one, you have to include the TOP n clause in the SELECT statement.


It will only guarantee which rows and NOT guarantee the output order. If you want an order to the result the ONLY way to ensure that is to have an order by on the query, not the view.

_______________________________________________________________

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.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Douglasjbell
Douglasjbell
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 70
Hi All

Sorry for the late reply, first of me getting a chance to look at this particular database.

PERSONNUM is NVARCHAR(15)

I have taken away the order by clause as to be honest its not really needed as the application front end does the sorting anyway.

I have tried multiple things converting both ClockNo and 722 to numeric, converting the 722 to NVARCHAR(15) I still get the error that it cannot convert.

Regards

Douglas Bell
Orlando Colamatteo
Orlando Colamatteo
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14825 Visits: 14396
What does this query yield?

SELECT DISTINCT
PERSONID AS EmpID,
CONVERT(NUMERIC, 722) AS ClockNo, -- we know the ClockNo is 722 per the WHERE-clause
FIRSTNM + ' ' + LASTNM AS EmpName,
EMPLOYMENTSTATUS,
HOMELABORLEVELNAME3
FROM KronosWFC.dbo.VP_EMPLOYEE
WHERE EMPLOYMENTSTATUS = 'Active'
AND PERSONNUM = CAST('722' AS NVARCHAR(15));



__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
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