Fin Table By Value

Handian Sudianto 5,121 Reputation points
2024-07-18T06:13:02.07+00:00

Hello,

I have an Network Performance Monitoring tools, and i create custom script to get some values for windows server. The script is run successful and return a value let say 565523.

The problem is i want to make custom report and the vendor is not provide support for reporting using custom query. The database contains lot of table, and i want to know can we find table by searching the value only? Example query all tables where contain record 565523.

SQL Server
SQL Server
A family of Microsoft relational database management and analysis systems for e-commerce, line-of-business, and data warehousing solutions.
13,948 questions
0 comments No comments
{count} votes

2 answers

Sort by: Most helpful
  1. Erland Sommarskog 112.7K Reputation points MVP
    2024-07-18T09:52:14.4033333+00:00

    Looking for a needle in a haystack?

    Try this, but beware that this can take a long time in a big database with many tables and columns. You need to adjust the selection of types depending on what sort of value you are looking for.

    SELECT 'IF EXISTS (SELECT *
                       FROM   ' + quotename(s.name) + '.' + quotename(t.name) + '
                       WHERE  ' + quotename(c.name) + ' = 11000)
               SELECT  ' + quotename(s.name, '''') + ' AS "schema", 
                       ' + quotename(t.name, '''') + ' AS "table", 
                       ' + quotename(c.name, '''') + ' AS "column"'
    FROM   sys.schemas s
    JOIN   sys.tables t ON s.schema_id = t.schema_id
    JOIN   sys.columns c ON t.object_id = c.object_id
    WHERE  type_name(c.system_type_id) IN ('int', 'bigint')
    
    0 comments No comments

  2. LiHongMSFT-4306 27,881 Reputation points
    2024-07-19T01:46:49.13+00:00

    Hi @Handian Sudianto

    See the answer from this similar thread: Search all tables, all columns for a specific value SQL Server

    DECLARE @SearchStr nvarchar(100)
    SET @SearchStr = '565523'
    
    CREATE TABLE #Results (ColumnName nvarchar(370), ColumnValue nvarchar(3630))
     
    SET NOCOUNT ON
     
    DECLARE @TableName nvarchar(256), @ColumnName nvarchar(128), @SearchStr2 nvarchar(110)
    SET  @TableName = ''
    SET @SearchStr2 = QUOTENAME('%' + @SearchStr + '%','''')
     
    WHILE @TableName IS NOT NULL
     
    BEGIN
        SET @ColumnName = ''
        SET @TableName = 
        (
            SELECT MIN(QUOTENAME(TABLE_SCHEMA) + '.' + QUOTENAME(TABLE_NAME))
            FROM     INFORMATION_SCHEMA.TABLES
            WHERE         TABLE_TYPE = 'BASE TABLE'
                AND    QUOTENAME(TABLE_SCHEMA) + '.' + QUOTENAME(TABLE_NAME) > @TableName
                AND    OBJECTPROPERTY(
                        OBJECT_ID(
                            QUOTENAME(TABLE_SCHEMA) + '.' + QUOTENAME(TABLE_NAME)
                             ), 'IsMSShipped'
                               ) = 0
        )
     
        WHILE (@TableName IS NOT NULL) AND (@ColumnName IS NOT NULL)
             
        BEGIN
            SET @ColumnName =
            (
                SELECT MIN(QUOTENAME(COLUMN_NAME))
                FROM     INFORMATION_SCHEMA.COLUMNS
                WHERE         TABLE_SCHEMA    = PARSENAME(@TableName, 2)
                    AND    TABLE_NAME    = PARSENAME(@TableName, 1)
                    AND    DATA_TYPE IN ('char', 'varchar', 'nchar', 'nvarchar', 'int', 'decimal')
                    AND    QUOTENAME(COLUMN_NAME) > @ColumnName
            )
     
            IF @ColumnName IS NOT NULL
             
            BEGIN
                INSERT INTO #Results
                EXEC
                (
                    'SELECT ''' + @TableName + '.' + @ColumnName + ''', LEFT(' + @ColumnName + ', 3630) FROM ' + @TableName + ' (NOLOCK) ' +
                    ' WHERE ' + @ColumnName + ' LIKE ' + @SearchStr2
                )
            END
        END   
    END
     
    SELECT ColumnName, ColumnValue FROM #Results
     
    DROP TABLE #Results
    

    Best regards,

    Cosmog


    If the answer is the right solution, please click "Accept Answer" and kindly upvote it. If you have extra questions about this answer, please click "Comment".

    0 comments No comments

Your answer

Answers can be marked as Accepted Answers by the question author, which helps users to know the answer solved the author's problem.