UNION Help

  • I have a database that contains a number of individual tables for each sales agents. I need to find a way to set up a query that dynamically unions all tables in the database, so as an new agent joins the business their table will automatically be picked up in the union. The idea being, I have 1 table that contains the information for all agents.

    Any help would be greatly appreciated.

    Many thanks in advance.

    Tables in database ( example)

    David

    John

    Steven

    Columns in agents table ( example)

    ,[Start_Time]

    ,[End_Time]

    ,[Record_Type]

    ,[User_Action]

    ,[Direction]

    ,[Action_Data]

    ,[From_addr]

    ,[To_addr]

    ,[Subject]

    ,[Detail]

    ,[Company]

    ,[Contact]

    ,[FullPath]

  • It would be possible to build a dynamic query that checks for tablenames, and checks if those tables have the columns corresponding to an agent table, and if so includes them in the union, but it would be quite complex, and from an SQL Server point of view, like using a Ferrari to plough a field.

    Much better to use the relational database in the way it is designed to be used.

    Create an Agents_Name Table, with an ID column

    Add and AgentName_ID column to your Agent table.

    This way, all agents share the same Agent Table, but are identified by AgentName_ID

    Then instead of a union, you only query one table, possibly joining to the AgentName table to get the name if needed.

  • DBayliss, if you can follow t.brown's advice, that would be the best solution to your issue. If you are constrained from making changes to the existing schema, here are a couple of thoughts.

    1) Create a new table per t.brown's advice and have a job that inserts the new agent information when a new agent is added. Then use that to hit all the other tables. You could (though this would be poor relational programming) even include the agent's table name as a column in the agent's table.

    2) Loop through information_schema.tables and pull the table_name values from there. Regardless of how you dynamically pull these table names, you would have to have an idea of what separates these agent tables from all the other tables. Or you could just throw the agent table names into a brand new table (maybe even that table into a new DatabaseAdmin database) that you can pull the agent tables from. Use Dynamic SQL to do your UNION / UNION ALL.

    BTW, I don't really recommend this as your best option.

    3) Use a staging table to merge all the agent table data into, then query off of that. You could use any number of things to keep the staging table updated, like replication, or a regular LEFT OUTER JOIN type of INSERT statement, or even an SSIS package with slowly changing dimensions. The options depend on your data, really.

    Brandie Tarvin, MCITP Database AdministratorLiveJournal Blog: http://brandietarvin.livejournal.com/[/url]On LinkedIn!, Google+, and Twitter.Freelance Writer: ShadowrunLatchkeys: Nevermore, Latchkeys: The Bootleg War, and Latchkeys: Roscoes in the Night are now available on Nook and Kindle.

  • If you created this database structure, please read up on database normalisation and correct the structure before you go any further down this design.

    If someone else created it and they are still around, go and puch them on the nose.

    If they are not around go and punch the wall.

    If you have to stick with this design, I would create a table of agents and a stored procedure that writes a view using dynamic SQL that is triggered every time the agents table is altered.

    the view with UNION ALL the same query once for each agent table

    The problem is that any other view or stored procedure that uses that generated view will also need to be recompiled every time the view changes.

    SERIOUSLY, get the data normalised.

  • DBayliss - I looked at your other posts, and I think you've been landed with this task to maintain someone elses questionable code.

    Brandie's Idea (2), while not ideal, can be done as follows.

    First get the tables of type Agent - using the column names common to the Agent Tables as shown here (you can extend it to all the column names for greater accuracy)

    SELECT DISTINCT T.TABLE_NAME

    FROM INFORMATION_SCHEMA.TABLES AS T

    JOIN INFORMATION_SCHEMA.COLUMNS AS C ON C.TABLE_NAME = T.TABLE_NAME

    WHERE C.COLUMN_NAME IN ( 'Start_Time' , 'End_Time', 'Record_Type', 'User_Action')

    Then Dynamically create a SELECT statement from each of these, UNIONing them all together I've only included a few of the columns in the select - as follows.

    Note: The fancy row_number bit is just to identify the last row, so it doesn't get a UNION ALL following.

    DECLARE @SQL VARCHAR(MAX)

    SET @SQL = '';

    ;WITH AgentTables AS (

    SELECT DISTINCT T.TABLE_NAME

    FROM INFORMATION_SCHEMA.TABLES AS T

    JOIN INFORMATION_SCHEMA.COLUMNS AS C ON C.TABLE_NAME = T.TABLE_NAME

    WHERE C.COLUMN_NAME IN ( 'Start_Time' , 'End_Time', 'Record_Type', 'User_Action')

    ), NumberedTables AS (

    SELECT TABLE_NAME, ROW_NUMBER() OVER (ORDER BY TABLE_NAME) AS RowNum

    FROM AgentTables

    )

    SELECT @SQL = @SQL + ' SELECT ''' + TABLE_NAME +''' AS AgentName, [Start_Time], [End_Time], [Record_Type] FROM ' + TABLE_NAME +

    CASE WHEN RowNum = (SELECT COUNT(*) FROM NumberedTables) THEN ''

    ELSE ' UNION ALL '

    END

    FROM NumberedTables

    ORDER BY TABLE_NAME

    -- PRINT @SQL;

    EXEC (@SQL);

    This may get you out of a hole for now, but fixing the normalization is the way to go.

  • aaron.reese (9/10/2012)


    the view with UNION ALL the same query once for each agent table

    Not something I recommend. The view will have to be recreated every time a new agents table is added, and it can break if the schema on any of the underlying tables is altered (except if WITH SCHEMABINDING is used, and that introduces its own issues).

    Plus the more UNIONs get added to a query, the worse the performance becomes. It gets really messy really quickly.

    Brandie Tarvin, MCITP Database AdministratorLiveJournal Blog: http://brandietarvin.livejournal.com/[/url]On LinkedIn!, Google+, and Twitter.Freelance Writer: ShadowrunLatchkeys: Nevermore, Latchkeys: The Bootleg War, and Latchkeys: Roscoes in the Night are now available on Nook and Kindle.

  • couldn't agree more!

    šŸ˜‰

  • Celko,

    Cute joke.

    Now do you actually have advice that is any different from that which was already offered?

    Brandie Tarvin, MCITP Database AdministratorLiveJournal Blog: http://brandietarvin.livejournal.com/[/url]On LinkedIn!, Google+, and Twitter.Freelance Writer: ShadowrunLatchkeys: Nevermore, Latchkeys: The Bootleg War, and Latchkeys: Roscoes in the Night are now available on Nook and Kindle.

  • CELKO (9/11/2012)


    Comments deleted.

    Really Mr. Celko? Your entire post is inappropriate, rude, and unprofessional. I personally would like to see you just leave this site and not come back.

  • CELKO (9/11/2012)


    I have a database that contains a number of individual tables for each sales agents.

    This design flaw is called attribute splitting. Would you have ā€œMale_Personnelā€ and ā€œFemale_Personnelā€ tables or a single ā€œPersonnelā€ table? Pretty obvious, isn't it? ...

    That is really bright idea! Actually, taking in count progress of the west civilization in whole, you need at least three tables:

    ā€œMale_Personnelā€, ā€œFemale_Personnelā€ and "Unknown_Personnel" :hehe:

    Actually the attribute splitting may not be a flaw, but done on purpose. One of the common places where you can see this kind of picture is data warehouses (non-conformed dimensions).

    There are other design patterns where attribute splitting is a feature - not a flow.

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Eugene Elutin (9/11/2012)


    Actually the attribute splitting may not be a flaw, but done on purpose. One of the common places where you can see this kind of picture is data warehouses (non-conformed dimensions).

    Or companies that vend solutions to multiple customers and can't mix their data for legal reasons. Like health insurance software companies that host the data on site. I actually worked for one of those.

    Of course, in that instance, any request to mingle the data via UNION (at least in the U.S.) would be a Bad Idea.

    Brandie Tarvin, MCITP Database AdministratorLiveJournal Blog: http://brandietarvin.livejournal.com/[/url]On LinkedIn!, Google+, and Twitter.Freelance Writer: ShadowrunLatchkeys: Nevermore, Latchkeys: The Bootleg War, and Latchkeys: Roscoes in the Night are now available on Nook and Kindle.

Viewing 11 posts - 1 through 10 (of 10 total)

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