Sage 200 Professional - SQL script to find a particular key word within the database
Description
Cause
Resolution

The following SQL Script enables you to search the database for a particular keyword. This script will return every table which contains that word.

This script can be very useful in troubleshooting error messages or just searching for where a particular field may exist.

NOTE: If looking for a particular field, enter a unique value into that field and search for the value using the script.

It is possible to use SQL wildcard's (for example % to replace multiple characters) to enable broader searching – the script includes these wildcards for your convenience.

Copy and paste the script below into your SQL database, replacing **** in the script with the relevant keyword.

 

DECLARE @SearchStr nvarchar(100) 
SET @SearchStr = '****'
      
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',  'numeric',
'decimal', 'double', 'money')
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 
Steps to duplicate
Related Solutions