-
Notifications
You must be signed in to change notification settings - Fork 1.3k
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
MySQL: rust enum not compatible with SQL ENUM #1241
Comments
Ok, I think I know where the issue comes from. In sqlx the ENUM type is defined as having char_set 63 ( However, if I change the column's collation to
I'm using MariaDB 10.5.10 - not sure if that's the reason for sqlx no getting the data it expects. I hope this helps somewhat. Regards, |
I ran into a similar error message last week. The solution to my issue was to specify the Rust enum type in the query. My column was also named SELECT
actual_start_time `actual_start_time: chrono::DateTime<chrono::Utc>`,
business_date,
end_time `end_time: chrono::DateTime<chrono::Utc>`,
failed_stores,
initiated_by,
kind `kind: crate::tables::batch::Kind`,
scheduled_start_time `scheduled_start_time: chrono::DateTime<chrono::Utc>`,
scheduled_stores,
status,
system_comment,
uid `uid: u64`,
user_comment
FROM batches
WHERE end_time IS NULL
AND initiated_by != ?; Edit: Including the definition of #[derive(Clone, Debug, Deserialize, PartialEq, Serialize, sqlx::Type)]
pub enum Kind {
#[sqlx(rename = "closed")]
Closed,
#[sqlx(rename = "custom")]
Custom,
#[sqlx(rename = "open")]
Open,
#[sqlx(rename = "process")]
Process,
} |
Thanks for your input @euphbriggs! From the errors that I'm getting it seems to me that sqlx is identifying the rust type fine, but there is a mismatch between the ENUM config for that type and the one for the column coming from the DB. |
I did some more digging and this is what I can see. The DB server (or at least my version) is sending a The reason that the error says "ENUM is not compatible with ENUM" is that the method that translates the column type into its name ( Unfortunately, the method that decides if the two types are compatible checks if the two I hope this helps somebody decide what's the correct fix for this issue. Cheers, |
Also faced similar issue:
One way to solve this is to overwrite the FromRow trait as such.
The |
Thank you for the workaround @amitavaghosh1 In fact, if you use the macro version ( However, the issue remains that, for the Regards, |
Right, but the problem with using query_as is it's dependent on one DATABASE_URL , but most of the time there are multiple database connections. Encoding type could be a issue, Not sure. |
I think I am running into the same problem when I am using
Is this supposed to work or am I doing something wrong? I would be really convenient if it worked as it avoids a lot of boilerplate for manual trait implementation. |
Following the in code comments saying this page was followed for I pulled the repo, and made the following changes then it started working just fine for me. sqlx/sqlx-core/src/mysql/type_info.rs new hard coded values to match my database
Cargo.toml path may differ
As a secondary note for others trying to make enums work, I had to force the Enum conversion for query_as to work: reproduction: docker |
Running into this issue in 2023:
Version: Has any progress been made on this issue? |
@khumps Considering that this issue has received no input from the crate maintainers in the two years it's been here, I have a feeling it's not a priority to get this particular thing working right. EDIT: That's not meant as criticism, btw; I realize that a popular project with ~400 open issues has to prioritize. 😄 |
It's not a great solution, but we use a mapper function with For example: fn map_user_entity(row: PgRow) -> Result<UserEntity, sqlx::Error> {
Ok(UserEntity {
id: row.try_get("id")?,
email: row.try_get("email")?,
user_status: row.try_get_unchecked("user_status")?,
})
}
let user = query
.try_map(map_user_entity)
.fetch_one(&self.db)
.await? |
I think this is the issue I just had. I kept getting this error:
And after at least an hour of debugging, I narrowed it down to one of my enums not being properly converted into a string. The workaround I went with was to implement query!(
r"INSERT INTO clients (id, alias, type, secret_hash, secret_salt, secret_version, allowed_scopes, default_scopes, trusted)
VALUES ( ?, ?, ?, ?, ?, ?, ?, ?, ?)",
client.id(),
client.alias(),
client.client_type().to_string(),
client.secret_hash(),
client.secret_salt(),
client.secret_version(),
client.allowed_scopes(),
client.default_scopes(),
client.is_trusted()
)
.execute(transaction.as_mut())
.await?; /// There are two types of clients, based on their ability to maintain the
/// security of their client credentials.
#[derive(Debug, Clone, Copy, PartialEq, Eq, Hash, Serialize, Deserialize, sqlx::Type)]
#[sqlx(rename_all = "lowercase")]
#[serde(rename_all = "SCREAMING_SNAKE_CASE")]
pub enum ClientType {
/// A client that is capable of maintaining the confidentiality of their
/// credentials, or capable of secure client authentication using other
/// means. An example would be a secure server with restricted access to
/// the client credentials.
Confidential,
/// A client that is incapable of maintaining the confidentiality of their
/// credentials and cannot authenticate securely by any other means, such
/// as an installed application, or a web-browser based application.
Public,
}
impl Display for ClientType {
fn fmt(&self, f: &mut std::fmt::Formatter<'_>) -> std::fmt::Result {
f.write_str(match self {
Self::Confidential => "confidential",
Self::Public => "public",
})
}
} |
I have a similar problem. I think the problem releated to uncompartible change of mysql 8.0.22 SEE. The problem have happen on several liblary such as node-mysql2, luadbi, and This discusstion is same. They say Another idea would be to implement |
@alu That is useful information. I did eventually find a way to do it without calling the /// There are two types of clients, based on their ability to maintain the
/// security of their client credentials.
#[derive(Debug, Clone, Copy, PartialEq, Eq, Hash, Serialize, Deserialize)]
#[serde(rename_all = "SCREAMING_SNAKE_CASE")]
pub enum ClientType {
/// A client that is capable of maintaining the confidentiality of their
/// credentials, or capable of secure client authentication using other
/// means. An example would be a secure server with restricted access to
/// the client credentials.
Confidential,
/// A client that is incapable of maintaining the confidentiality of their
/// credentials and cannot authenticate securely by any other means, such
/// as an installed application, or a web-browser based application.
Public,
}
impl Display for ClientType {
fn fmt(&self, f: &mut std::fmt::Formatter<'_>) -> std::fmt::Result {
f.write_str(match self {
Self::Confidential => "confidential",
Self::Public => "public",
})
}
}
impl FromStr for ClientType {
type Err = ();
fn from_str(s: &str) -> Result<Self, Self::Err> {
match s {
"confidential" => Ok(Self::Confidential),
"public" => Ok(Self::Public),
_ => Err(()),
}
}
}
impl sqlx::Type<MySql> for ClientType {
fn type_info() -> MySqlTypeInfo {
<str as sqlx::Type<MySql>>::type_info()
}
}
impl sqlx::Encode<'_, MySql> for ClientType {
fn encode_by_ref(
&self,
buf: &mut <MySql as sqlx::database::HasArguments<'_>>::ArgumentBuffer,
) -> sqlx::encode::IsNull {
<String as sqlx::Encode<MySql>>::encode_by_ref(&self.to_string(), buf)
}
}
impl sqlx::Decode<'_, MySql> for ClientType {
fn decode(
value: <MySql as sqlx::database::HasValueRef<'_>>::ValueRef,
) -> Result<Self, sqlx::error::BoxDynError> {
<&str as sqlx::Decode<MySql>>::decode(value).map(|s| s.parse().unwrap())
}
}
impl From<String> for ClientType {
fn from(value: String) -> Self {
// TODO banish this abomination back to the shadows from whence it came
value.parse().unwrap()
}
} |
@mitchrmiller 's discovery inspired me to come up with a relatively quiet workaround. #[derive(Debug, sqlx::Decode, sqlx::Encode)]
#[sqlx(rename_all = "lowercase")]
enum Size {
Small,
Medium,
Large,
}
impl sqlx::Type<sqlx::MySql> for Size {
fn type_info() -> <sqlx::MySql as sqlx::Database>::TypeInfo {
<str as sqlx::Type<sqlx::MySql>>::type_info()
}
fn compatible(ty: &<sqlx::MySql as sqlx::Database>::TypeInfo) -> bool {
<str as sqlx::Type<sqlx::MySql>>::compatible(ty)
}
} It could also be a macro. macro_rules! impl_enum_type {
($ty:ty) => {
impl sqlx::Type<sqlx::MySql> for $ty {
fn type_info() -> <sqlx::MySql as sqlx::Database>::TypeInfo {
<str as sqlx::Type<sqlx::MySql>>::type_info()
}
fn compatible(ty: &<sqlx::MySql as sqlx::Database>::TypeInfo) -> bool {
<str as sqlx::Type<sqlx::MySql>>::compatible(ty)
}
}
};
}
impl_enum_type!(Size); |
Another workaround is just to cast it as signed: #[derive(sqlx::Type)]
#[repr(i32)]
pub enum Size {
Small = 1,
Medium = 2,
Large = 3,
}
#[derive(sqlx::FromRow)]
struct Shirt {
size: Size
}
sqlx::query_as::<_, Shirt>("select cast(size as signed) size from shirts")" |
If anyone else is still struggling with this, I made a macro which implements the same things /// Implement `sqlx::Type`, `sqlx::Encode` and `sqlx::Decode` for values that can be safely
/// transmuted to another `sqlx::Type`, but can't use `#[derive(sqlx::Type)]` i.e. Nested enums.
#[macro_export]
macro_rules! impl_sqlx_type {
(<$db:ty> $in_ty:ty as $out_ty:ty) => {
impl sqlx::Type<$db> for $in_ty {
fn type_info() -> <$db as sqlx::Database>::TypeInfo {
<$out_ty as sqlx::Type<$db>>::type_info()
}
fn compatible(ty: &<$db as sqlx::Database>::TypeInfo) -> bool {
<$out_ty as sqlx::Type<$db>>::compatible(ty)
}
}
impl sqlx::Encode<'_, $db> for $in_ty {
fn encode_by_ref(&self, buf: &mut <$db as HasArguments<'_>>::ArgumentBuffer) -> IsNull {
#[allow(clippy::transmute_ptr_to_ptr)]
let out: &$out_ty = unsafe { std::mem::transmute(self) };
<$out_ty as sqlx::Encode<$db>>::encode_by_ref(out, buf)
}
}
impl sqlx::Decode<'_, $db> for $in_ty {
fn decode(value: <$db as HasValueRef<'_>>::ValueRef) -> Result<Self, BoxDynError> {
<$out_ty as sqlx::Decode<$db>>::decode(value)
.map(|v| unsafe { std::mem::transmute(v) })
}
}
};
} Usage is i.e.: impl_sqlx_type!(<Sqlite> EventType as u32); In this case, #[derive(Debug, Copy, Clone, Eq, PartialEq)]
#[repr(u16)]
pub enum EventType {
Common(CommonEvent),
DB(DBEvent),
} Where the types nested within it are also enums: #[derive(sqlx::Type, Debug, Copy, Clone, Eq, PartialEq)]
#[repr(u16)]
pub enum CommonEvent {
Created,
Destroyed,
} This is only useful if your type can be safely transmuted to another type which already implements |
Tentatively closed by #2652, feel free to open a new issue if this is not fixed. |
Hi,
I've hit an issue with ENUMs in MySQL and, after reviewing docs and issues here, I can't find anything that helps with this particular problem. Basically, the error says that type 'ENUM' is not compatible with type 'ENUM':
The relevant (abridged) code is this:
The DB schema looks like this (again, abridged):
This was happening with v0.5.1 and is still happening after upgrade to v.0.5.4
I'm guessing that I have hit a fairly obscure issue, or that I'm missing something pretty basic.
Any help would be appreciated.
Regards,
Alfonso
The text was updated successfully, but these errors were encountered: