Please HELP !! :SQL SERVER with MySQL Linked Server. Error Executing Trigger

  • Hi sirs ! If somebody can help me i would appreciate a lot !

    I have SQL server with MySQL Linked server through ODBC.

    Also have a Trigger on SQL Server Table :

    ALTER TRIGGER [dbo].[TriggerStock]

    ON [dbo].[T_Contabilidad]

    FOR UPDATE,insert

    AS

    BEGIN

    DECLARE

    @Id integer,

    @Stock integer

    SELECT @ID = Idt_Conta,@stock=Stock FROM INSERTED

    IF @Stock>0

    BEGIN

    UPDATE OPENQUERY(MYSQLVINC,'SELECT Idt_web, disponible FROM mibasedatos.t_web

    where idt_web=@id') SET disponible= 1

    END

    ELSE

    BEGIN

    UPDATE OPENQUERY(MYSQLVINC,'SELECT Idt_web, disponible FROM mibasedatos.t_web

    where idt_web=@id') SET disponible= 0

    END

    END

    The idea : I NEED TO UPDATE MySQL TABLE WHEN SQL SERVER Table is UPDATED/INSERT

    PROBLEM : SQL throws an error :

    Mens 7390, Nivel 16, Estado 2, Procedimiento TriggerStock, Línea 18

    No se pudo realizar la operación solicitada porque el proveedor OLE DB "MSDASQL" del servidor vinculado "MYSQLVINC" no admite la interfaz de transacción requerida.

    (In english : Could'nt do the operation because of OLE DB MSDASQL from linked server does'nt admit transation required interface.

    Any help please ? Thanks in advance

  • First, let me say that your trigger will cause you problems as it does not cater for multiple row updates, this is something you should look into changing as soon as possible.

    Now, moving on to your immediate problem, this can be handled slightly differently.

    My recommendation to you is to not attempt to do cross system updates within a trigger.

    Better would be to write the updates to a local sql server database and process them outside of the transaction (the transaction that fired the trigger), this will remove the potential bottleneck every time you update your table.

    Something like this would be your table to hold details of updates required to your MySQL table:

    create table some_holding_table(inserted_time datetime default(getdate()) not null, ID int, Stock int);

    GO

    And your trigger would be something like this:

    ALTER TRIGGER [dbo].[TriggerStock]

    ON [dbo].[T_Contabilidad]

    FOR UPDATE,insert

    AS

    BEGIN

    INSERT some_holding_table(ID,Stock)

    SELECT Idt_Conta,Stock FROM INSERTED

    END

    GO

    Then you have a periodic process to read "some_holding_table" and perform the required updates to the remote system.

    MM



    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);

  • Forum Etiquette: How to post Reporting Services problems
  • [/url]
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • [/url]
  • How to Post Performance Problems - by Gail Shaw
  • [/url]

  • First of all, thanks for your advices.

    The problem continues alive, I need to update to MySQL Server, how can i do that ? Could you be more explicit ? I m sorry, i m not an expert on SQL Server.

    Thanks again

  • This is not a simple problem, but mister.magoo is correct. The trigger way is not likely to work out well. First a few words on why the trigger you have does not work at all:

    SELECT @ID = Idt_Conta,@stock=Stock FROM INSERTED

    This is the first error. A trigger fires once per statement, and a INSERT or UPDATE statement could affect multiple rows. You are only catering for one of them.

    UPDATE OPENQUERY(MYSQLVINC,'SELECT Idt_web, disponible FROM mibasedatos.t_web

    where idt_web=@id')

    This is the second error. The SELECT statement you pass to OPENQUERY is executed in MySQL where @id is likely to be a syntax error. It certainly has no relation to your local variable @id. To get the value into the query you would need to use dynamic SQL. But as already noted, @id should not be there at all, since you need to handle multiple-row operations.

    This could work in theory:

    UPDATE MYSQLVINC..mibasedatos.t_web

    SET disponible = CASE WHEN i.Stock > 0 THEN 1 ELSE 0 END

    FROM MYSQLVINC..mibasedatos.t_web m

    JOIN inserted i ON m.idt_web = i.Idt_conta

    But I would be surprised that it actually does in practice.

    As Mister.magoo suggests you need to find an asynchronous solution. The trigger could popoulate a queue table which you poll reguarly. You could also implement Change Tracking (which means that SQL Server maintains that queue table for you.)

    [font="Times New Roman"]Erland Sommarskog, SQL Server MVP, www.sommarskog.se[/font]

  • Thank you so much !

    I 'll try this first, if it works, I 'll study the problem of several rows.

    Thanks a lot, seriously !

  • your original error may be due to SQL server attempting to enlist a distributed transaction and MySQL cannot take part in that transaction.

    This would be because you are attempting to update MySQL from a trigger and the code is therefore running as part of the transaction that fires the trigger.

    I am not sure about this because I don't ever use MySQL, but that seems to be what the error is saying.

    This is another reason to move the remote update outside of the trigger....

    MM



    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);

  • Forum Etiquette: How to post Reporting Services problems
  • [/url]
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • [/url]
  • How to Post Performance Problems - by Gail Shaw
  • [/url]

  • mister.magoo (7/8/2013)


    your original error may be due to SQL server attempting to enlist a distributed transaction and MySQL cannot take part in that transaction.

    This would be because you are attempting to update MySQL from a trigger and the code is therefore running as part of the transaction that fires the trigger.

    You are right. I did not look too close on the error message, as there was an obvious syntax error in the MySQL query (the variable @id). But I more or less expect that the query I suggested would die with that error. Since you are in a trigger, you are in a transaction, and by default SQL Server attempts to make that a distributed transaction. (This can be changed with sp_serveroption). A distributed query may have better odds to work, if one uses the OLE DB provider for MySQL rather than MSDASQL + ODBC, but I would not count on it.

    (Just like Mister Magoo, I have no experience of MySQL myself.)

    [font="Times New Roman"]Erland Sommarskog, SQL Server MVP, www.sommarskog.se[/font]

  • Erland Sommarskog - Author of several excellent writings and the host of sp_sqltrace. Very nice you see you here. Welcome!

  • Viewing 8 posts - 1 through 7 (of 7 total)

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