Inserting Rows into an Audit Table

  • I have an application that consists of MS Access with VBA as the Front End and SQL Server 2012 as the Backend.

    I have a bunch of audit tables that I use instead of triggers. I have one audit table for each regular table that I choose to audit. The first five columns are the same for all audit tables as follows:

    audID

    audType

    audDate

    audUser

    audTxnName

    The rest of the fields are named exactly the same as the columns in the corresponding table I'm logging changes for. At one point in the process I want to put specific values in the four fields after audID (which is an Identity field) and then just copy all the rest of the fields from the source table. I've tried the following code:

    I set the string sSql to...

    INSERT INTO audUsers (audType, audDate, audUser, audTxnName)

    SELECT 'EditTo' AS Expr1,

    '3/1/2015 12:33:06 PM' AS Expr2,

    'Sally Brown' AS Expr3,

    'LoadUser' AS Expr4,

    Users.* FROM Users

    WHERE (Users.DetailID = 22);

    and then execute it with...

    Cnxn.Execute sSql, dbFailOnError

    When I try to execute this in VBA or in the Query window of SSMS, I get the following error...

    The select list for the INSERT statement contains more items than the insert list. The number of SELECT values must match the number of INSERT columns.

    I can run this code using DAO, but I would rather use SQL because I would imagine it would be much faster.

    Can someone tell me what I'm missing here?

    Thanks, Eddie

  • Yes... I you look at your code...

    INSERT INTO audUsers (audType, audDate, audUser, audTxnName)

    SELECT 'EditTo' AS Expr1,

    '3/1/2015 12:33:06 PM' AS Expr2,

    'Sally Brown' AS Expr3,

    'LoadUser' AS Expr4,

    Users.* FROM Users

    WHERE (Users.DetailID = 22);

    ... you have only defined 4 columns in the insert statement but the SELECT will have at least 5 columns because you've defined 4 and then used "Users.*". I would imagine that will return more than just 1 column, as well.

    The number of columns in the INSERT-columnlist must match the number of columns returned by the SELECT. "*" isn't just one column.

    It's easy enough to copy all the column names. Just expand the table in the Object Explorer of SSMS, click on the "columns" "folder" and drag it into the query screen.

    As a bit of a sidebar, you could save yourself a shedload of trouble if you did this auditing using properly formed triggers. It'll also save you a huge headache when the table gets an extra column added somewhere to the middle of it. You shouldn't use "*" for such things because of such possibilities.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 2 posts - 1 through 1 (of 1 total)

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