Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Incorrect arguments to mysqld_stmt_execute (MySQL 8.0.22) #1239

Open
perry-mitchell opened this issue Oct 29, 2020 · 56 comments
Open

Incorrect arguments to mysqld_stmt_execute (MySQL 8.0.22) #1239

perry-mitchell opened this issue Oct 29, 2020 · 56 comments

Comments

@perry-mitchell
Copy link

perry-mitchell commented Oct 29, 2020

Hi, love this library!

Have been using it successfully across a large number of projects and it's worked flawlessly for me so far. Just now I've seen that I have a single test case failing on the CI server (Gitlab), MySQL 8, failing with the following error:

VError: Failed executing query: \"SELECT * FROM message WHERE chat_id = ? ORDER BY sent DESC LIMIT ? OFFSET ?\" [01ensmg6m4dea0gh7gsjgaa5gb, 50, 0]: Incorrect arguments to mysqld_stmt_execute
    at ConnectionPool.<anonymous> (/data/node_modules/@my-company/mysql-connection-pool/dist/ConnectionPool.js:128:27)
    at Generator.throw (<anonymous>)
    at rejected (/data/node_modules/@my-company/mysql-connection-pool/dist/ConnectionPool.js:6:65)
    at processTicksAndRejections (internal/process/task_queues.js:97:5)
caused by: Error: Incorrect arguments to mysqld_stmt_execute
    at PromiseConnection.execute (/data/node_modules/mysql2/promise.js:110:22)
    at ConnectionPool.<anonymous> (/data/node_modules/@my-company/mysql-connection-pool/dist/ConnectionPool.js:117:58)
    at Generator.next (<anonymous>)
    at fulfilled (/data/node_modules/@my-company/mysql-connection-pool/dist/ConnectionPool.js:5:58)

Now this error is wrapped by my own logic, but the cause I think it quite clear: Incorrect arguments to mysqld_stmt_execute. The query being passed to the execute method on the mysql2/promise library is SELECT * FROM message WHERE chat_id = ? ORDER BY sent DESC LIMIT ? OFFSET ? and the values are ["01ensmg6m4dea0gh7gsjgaa5gb", 50, 0]. For some reason this only fails on the CI, and not locally on any of my (or my colleagues') machines.

If I change this to query instead of execute, it works on the CI. If I form this query manually using the values that were passed-in, and run it, it also works.

Any idea what's happening here? Is there some failure in how the parameters are being transferred to the MySQL service before being inserted?

EDIT 1: I'm also using v2.2.5 of the library

EDIT 2: Seems after the suggestions made here that the issue, at least for me, is only with mysql2 and MySQL server 8.0.22. 8.0.21 seems to work fine.

@perry-mitchell
Copy link
Author

Not sure it helps, but this is the usage:

export async function getChatMessages(
    chatID: string,
    limit: number,
    offset: number = 0,
    connection = getConnection()
): Promise<Array<MessageSlow>> {
    const [
        rows
    ] = await connection.execute(
        `SELECT * FROM message WHERE chat_id = ? ORDER BY sent DESC LIMIT ? OFFSET ?`,
        [chatID, limit, offset]
    );
    // Snip
}

@sidorares
Copy link
Owner

Could you try to prepare from mysql cli?

mysql> PREPARE stmt1 FROM 'SELECT * FROM message WHERE chat_id = ? ORDER BY sent DESC LIMIT ? OFFSET ?';

trying to make sure sql syntax is valid ( there are limitation on to what can be a placeholder in PS )

@sidorares
Copy link
Owner

hm, re reading your text, it works on local machine. Can you double check your local mysql server version is exactly the same as on CI?

@dimitar3web
Copy link

dimitar3web commented Oct 29, 2020

I have the same problem since i updated mysql from 8.0.21 -> 8.0.22. I am pretty sure that my queries are alright cause i didnt have any issues before version upgrade. I`ve got ubintu (20.04) which I updated yesterday and after installing the update this error started. I tested the queries on older version (before yesterdays update) and it seems to work without any problem. Any advice?

A workaround that I found yesterday was, pasring the bindedparms to string as such: bindedparams.map(i => i.toString()) ; If the params are left as integers the error appears

{
code: 'ER_WRONG_ARGUMENTS',
errno: 1210,
sqlState: 'HY000',
sqlMessage: 'Incorrect arguments to mysqld_stmt_execute'
}

@perry-mitchell
Copy link
Author

Ok, that was a good recommendation @sidorares - I was not using the same version locally. I've updated my local to MySQL 8.0.22 and now it fails on many queries:

VError: Failed executing query: "
    SELECT
        m.chat_id,
        MAX(m.sent) AS sent,
        c.channel,
        c.is_completed
    FROM message AS m
    INNER JOIN chat AS c ON c.id = m.chat_id
    WHERE
        sent <= ? AND
        c.is_completed = 0
    GROUP BY m.chat_id
    LIMIT ?
" [2020-10-29 10:11:45, 10]: Incorrect arguments to mysqld_stmt_execute

Variables above being ["2020-10-29 10:11:45", 10]

@sidorares
Copy link
Owner

@ruiquelhas could you comment on this 8.0.21 -> 8.0.22 incompatibility?

@ruiquelhas
Copy link
Contributor

Yeah, there were some major changes with regards to how prepared statements work in the server (type inferences and whatnot), and unfortunately some specific queries might break. I'll look at this specific example as well. Thanks for the mention @sidorares.

@ruiquelhas
Copy link
Contributor

@perry-mitchell what's the column datatype of chat_id? Just so I can re-create the exact same scenario.

@perry-mitchell
Copy link
Author

perry-mitchell commented Oct 29, 2020

@ruiquelhas chat_id is a string, 26 chars. The values being inserted in that first query are ["01ensmg6m4dea0gh7gsjgaa5gb", 50, 0].

Confirming that 8.0.21 works for me, and 8.0.22 presents these prepare statement errors.

@perry-mitchell perry-mitchell changed the title Incorrect arguments to mysqld_stmt_execute Incorrect arguments to mysqld_stmt_execute (MySQL 8.0.22) Oct 29, 2020
@ruiquelhas
Copy link
Contributor

@ruiquelhas chat_id is a string, 26 chars. The values being inserted in that first query are ["01ensmg6m4dea0gh7gsjgaa5gb", 50, 0].

Confirming that 8.0.21 works for me, and 8.0.22 presents these prepare statement errors.

@perry-mitchell I mean on the table column itself. The MySQL column datatype. Which one of these?

@perry-mitchell
Copy link
Author

@ruiquelhas varchar(30) sorry..

@bkarlson
Copy link

Just stumbled upon the same problem. A statement works fine when using query, but fails with execute:

Error: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near '? ORDER BY video_id DESC LIMIT ?' at line 1

@bkarlson
Copy link

bkarlson commented Oct 29, 2020

as a matter of fact, something's weird is on mysql side, working query cannot be prepared:

mysql> PREPARE stmt SELECT video_id FROM videos ORDER BY video_id DESC LIMIT 10;
ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'SELECT video_id FROM videos ORDER BY video_id DESC LIMIT 10' at line 1


mysql> SELECT video_id FROM videos ORDER BY video_id DESC LIMIT 10;
+-----------+
| video_id  |
+-----------+
[...]
+-----------+
10 rows in set (0.00 sec)

@sidorares
Copy link
Owner

@bkarlson try this:

mysql> PREPARE stmt1 FROM 'SELECT video_id FROM videos ORDER BY video_id DESC LIMIT 1';

@bkarlson
Copy link

bkarlson commented Oct 29, 2020

well okay, that was a lame act on my side with mysql, yet this statement works with query but not with execute

const sqlVideos = `SELECT video_id FROM videos ORDER BY video_id DESC LIMIT ?`; 
pool.query(sqlVideosToProcess, [batchSize], async (err, rows) => {..

@sidorares
Copy link
Owner

@bkarlson probably not relevant to the topic, but why async callback?

@sidorares
Copy link
Owner

what error with execute? You have an error in your SQL syntax ?

@bkarlson
Copy link

@bkarlson probably not relevant to the topic, but why async callback?

I'm just refactoring old mysql code to mysql2 with promises, and stumbled upon this issue. Now wondering whether the rest of my queries would work...

@bkarlson
Copy link

what error with execute? You have an error in your SQL syntax ?

yes

@ruiquelhas
Copy link
Contributor

@perry-mitchell what about the datatype of the sent column?

@ruiquelhas
Copy link
Contributor

ruiquelhas commented Oct 29, 2020

@sidorares from a preliminary analysis, I'm not able to reproduce this issue with the mysql CLI or other wire protocol implementations with prepared statement support. Again, this seems to be related to the changes in how prepared statements work with regards to type inference and whatnot. As described in the 8.0.22 server release notes.

Important Change: A prepared statement is now prepared only once, when executing PREPARE, rather than once each time it is executed. In addition, a statement inside a stored procedure is also now prepared only once, when the stored procedure is first executed. This change enhances performance of such statements, since it avoids the added cost of repeated preparation and rollback of preparation structures, the latter being the source of several bugs.

From what I can tell, one of the problems is that when encoding the COM_STMT_EXECUTE this driver is mapping all JavaScript number values to MYSQL_TYPE_DOUBLE and ignoring the type hint available in the COM_STMT_PREPARE Response.

In this specific case, if we force the driver to encode the value using a MYSQL_TYPE_LONGLONG type (which is the one suggested by the server after the prepare stage), it seems to work fine.

In any case, I'm still trying to figure out the entire thing. In the meantime, we can take this "offline" and discuss how can this be addressed from the client POV, because the server will own these changes.

@perry-mitchell
Copy link
Author

perry-mitchell commented Oct 29, 2020

what about the datatype of the sent column?

@ruiquelhas It's a timestamp

@sidorares
Copy link
Owner

Important Change: A prepared statement is now prepared only once, when executing PREPARE, rather than once each time it is executed.

@ruiquelhas can you clarify this?

That is also current behaviour or mysql2 driver: it sends COM_PREPARE only once for the first .execute() call and later if query is the same statement id is re used. I read server changelog the same way: when you do PREPARE command, after parsing it server uses body of the prepare argument and caches result ( previously each new PREPARE would generate new statement id ) - is that correct?

@sidorares
Copy link
Owner

sidorares commented Oct 29, 2020

mapping all JavaScript number values to MYSQL_TYPE_DOUBLE and ignoring the type hint available in the COM_STMT_PREPARE Response.

yes. Initially this driver was using string type for all parameters relying on server to do all the translation to actual expected types, and right now types are inferred from JS parameters ( and not on based on what we know server expects as a parameter ) - added in #353 and #705

also ref
#516 (comment)
( I'm sure I discussed "we need to use types from prepare response to serialize parameters" somewhere before but can't find it )

@ruiquelhas
Copy link
Contributor

Important Change: A prepared statement is now prepared only once, when executing PREPARE, rather than once each time it is executed.

@ruiquelhas can you clarify this?

That is also current behaviour or mysql2 driver: it sends COM_PREPARE only once for the first .execute() call and later if query is the same statement id is re used. I read server changelog the same way: when you do PREPARE command, after parsing it server uses body of the prepare argument and caches result ( previously each new PREPARE would generate new statement id ) - is that correct?

Yeah, the client flow is/was fine. That just mentions the change that happened in the server, which internally was always preparing statements once for each execution. That isn't the case anymore, and the statements are now prepared effectively once (only when PREPARE is called i.e. when COM_STMT_PREPARE is sent). This caused some changes in the way dynamic parameters used in prepared statements are resolved (in particular when it comes to derive their type). Up until now, you could get away with sending different parameter types in the COM_STMT_EXECUTE, and the statement would basically be re-prepared using that type. This isn't the case now, and even though I haven't explored it in full, I guess, at least, COM_STMT_EXECUTE will have to use the types hinted by the COM_STMT_PREPARE Response.

If you are interested, the full write-up of those server changes is available here.

@dalalmj
Copy link

dalalmj commented Jan 14, 2021

Any update to this? Facing same error on 8.0.22 and on 8.0.19. Works with query, fails with execute (works properly on 8.0.14)

@sidorares
Copy link
Owner

@dalalmj no update on my side, reading @ruiquelhas comment I guess we need to make sure that types used for serialising parameters are exactly those returned by COM_STMT_PREPARE response ( right now we use dynamically whatever is parameters - number / string / buffer etc ) - might be wrong, need to double check

@ruiquelhas
Copy link
Contributor

@dalalmj if it happens on 8.0.19 then it's probably not related to this specific issue. The changes I mentioned were only introduced by the MySQL server in 8.0.22.

@alisson-acioli
Copy link

Hello, is this problem still persisting? I am passing this now on 08/2023

@sidorares
Copy link
Owner

@alisson-acioli yes, to a degree. You can work around it by casting your data to a more compatible type ( for example, pass number as a string ). We plan to add api to set mysql type of a parameter explicitly

@mikiU2022
Copy link

this problems persist... it's dec/2023.....

@sidorares
Copy link
Owner

@mikiU2022 its still November on my calendar, but thanks for the ping

@BlockifyTechnologies
Copy link

BlockifyTechnologies commented Nov 22, 2023

      const sql = `SELECT * FROM DB.Users WHERE uid > ? ORDER BY uid LIMIT ?`;
      const values = [0, 50];

      try {
        const [results] = await connection.execute(sql, values);
        console.log("SQL Result: ", results);
      } catch (error) {
        console.error("Error executing SQL query:", error);
      }

Why would a query as simple as this give me the error of incorrect arguments ?

@sidorares
Copy link
Owner

@BlockifyTechnologies short explanation: currently argument type is inferred from JS type ( you can see mapping here ). Previously this worked fine as the server was able to convert to type actually expected by the statement, but after version 8.0.22 this behaviour changed, see #1239 (comment)

Workaround for you right now: force it to be sent as string, const values = ['0', '50'];. In the future we'll add ability to explicitly set parameter type, the api would be something like this: const values = [mysql.types.LONGLONG(0), mysql.types.LONGLONG(50)]; - that way 0 and 50 are sent as LONGLONG instead of default DOUBLE. Also we plan to potentially change default type to be the one returned from prepare call, but this can be unreliable ( execute('SELECT ? as data') would have a type, likely LONG, set in a response but in reality its "unknown type" )

@BlockifyTechnologies
Copy link

@sidorares
const values = [mysql.types.LONGLONG(0), mysql.types.LONGLONG(50)]; this seems like the perfect path to take. Hope this won't take too long! Thanks

@perry-mitchell
Copy link
Author

We wrote a query wrapper in house to do this automatically.. and haven't had to think about it since. This particular problem can be abstracted away somewhat easily :)

@sidorares
Copy link
Owner

@perry-mitchell please share it!

@perry-mitchell
Copy link
Author

perry-mitchell commented Nov 23, 2023

I'm still in the process of convincing management to release the code. Trust me, if it were solely my decision I'd have responded with a link to it. I'll update here if something changes.

EDIT: Process is looking good, we might consider a release in the near future. Mind you the code is actually quite simple, so I don't think it's anything ground breaking. We're mostly just casting numbers => string in the parameters when detected. The library does provide improved pooling logic we had to write for AWS RDS instances (auto-stale connections), so maybe something else is beneficial there.

EDIT 2: My company agreed for me to open source the repo. I'll have it up in the coming days.

@fires3as0n
Copy link

I am sorry, but 4 years have passed since this issue was raised, there is MySQL 9 out there, I'm using the latest version of node-mysql2 library and still have to apply this solution by damianobarbati in every project.

If this is not going to be fixed any time in the future, am thinking about just cloning the repo and disabling this case statement
As a temporary solution, to avoid patching the execute in server side code, but I wonder, won't it break anything?

The library itself is great, no push, I understand that this is a minor problem and appreciate your time for the open source. Thank you.

@sidorares
Copy link
Owner

hey @fires3as0n thanks for a friendly nudge
If you have a capacity for a proper solution I can try to guide you.

Initial step I see is to allow to manually specify the type. For example, we'll provide a value+type containers, and when you pass a value using that container the data type and serialisation format will match to that of the parameter.

example:

// not sure about naming, say we have StatementParameter exported with DOUBLE/LONG etc fields on them

connection.execute(`SELECT video_id FROM videos ORDER BY video_id DESC LIMIT ?`, StatementParameter.LONG(1))

execute command would be able to see type hint and use LONG instead of incorrect DOUBLE

@vlasky
Copy link

vlasky commented Aug 5, 2024

I'm still in the process of convincing management to release the code. Trust me, if it were solely my decision I'd have responded with a link to it. I'll update here if something changes.

EDIT: Process is looking good, we might consider a release in the near future. Mind you the code is actually quite simple, so I don't think it's anything ground breaking. We're mostly just casting numbers => string in the parameters when detected. The library does provide improved pooling logic we had to write for AWS RDS instances (auto-stale connections), so maybe something else is beneficial there.

EDIT 2: My company agreed for me to open source the repo. I'll have it up in the coming days.

@perry-mitchell where can I find your repo with the node-mysql2 query wrapper code?

@Sohamnimbalkar07
Copy link

Sohamnimbalkar07 commented Aug 27, 2024

pageSize = 8;
const offset = (pageNumber - 1) * pageSize;
const query = select column_names from table_name where some_column = ? and another_column = ? limit ${pagesize} offset ${offset};
const [result] = await connection.execute(query, [column1, column2]);

write query like this.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

No branches or pull requests