x

How to select data from tables with names matching a pattern

Hi, The SQL Server 2008 database stores data in multiple tables for each month with a random string appended with month and year. For Example the name of each table for the month of August 2011 "some_random_string_2011_08". For August there are like 1800 tables like this and similarly for each month starting from year 2009.

Each table has information about user_id, page access etc... basically audit log information The total tables in the database is around 17000. How do I search for user with a particular user_name or any field for that matter for the month of august, and may be this query would be expandable to have a date range. Thanks, Priyank
more ▼

asked Sep 28, 2011 at 06:58 PM in Default

priyank15 gravatar image

priyank15
342 9 9 10

(comments are locked)
10|1200 characters needed characters left

1 answer: sort voted first

DECLARE @ParameterValue VARCHAR(100), @SQL VARCHAR(MAX)

SET @ParameterValue = 'A'

SET @SQL = STUFF((SELECT 'UNION ALL SELECT event_name, User_name FROM '+ TABLE_NAME + ' WHERE User_name = '''+@ParameterValue+'''' AS 'data()' FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME LIKE '%2011_09' -- For 2011 Sept FOR XML PATH('')),1,10,'') EXEC(@SQL)

more ▼

answered Sep 28, 2011 at 10:47 PM

Cyborg gravatar image

Cyborg
10.6k 36 40 45

Hi, Thanks for the quick reply... I tried the query..and it gave me an error on "Invalid column name 'Field'." Its giving the same error even if I change it to any other column name (which I suppose it stands for) like user_name, event_name.. etc, which I know for sure exists as a column in these dated tables.
Sep 28, 2011 at 11:30 PM priyank15
Also to understand the query I wanted to know what the use of the part FOR XML PATH('')),1,10,'')
Sep 28, 2011 at 11:31 PM priyank15
@Priyank15, I have edited the above post, can you try now?
Sep 28, 2011 at 11:42 PM Cyborg
The query is perfect now, thanks for the help!
Sep 29, 2011 at 11:13 AM priyank15
(comments are locked)
10|1200 characters needed characters left
Your answer
toggle preview:

Up to 2 attachments (including images) can be used with a maximum of 524.3 kB each and 1.0 MB total.

New code box

There's a new way to format code on the site - the red speech bubble logo will automatically format T-SQL for you. The original code box is still there for XML, etc. More details here.

Follow this question

By Email:

Once you sign in you will be able to subscribe for any updates here

By RSS:

Answers

Answers and Comments

SQL Server Central

Need long-form SQL discussion? SQLserverCentral.com is the place.

Topics:

x84

asked: Sep 28, 2011 at 06:58 PM

Seen: 1745 times

Last Updated: Sep 28, 2011 at 06:58 PM