在整个数据库中根据某一个字段值查找该值所在的表及列
方案一:

1.建存储过程[SP_FindValueInDB]

  
Create PROCEDURE [dbo].[SP_FindValueInDB]
 
(
    @value VARCHAR(1024)
)        
AS
BEGIN
    -- SET NOCOUNT ON added to prevent extra result sets from
    -- interfering with SELECT statements.
SET NOCOUNT ON;
DECLARE @sql VARCHAR(1024) 
DECLARE @table VARCHAR(64) 
DECLARE @column VARCHAR(64) 
CREATE TABLE #t ( 
    tablename VARCHAR(64), 
    columnname VARCHAR(64) 
) 
DECLARE TABLES CURSOR 
FOR 
    SELECT o.name, c.name 
    FROM syscolumns c 
    INNER JOIN sysobjects o ON c.id = o.id 
    WHERE o.type = 'U' AND c.xtype IN (167, 175, 231, 239) 
    ORDER BY o.name, c.name 
OPEN TABLES 
FETCH NEXT FROM TABLES 
INTO @table, @column 
WHILE @@FETCH_STATUS = 0 
BEGIN 
    SET @sql = 'IF EXISTS(SELECT NULL FROM [' + @table + '] ' 
    SET @sql = @sql + 'WHERE RTRIM(LTRIM([' + @column + '])) LIKE ''%' + @value + '%'') ' 
    SET @sql = @sql + 'INSERT INTO #t VALUES (''' + @table + ''', ''' 
    SET @sql = @sql + @column + ''')' 
    EXEC(@sql) 
    FETCH NEXT FROM TABLES 
    INTO @table, @column 
END 
CLOSE TABLES 
DEALLOCATE TABLES 
SELECT * 
FROM #t 
DROP TABLE #t 

End
  

2.查询语句

  
EXEC SP_FindValueInDB  N'字段值' 
  

方案二:

只知道页面数据,而且数据库表没有备注,需要查询这个数据对应哪些表的哪些字段,操作如下:选中需要查询的数据库,执行如下sql:

  
DECLARE @what varchar(800) 
SET @what='要查询的值' --要搜索的字符串 
 
DECLARE @sql varchar(8000) 
 
DECLARE TableCursor CURSOR LOCAL FOR 
SELECT sql='IF EXISTS ( SELECT 1 FROM ['+o.name+'] WHERE ['+c.name+'] LIKE ''%'+@what+'%'' ) PRINT ''Table and field:['+o.name+'].['+c.name+']''' 
FROM syscolumns c JOIN sysobjects o ON c.id=o.id 
 
-- 175=char 56=int; 可以执行查询: select * from sys.types 获取每个数据类型对应的值
WHERE o.xtype='U' AND c.status>=0 AND c.xusertype IN (175, 239, 231, 167 ) 
 
OPEN TableCursor 
 
FETCH NEXT FROM TableCursor INTO @sql 
WHILE @@FETCH_STATUS=0 
BEGIN 
EXEC( @sql ) 
FETCH NEXT FROM TableCursor INTO @sql 
END 
 
CLOSE TableCursor 
 
-- 删除游标引用 
DEALLOCATE TableCursor

  

执行如上语句后控制台就会输出这条数据在哪些表里,是哪些字段,运行结果如下图所示:

2025-03-30T03:24:03.png

缩小了表的查询范围 ,不必盲目查询表。

发表评论