Its there a Way to find out

  • Hi everyone...

    Is there a way to search in the DATABASE to find out where the specific data is .. i mean in which table.column in a database...

    going through by each table is time consuming...

  • I don't know if I understand your question properly. Are you asking if there is a way to see all the columns in a database?

  • No i mean all the data in each table.column...

    Here is the situation .. i migrated my database from old domain to new domain and it migrated successfully but the data in that database has the old domain name attached with that database so i need to find out where that data is so i can change the name in the data..

    e.g.

    Old servername.database name i want to change the data to new name

    new server.database

    we have few columns like that which runs like that so i have to change to new server name in order to work them properly

  • Something like this?

    http://www.mssqltips.com/sqlservertip/1522/searching-and-finding-a-string-value-in-all-columns-in-a-sql-server-table/

    ----------------------------------------------------------------------------
    Sacramento SQL Server users group - http://sac.sqlpass.org
    Follow me on Twitter - @SQLDCH
    ----------------------------------------------------------------------------

    Yeah, well...The Dude abides.
  • This topic pops up around here a lot. Both Lowell and I have posted scripts over the years for doing this. A few months ago Chris M came along with a newer concept of doing this that doesn't require the hideously slow performance issues with a cursor (like the idea presented in the article above and the versions that both Lowell and I wrote years ago).

    The code Chris posted was looking a series of values but this can easily be modified to search for only a single value.

    DECLARE @MySearchCriteria VARCHAR(500)

    SET @MySearchCriteria = '''RO04381'',''RO04052'',''RO04210'''

    SELECT 'SELECT ' + c.columnlist + ' FROM ' + t.name + ' WHERE ' + w.whereclause

    FROM sys.tables t

    CROSS APPLY (

    SELECT STUFF((

    SELECT ', ' + c.Name AS [text()]

    FROM sys.columns c

    WHERE t.object_id = c.object_id

    AND c.collation_name IS NOT NULL

    AND c.max_length > 6

    FOR XML PATH('')

    ), 1, 2, '' )

    ) c (columnlist)

    CROSS APPLY (

    SELECT STUFF((

    SELECT ' OR ' + c.Name + ' IN (' + @MySearchCriteria + ')' AS [text()]

    FROM sys.columns c

    WHERE t.object_id = c.object_id

    AND c.collation_name IS NOT NULL

    AND c.max_length > 6

    FOR XML PATH('')

    ), 1, 4, '' )

    ) w (whereclause)

    ORDER BY t.name

    If you want to compare this to the cursor type searching you can look at my version.

    declare @table_name varchar(2000)

    declare @sSQL nvarchar(4000)

    declare @result varchar(20)

    declare @column_name varchar(2000)

    declare @SearchVal varchar(200)

    set @SearchVal = '%your search val here%'

    declare @ColName varchar (250)

    set @ColName = '%use this if you want to limit to a naming convention on the columns to search (i.e. email)%'

    declare SearchList cursor for

    select distinct so.name,sc.name from syscolumns sc

    inner join sysobjects so on sc.id = so.id

    where 1 = 1

    and sc.name like @ColName

    and so.type = 'U'

    open SearchList

    fetch next from SearchList into @table_name, @column_name

    while(@@fetch_status = 0)

    begin

    select @sSQL = 'if exists (select ''' + @table_name + ''' as TableName,' + @column_name + ' from ' + @table_name + ' where ' + @column_name + ' like ''' + @SearchVal + ''') select ''' + @table_name + ''' as TableName,' + @column_name + ' from ' + @table_name + ' where ' + @column_name + ' like ''' + @SearchVal + ''''

    exec sp_executesql @sSQL

    --select @ssql

    fetch next from SearchList into @table_name, @column_name

    end

    close SearchList

    deallocate SearchList

    Or you can look at Lowell's version.

    CREATE PROCEDURE sp_UGLYSEARCH

    /*

    --Purpose: to search every string column in a databasefor a specific word

    --returns sql statement as a string which idnetifies the matching table

    -- or when the optional parameter is used, the sql statement for the specific matching column.

    --usage:

    -- EXEC sp_UGLYSEARCH 'Provisional'

    -- EXEC sp_UGLYSEARCH 'TEST'

    -- creates one SQL for each table that actually has a match for the searched value i.e.

    -- SELECT * FROM [ACACTSCR] WHERE [DESCRIP] LIKE '%TEST%' OR [TITLE] LIKE '%TEST%'

    --optional parameter SEARCHBYCOLUMN

    -- EXEC sp_UGLYSEARCH 'TEST',1

    -- creates one SQL for each Column that actually has a match for the searched value i.e.

    -- SELECT * FROM [dbo].[ACACTSCR] WHERE [DESCRIP] LIKE '%TEST%'

    -- SELECT * FROM [dbo].[ACACTSCR] WHERE [TITLE] LIKE '%TEST%'

    */

    @SEARCHSTRING VARCHAR(50),

    @SEARCHBYCOLUMN INT = 0

    AS

    BEGIN

    SET NOCOUNT ON

    DECLARE @SQL VARCHAR(max),

    @SCHEMANAME VARCHAR(100),

    @TABLENAME VARCHAR(100),

    @COLUMNNAME VARCHAR(100),

    @COLZ VARCHAR(max)

    CREATE TABLE #RESULTS(SCHEMANAME VARCHAR(100), TBLNAME VARCHAR(100),COLNAME VARCHAR(100),SQL VARCHAR(max))

    SELECT

    SCHEMA_NAME(schema_id) AS SCHEMANAME,

    objz.name AS TBLNAME,

    colz.name AS COLNAME,

    TYPE_NAME(colz.user_type_id) AS DATATYPE

    INTO #TEMP

    FROM sys.objects objz

    INNER JOIN sys.columns colz ON objz.object_id = colz.object_id

    WHERE objz.type='U'

    AND TYPE_NAME(colz.user_type_id) IN ('VARCHAR','NVARCHAR','CHAR','NCHAR')

    AND colz.max_length >= LEN(@SEARCHSTRING) --smart: don't search varchar(1) columns for 'TEST' 4xmpl

    ORDER BY TBLNAME,COLNAME

    IF @SEARCHBYCOLUMN = 0

    BEGIN

    DECLARE C1 CURSOR FOR

    SELECT SCHEMANAME,TBLNAME,COLNAME FROM #TEMP ORDER BY SCHEMANAME,TBLNAME,COLNAME

    OPEN C1

    FETCH NEXT FROM C1 INTO @SCHEMANAME,@TABLENAME,@COLUMNNAME

    WHILE @@FETCH_STATUS <> -1

    BEGIN

    SET @COLZ=''

    SELECT @COLZ = @COLZ + QUOTENAME(COLNAME) + ' LIKE ''%' + @SEARCHSTRING + '%'' OR ' FROM #TEMP WHERE TBLNAME=@TABLENAME

    --@COLZ has a trailing 'OR ' which must be removed

    SET @COLZ = SUBSTRING(@COLZ,1,LEN(@COLZ) -3)

    --PRINT @COLZ

    SET @SQL = 'IF EXISTS(SELECT * FROM ' + QUOTENAME(@SCHEMANAME) + '.' + QUOTENAME(@TABLENAME) + ' WHERE ' + @COLZ + ') INSERT INTO #RESULTS(TBLNAME,COLNAME,SQL) VALUES(''' + @TABLENAME + ''',''-'','' SELECT * FROM ' + QUOTENAME(@TABLENAME) + ' WHERE ' + REPLACE(@COLZ,'''','''''') + ''') ;'

    --PRINT @SQL

    EXEC (@SQL)

    FETCH NEXT FROM C1 INTO @SCHEMANAME,@TABLENAME,@COLUMNNAME

    END

    CLOSE C1

    DEALLOCATE C1

    END

    ELSE --@SEARCHBYCOLUMN <> 0

    BEGIN

    DECLARE C2 CURSOR FOR

    SELECT SCHEMANAME,TBLNAME,COLNAME FROM #TEMP ORDER BY SCHEMANAME,TBLNAME,COLNAME

    OPEN C2

    FETCH NEXT FROM C2 INTO @SCHEMANAME,@TABLENAME,@COLUMNNAME

    WHILE @@FETCH_STATUS <> -1

    BEGIN

    SET @SQL = 'IF EXISTS(SELECT * FROM ' + QUOTENAME(@SCHEMANAME) + '.' + QUOTENAME(@TABLENAME) + ' WHERE ' + QUOTENAME(@COLUMNNAME) + ' LIKE ''%' + @SEARCHSTRING + '%'')

    INSERT INTO #RESULTS(SCHEMANAME,TBLNAME,COLNAME,SQL) VALUES(''' + @SCHEMANAME + ''',''' + @TABLENAME + ''',''' + @COLUMNNAME + ''',''

    SELECT * FROM ' + QUOTENAME(@SCHEMANAME) + '.' + QUOTENAME(@TABLENAME) + ' WHERE ' + QUOTENAME(@COLUMNNAME) + ' LIKE ''''%' + @SEARCHSTRING + '%'''' '') ;'

    PRINT @SQL

    EXEC (@SQL)

    FETCH NEXT FROM C2 INTO @SCHEMANAME,@TABLENAME,@COLUMNNAME

    END

    CLOSE C2

    DEALLOCATE C2

    END --@SEARCHBYCOLUMN <> 0

    SELECT * FROM #RESULTS ORDER BY TBLNAME,COLNAME

    END --PROC

    GO

    SELECT * FROM #RESULTS ORDER BY TBLNAME,COLNAME

    END --PROC

    GO

    _______________________________________________________________

    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/

  • Here is the one I like using. Written by SQLDenis, it helped me quite a bit when I needed to write migration routines between two systems.

    http://blogs.lessthandot.com/index.php/DataMgmt/DataDesign/the-ten-most-asked-sql-server-questions--1#2

    Why is it that people who can't take advice always insist on giving it? - James Bond, Casino Royale

Viewing 6 posts - 1 through 5 (of 5 total)

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