Determine if DB name has numerics

  • I am writing a script to move through specific databases in our server and if the name ends in 2 digits then I run a select statement  in it. The following returns a 1 if the ISNUMERIC returns true

    select  sd.name, ISNUMERIC(RIGHT(sd.name,2)
    from sys.sysdatabases sd
    Where sd.name not in ('master','tempdb','model','msdb')

    However when I run that in the WHERE clause it doesn't return the db names in the resultset.

    select  sd.name
    from sys.sysdatabases sd
    Where sd.name not in ('master','tempdb','model','msdb') AND ISNUMERIC(RIGHT(sd.name,2)) != 0;

    How can I find the databases whose name ends in 2 numerics?

     

    EDIT: This does work. THe failure was on another part of the query. I'm obviously not awake yet 🙁

     

    Even as a mother protects with her life
    Her child, her only child,
    So with a boundless heart
    Should one cherish all living beings;

  • Here's another way which is slightly more robust (because IsNumeric() can return unexpected results).

    SELECT d.name
    FROM sys.databases d
    WHERE d.database_id > 4
    AND PATINDEX('%[0-9][0-9]', d.name) > 0;

    If you haven't even tried to resolve your issue, please don't expect the hard-working volunteers here to waste their time providing links to answers which you could easily have found yourself.

  • Phil's answer is the way to go here. To expand on his comment about ISNUMERIC, for this specific scenario database names that end in something like .5 and -9 would also meet the requirements of your WHERE, even though they don't have 2 digits at the end of their name. For example, note what the below returns:

    SELECT V.DBName,
    RIGHT(V.DBName,2) AS Right2,
    ISNUMERIC(RIGHT(V.DBName,2)) AS Numerical
    FROM (VALUES(N'MyDatabase123'),(N'TestDB.1'),(N'Trial-7'),(N'DB 4'),(N'YourDB0.'))V(DBName);

    ISNUMERIC did used to get used to check if the value "could" be interpreted as a numerical data type, however, it had it quirks and gave false answers. For example ISNUMERIC('') will return 0, however, '' can be converted to a numerical data type. On the other hand '.' would return 1, but can't be converted. You also have cases where ISNUMERIC('1.0') would return 1, however, CONVERT(int, '1.0') would generate an error (trying to convert to a decimal would work though). For checking to see if a value can be converted to a numerical datatype, you want TRY_CONVERT and TRY_CAST (which are both available in 2012+)

    For what you want, using PATINDEX or LIKE, with 2 single character ranges at the end will work 100% of the time and not provide incorrect results.

    Thom~

    Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does.
    Larnu.uk

  • I'd use RIGHT rather than PATINDEX, just because I think's it mildly clearer:

    WHERE RIGHT(name, 2) LIKE '[0-9][0-9]'

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

Viewing 4 posts - 1 through 3 (of 3 total)

You must be logged in to reply to this topic. Login to reply