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

More useful examples #1014

Open
pythoneer opened this issue Jan 24, 2021 · 24 comments
Open

More useful examples #1014

pythoneer opened this issue Jan 24, 2021 · 24 comments

Comments

@pythoneer
Copy link

pythoneer commented Jan 24, 2021

It would be very helpful to get more examples that show the features and possibilities of this library. It would help tremendously to set boundaries of what to expect for newcomers. This could help to mitigate the currently missing guide. As a newcomer it is very frustrating to get to a starting point or even validate if this library is a good fit for what one is searching for. Yes the documentation is quite good but it is only useful for people that are familiar with the project and know what to look for. Chasing types might also be to hard in the beginning to interpret certain error messages.

If you want to achieve something – and thus having an expectation – it is very hard to

  1. find information if it is possible what you want to achieve
  2. find information how to achieve it if you think it is possible

To give a concrete example and use case. As a newcomer i want to create an application that manages accounts, addresses and posts written from these accounts. So that is your common one to one and one to many relationship. One account has a single address and has many posts. How do i achieve that with SQLx? Digging through the documentation and the sparse examples you learn about query_as and sqlx::Type and end up with a starting point that has you covered with accounts and addresses

create table address (
	address_id BIGSERIAL primary key,
	street text not null,
	street_number text not null,
	city text not null,
	country text not null	
);

create table accounts (
	account_id BIGSERIAL primary key,
	user_name text not null,
	address_id BIGINT,
	constraint fk_address foreign key(address_id) references address(address_id)
);
#[derive(Debug, sqlx::Type)]
struct Address {
    address_id: i64,
    street: String,
    street_number: String,
    city: String,
    country: String,
}

#[derive(Debug)]
struct AccountNoPost {
    account_id: i64,
    user_name: String,
    address: Address,
}

async fn get_account_with_address(pool: &PgPool) -> Result<(), sqlx::Error> {
    let account = sqlx::query_as!(AccountNoPost, r#"
        select 
          ac.account_id, ac.user_name,
          (ad.address_id, ad.city, ad.country, ad.street, ad.street_number) as "address!: Address"
        from accounts as ac
        join address as ad using(address_id)
        where ac.account_id = 1;
    "#).fetch_one(pool).await?;

    println!("account: {:#?}", account);
    Ok(())
}

That alone could be one example that could save a tremendous amount of time for a newcomer. It shows what is possible and how to achieve it. Sprinkled with a little more explanatory text and hints to the specific places in the documentation that explains it more in detail could act as a starting point for a future guide.

Wanting to have your one to many case covered is a hole other deal. Now the documentation gets hard to understand and there are no examples. Looking through various issues ( #856, #714, #298, #552, ... etc ) only gets you more confused. So is it possible to get your data in a single query or not? All the issues that are closed have no conclusion or a definitive answer to it, they seem to just derail into details that are unintelligible by newcomers. So was issue #856 just a misplaced comma? Lets try this out

create table posts (
	post_id BIGSERIAL primary key,
	account_id BIGINT,
	title text not null,
	body text not null,
	constraint fk_account foreign KEY(account_id) references accounts(account_id)
);
#[derive(Debug)]
struct Account {
    account_id: i64,
    user_name: String,
    address: Address,
    posts: Vec<Post>,
}

#[derive(Debug, sqlx::Type)]
struct Post {
    post_id: i64,
    title: String,
    body: String,
}

async fn get_account_with_address_posts(pool: &PgPool) -> Result<(), sqlx::Error> {
    let account = sqlx::query_as!(Account, r#"
        select
          ac.account_id, ac.user_name,
          (ad.address_id, ad.city, ad.country, ad.street, ad.street_number) as "address!: Address",
          (p.post_id, p.title, p.body) as "posts!: Vec<Post>"
        from accounts as ac
        join address as ad using(address_id)
        join posts as p using(account_id)
        where ac.account_id = 1;
    "#).fetch_one(pool).await?;

    println!("account: {:#?}", account);
    Ok(())
}

Ok, that looks like it does not work. Looking at the output that this query is making it looks like that this should not work anyway. Running this query in your sql tool of choice gives you

account_id user_name address!: Address posts!: Vec
1 peter (1,city_1,country_1,street_1,1a) (1,"first post","my first post has not much text")
1 peter (1,city_1,country_1,street_1,1a) (2,"second post","my second post has more text, but not much more.")
1 peter (1,city_1,country_1,street_1,1a) (3,"third post","third one is even shorter")

This looks absolutely wrong but isn't even mentioned in issue #856 . So for this to work it looks like we have to get the posts in a single row.

We can validate that this is working to some extend we can change

#[derive(Debug)]
struct Account {
    account_id: i64,
    user_name: String,
    address: Address,
    posts: Post, // <- No Vec<Post>
}

async fn get_account_with_address_posts(pool: &PgPool) -> Result<(), sqlx::Error> {
    let account = sqlx::query_as!(Account, r#"
        select
          ac.account_id, ac.user_name,
          (ad.address_id, ad.city, ad.country, ad.street, ad.street_number) as "address!: Address",
          (p.post_id, p.title, p.body) as "posts!: Post" -- ## !! No Vec<Post> !! ##
        from accounts as ac
        join address as ad using(address_id)
        join posts as p using(account_id)
        where ac.account_id = 1;
    "#).fetch_one(pool).await?;

    println!("account: {:#?}", account);
    Ok(())
}

To get just a single Post this looks like it is working.

Changing the query to

select
  ac.account_id, ac.user_name,
  (ad.address_id, ad.city, ad.country, ad.street, ad.street_number) as "address!: Address",
  array_agg((p.post_id, p.title, p.body)) as "posts!: Vec<Post>"
from accounts as ac
join address as ad using(address_id)
join posts as p using(account_id) 
where ac.account_id = 1
group by ac.account_id, "address!: Address";

should do the trick and gives us

account_id user_name address!: Address posts!: Vec
1 peter (1,city_1,country_1,street_1,1a) {"(1,"first post","my first post has not much text")","(2,"second post","my second post has more text, but not much more.")","(3,"third post","third one is even shorter")"}

however

#[derive(Debug)]
struct Account {
    account_id: i64,
    user_name: String,
    address: Address,
    posts: Vec<Post>,
}

async fn get_account_with_address_posts(pool: &PgPool) -> Result<(), sqlx::Error> {
    let account = sqlx::query_as!(Account, r#"
        select
          ac.account_id, ac.user_name,
          (ad.address_id, ad.city, ad.country, ad.street, ad.street_number) as "address!: Address",
          array_agg((p.post_id, p.title, p.body)) as "posts!: Vec<Post>"
        from accounts as ac
        join address as ad using(address_id)
        join posts as p using(account_id)
        where ac.account_id = 1;
    "#).fetch_one(pool).await?;

    println!("account: {:#?}", account);
    Ok(())
}

Is not getting us anywhere.

error[E0277]: the trait bound `Vec<Post>: Type<Postgres>` is not satisfied
  --> src/main.rs:86:19
   |
86 |       let account = sqlx::query_as!(Account, r#"
   |  ___________________^
87 | |         select
88 | |           ac.account_id, ac.user_name,
89 | |           (ad.address_id, ad.city, ad.country, ad.street, ad.street_number) as "address!: Address",
...  |
94 | |         where ac.account_id = 1;
95 | |     "#).fetch_one(pool).await?;
   | |_______^ the trait `Type<Postgres>` is not implemented for `Vec<Post>`
   |
   = help: the following implementations were found:
             <Vec<&[u8]> as Type<Postgres>>
             <Vec<&str> as Type<Postgres>>
             <Vec<(T1, T2)> as Type<Postgres>>
             <Vec<(T1, T2, T3)> as Type<Postgres>>
           and 22 others
   = note: required because of the requirements on the impl of `sqlx::Decode<'_, Postgres>` for `Vec<Post>`
   = note: this error originates in a macro (in Nightly builds, run with -Z macro-backtrace for more info)

error: aborting due to previous error

And i don't really understand what the error message is trying to say to me. After digging a little bit further i found this issue #349 where i also don't understand if this is related or not and what the conclusion here is.

At this point i am into my third weekend playing around with sqlx and i don't even know how to use it for a simple one to many use case. This is very frustrating as stated before. sqlx might have many cool features but i just can't get to know them. What is the "idiomatic" way to do such a simple task in sqlx? Am i supposed to do it with multiple different queries as mentioned in this issue #552 ? Is what i was trying to do in the first place even possible with sqlx and i am just not able to express it the right way or is it a limitation/boundary that sqlx has due to the way it is working (which i don't know as a beginner). I suspect issue #298 to be the current roadblocker but i just don't know.

Having a variety of "simple" examples that show how to deal with them in sqlx could save a huge amount of time and frustration for people that just "wanted to take a look" at the project and it could make on boarding significantly easier as the only real way is to search the issues which is often not really helpful. Examples could show current limitations like

this is how you need to make it currently due to issue xyz – we seek to have a solution that would look like this but currently not available.

And the discord channel is not the right tool to search for answers. I can imagine that this sort of questions are asked many times before and is frustrating to answer.

I hope this gets a little insight on my process and experience. Love the project! ❤️

@mehcode
Copy link
Member

mehcode commented Jan 24, 2021

That is all completely fair. I agree that we need to make this a priority. I think a potentially good solution here is to take a public SQL dataset, and setup several guided examples using that dataset.

  • Connect (explain pools)
  • Select many rows from 1 table
  • Select one row
  • Count rows from a table
  • Select many rows from 2 tables with a 1:1 relationship with 2 queries
  • Select many rows from 2 tables with a 1:N relationship with 2 queries
  • Insert one row (and getting a generated primary key)
  • Insert many rows
  • Update one to many rows (and getting number or rows updated)
  • Delete one to many rows (and getting number or rows deleted)
  • Acquire/release a database-level mutex (very helpful when you want to do something exclusively in 1 node in a typical multi-node setup under a load balancer)

Postgres


We can plan to get a mdbook or similar setup with a lot of this and then iterate on it. Is there anything large I'm missing from the above?

@pythoneer
Copy link
Author

This looks like a very helpful list of examples. I don't know if its better suited for a "tips and tricks" section but i often like to use some kind of upsert INSERT ON CONFLICT but this may be to specific to my usual use cases and is not applicable to a wide variety of people and could be easily derived from the current list of examples as it is more or less just another query case we have already covered.

A Transactions-Example could be useful? Maybe one that recovers from a 40001 by repeating the tx ... may be to specific again.

Do you plan to have this as examples and a corresponding mdbook (guide)?

@mehcode
Copy link
Member

mehcode commented Jan 24, 2021

Do you plan to have this as examples and a corresponding mdbook (guide)?

Maybe a first step would be just examples. Trying to reign myself in so this gets done.

# guide for mysql
# activate SQLx with async-std and mysql, with explicit bin paths to avoid the src/bin/x path
examples/guide/mysql/Cargo.toml 
examples/guide/mysql/connect.rs
examples/guide/mysql/select_many.rs
examples/guide/mysql/select_one.rs
examples/guide/mysql/count.rs
examples/guide/mysql/select_many_1_to_1.rs
examples/guide/mysql/select_many_1_to_n.rs
# ...

# quickstart for mysql with tokio
examples/quickstart/mysql+tokio/Cargo.toml
examples/quickstart/mysql+tokio/src/main.rs

# quickstart for mysql with blocking IO
examples/quickstart/mysql+blocking/Cargo.toml
examples/quickstart/mysql+blocking/src/main.rs

I only show mysql above but the idea is we would have guide/postgres, guide/sqlite, etc.

I'm thinking that the larger examples should probably move to another repo like sqlx-rs/examples.


A Transactions-Example could be useful?

Definitely. At least something like "Start a transaction, insert into two different tables and then commit it".

Maybe one that recovers from a 40001 by repeating the tx

It might be nice to do this automatically now that we have a working .transaction function that takes a closure. Simply re-invoke the closure on 40001.

@rich-murphey
Copy link
Contributor

I'm interested in helping with this.

As a recent newcomer, I wished there were introductory on-boarding information, as a supplement to just one example to help folks get from zero familiarity to having one running example for one database.

@rich-murphey
Copy link
Contributor

Hey, I might help with sqlite examples. The idea of showing features and possibilities through examples is a very good point.

@asnimansari
Copy link

Would like to contribute to more examples

@pauldorehill
Copy link

pauldorehill commented Jan 30, 2021

Hi - this library is great! 😄 I've been using it for a project and ran into some similar issues as described here when you start to get into table joins with 1:Many etc. and/or using the ARRAY_AGG for returning Vec<T>; or structs with Vec<T>. #298 seems to cover this.

My current work in progress is to simply define a database specific type and then flatten the rows into my final type: since I've many types to do this with I made a trait FromDBFlatten (that gist has an example with joins). It then gives me a nice usage:

let _: Option<ReturnType> = sqlx::query_as!(DBType, r#"...SOME SQL..."#)
    .fetch_all(&pool)
    .await
    .map(FromDBFlatten::flatten_one)?;

let _: Vec<ReturnType> = sqlx::query_as!(DBType, r#"...SOME SQL..."#)
    .fetch_all(&pool)
    .await
    .map(FromDBFlatten::flatten)?;

If anyone is looking for how to run multiple queries in one transaction (I couldn't find anything), I think this is the correct way:

let pool = PgPool::connect("DATABASE_URL").unwrap()).await?;
let mut conn = pool.acquire().await?;
let mut tx = conn.begin().await?;

let _: ReturnType = sqlx::query_as!(DBType, r#"...SOME SQL..."#)
    .fetch_one(&mut tx)
    .await?;

let _: Vec<ReturnType> = sqlx::query_as!(DBType, r#"...SOME SQL..."#)
    .fetch_all(&mut tx)
    .await?;

tx.commit().await?;

@mehcode
Copy link
Member

mehcode commented Jan 30, 2021

Love the enthusiasm everyone. I will commit to getting this started over the next couple days (in the next branch) and then would love additional help filling in.


@pauldorehill Very nice! Coincidentally (and coming from a lot of the 1:M requests) we're planning on adding something like:

// impl Executor
fn fetch_group_map_by<T, F>(self, f: F) -> HashMap<T, Vec<O>>
where
  T: Decode<DB>,
  F: Fn(&O) -> T

Which would allow something like:

/*: Vec<User> */
let mut users = query!(" ... ")
  .map(|row| User {
    id: row.id,
    name: row.name,
    products: Vec::new(),
    // [...]
  })
  .fetch_all(&mut conn).await?;

let user_ids: Vec<_> = users.iter().map(|user| user.id).collect();

/*: HashMap<Uuid, Vec<Product>> */ 
let mut products = query_as!(Product, " ... WHERE user_id = any($1)", user_ids)
  .fetch_group_map_by(&mut conn, |product| product.user_id).await?;

for user in &mut users {
  users.products = products.remove(user.id);
}

A large improvement to this pattern would be to query and ignore some fields. This would remove the need for a .map or two User types.

Perhaps something like:

query_as!(User, "SELECT u.id, u.name, ...", skip: ["products"])

@pauldorehill
Copy link

@mehcode that is an nice way of doing it too: I like domain transfer objects as way to over come the impedance miss match at boundaries. One other slightly cryptic error I've come across is assertion failed: self.remaining() >= dst.len(): there is no compile time error but it comes at runtime. From what I've worked out its when your parent struct contains a child struct that doesn't have/match all the fields in the db table in something like:

CREATE TABLE public.giant (
    id integer NOT NULL,
    name text NOT NULL
);
CREATE TABLE public.meal (
   id integer NOT NULL,
   name text NOT NULL
);
struct GiantDB {
    id: i32,
    name: String,
    meal: Meal,
}

#[derive(sqlx::Type, Debug)]
struct Meal {
    // id: i32, // If this field is not here, get self.remaining() >= dst.len() at runtime
    name: String,
}

I'm not sure if I should open an issue, or if its a know limitation, but there isn't the same level of compile checking for child structs? You get a runtime error along the lines of error occurred while decoding column 1: mismatched types if you don't get the ordering of the SQL tuple to match the ordering of the struct fields e.g.

SELECT giant.id AS id, giant.name AS name, (meal.name, meal.id) AS "meal!: Meal" compiles, but runtime errors since name is before id

Or a no field `0` found on record if you were to write SELECT giant.id AS id, giant.name AS name, meal.id AS "meal!: Meal"

@pythoneer
Copy link
Author

pythoneer commented Jan 30, 2021

I think this issue is getting filled with great ideas all based around the topic of "idiomatic usage of sqlx" and how to improve the current state. Do we need to branch out some new issues for these?

  • .transaction() that can retry on 40001 (should this be configurable? usable for other generic cases?)
  • fetch_group_map_by
  • query_as - skip i really like this one. it would eliminate my AccountNoPost struct if you really don't want to use .map. Do we have to wrap those skip{ed, able} fields in option (that might interfere with other usages) or do we need those fields to derive Default?

@camsjams
Copy link

I made a presentation for Rust Lang Los Angeles which uses SQLx, actix and async-graphql, it showcases UUIDs and datetime fields which I found missing from the documentation:
https://github.com/camsjams/rust-actix-graphql-sqlx-postgresql

@shanesveller
Copy link

Is there any new information, features or references for one-to-many or many-to-many relationships with query_as! since the last activity here? I'm interested in a seemingly straightforward case where one struct has a member which is a Vec of another struct, for example. I've seen snippets around array_agg and type hinting within the SQL, but I'm not able to successfully compile to deserialize the result so far.

@longfellowone
Copy link

Is there any new information, features or references for one-to-many or many-to-many relationships with query_as! since the last activity here? I'm interested in a seemingly straightforward case where one struct has a member which is a Vec of another struct, for example. I've seen snippets around array_agg and type hinting within the SQL, but I'm not able to successfully compile to deserialize the result so far.

Where you able to find any simple examples using array_agg?

@FabienD
Copy link

FabienD commented May 20, 2022

Hello,

Yes, It'll be very interesting to have few examples of how to deal with relations between models. I use this library for my first "side-project" and It's difficult to find more complex example than a simple "todo list" :-)

In my example, I have 2 models, Tracking and TrackingLink. Tracking can have few TrackingLink (cf. links: Vec).

#[derive(Debug, Serialize, FromRow)]
pub struct Tracking {
    product_id: Uuid,
    product_name: String,
    links: Vec<TrackingLink>
}

#[derive(Debug, Serialize, sqlx::Type, FromRow)]
pub struct TrackingLink {
    merchant_product_url: String,
    merchant: String,
    is_in_stock: bool,
    #[serde(with = "ts_seconds")]
    tracked_at: DateTime<Utc>,
}

Bellow the SQL part, with the use of the macro sqlx::query_as! with the use of postgresql array_agg function.

impl Tracking {
    pub async fn get_last(pool: &PgPool) -> Result<Vec<Tracking>> {       
        
        let products = sqlx::query_as!(
            Tracking,
            r#"WITH last_tracking AS (
                SELECT 
                    DISTINCT ON (t.merchant_product_id) t.merchant_product_id, 
                    t.is_in_stock, 
                    t.tracked_at
                FROM instock.tracking AS t
                ORDER BY t.merchant_product_id, t.tracked_at DESC
            ), tracked_products AS (
                SELECT
                    p.id as product_id,
                    p.name as product_name,
                    m.name as merchant,
                    mp.url as product_merchant_url,
                    lt.is_in_stock, 
                    lt.tracked_at
                FROM last_tracking AS lt
                    JOIN instock.merchant_product AS mp ON mp.id = lt.merchant_product_id
                    JOIN instock.product AS p ON p.id = mp.product_id
                    JOIN instock.merchant AS m ON m.id = mp.merchant_id
            )
            SELECT 
                tp.product_id,
                tp.product_name,
                array_agg((
                    tp.product_merchant_url,
                    tp.merchant,
                    tp.is_in_stock,
                    tp.tracked_at
                )) as "links!: Vec<TrackingLink>"
            FROM tracked_products AS tp 
            GROUP BY tp.product_id, tp.product_name
            "#
        )
        .fetch_all(pool)
        .await?;

        Ok(products)
    }
}

This first example works.

After that, I wanted to add a filter to this SQL, and use a "non-macro" form of query_as :

impl Tracking {
    pub async fn get_last(pool: &PgPool) -> Result<Vec<Tracking>> {       
        // Just for the example
        let mut sql_filter = "WHERE t.is_in_stock IS TRUE";
        // Format the SQL string        
        let sql = format!(r#"WITH last_tracking AS (
                SELECT 
                    DISTINCT ON (t.merchant_product_id) t.merchant_product_id, 
                    t.is_in_stock, 
                    t.tracked_at
                FROM instock.tracking AS t
                {sql_filter}
                ORDER BY t.merchant_product_id, t.tracked_at DESC
            ), tracked_products AS (
                SELECT
                    p.id as product_id,
                    p.name as product_name,
                    m.name as merchant,
                    mp.url as product_merchant_url,
                    lt.is_in_stock, 
                    lt.tracked_at
                FROM last_tracking AS lt
                    JOIN instock.merchant_product AS mp ON mp.id = lt.merchant_product_id
                    JOIN instock.product AS p ON p.id = mp.product_id
                    JOIN instock.merchant AS m ON m.id = mp.merchant_id
            )
            SELECT 
                tp.product_id,
                tp.product_name,
                array_agg((
                    tp.product_merchant_url,
                    tp.merchant,
                    tp.is_in_stock,
                    tp.tracked_at
                )) as "links!: Vec<TrackingLink>"
            FROM tracked_products AS tp 
            GROUP BY tp.product_id, tp.product_name
            "#
        // 
        let products = sqlx::query_as::<_, Tracking(
            &sql
        )
        .fetch_all(pool)
        .await?;

        Ok(products)
    }
}

It produces this error :

the trait bound `TrackingLink: PgHasArrayType` is not satisfied
required because of the requirements on the impl of `Type<Postgres>` for `Vec<TrackingLink>`

I don't understand why the first example work and the second one not.

Fabien.

@mattoni
Copy link

mattoni commented Jul 1, 2022

An important item to note from my own experiments:

Using array_agg() the listed fields in the parenthesis MUST be listed in the exact same order as the fields of your struct, otherwise it will either fail to decode at runtime, or the fields will have the incorrect values.

THIS IS NOT CAUGHT AT COMPILE TIME

If your fields are out of order, you would get a runtime error something like this:

Err(error occurred while decoding column 17: mismatched types; Rust type `core::option::Option<alloc::string::String>` (as SQL type `TEXT`) is not compatible with SQL type `NUMERIC`

I wonder if there is a way to catch this in the macro to at least prevent accidental runtime bugs.

@abonander
Copy link
Collaborator

That's unlikely to be something we can typecheck at compile time without performing our own analysis of the query.

@mattoni
Copy link

mattoni commented Jul 1, 2022

Ah, thanks @abonander. It looked like there was another interesting proposal to do a fetch_group_map_by, but I don't see anything in the PRs for that work. Is it currently being tackled by someone/on the roadmap still as far as you're aware?

@seguidor777
Copy link

Can anyone please let me know if the nested queries are possible by using the query_as function (not the macro). All I have found are examples using the query_as! macro

@jb-alvarado
Copy link

jb-alvarado commented Nov 16, 2022

Can anyone please let me know if the nested queries are possible by using the query_as function (not the macro). All I have found are examples using the query_as! macro

The exact same question I was asking my self to. Yesterday I struggle some hours with the query_as function, and now I found out, that with the macro it works.

It would be very useful to have this feature to, in the query_as function. At the moment is not possible to build a dynamic nested query.

@jb-alvarado
Copy link

Just for others when they end up here, and like me and @seguidor777 don't know how to manage complex structures with query_as function:

There is everything in the documentation, I just did not found it first. Lets say you have this tables:

#[derive(Clone, Debug)]
pub struct MediaFile {
    pub id: i32,
    pub name: String,
    pub media_language: Lang,
    pub media_speaker: Vec<Speaker>,
}

#[derive(Clone, Debug, Default)]
pub struct Lang {
    pub id: i32,
    pub name: String,
}

#[derive(Clone, Debug, Default)]
pub struct Speaker {
    pub id: i32,
    pub name: String,
}

For MediaFile you can create a custom FromRow trait:

impl FromRow<'_, PgRow> for MediaFile {
    fn from_row(row: &PgRow) -> sqlx::Result<Self> {
        let lang = Lang {
            id: row.get::<(i32, String), &str>("language").0,
            name: row.get::<(i32, String), &str>("language").1,
        };

        let mut speaker = vec![];

        for s in row
            .get::<Vec<Option<(i32, String)>>, &str>("speaker")
            .into_iter()
            .flatten()
        {
            speaker.push(Speaker { id: s.0, name: s.1 })
        }

        Ok(Self {
            id: row.get("id"),
            name: row.get("name"),
            media_language: lang,
            media_speaker: speaker,
        })
    }
}

Then you can query the table with:

let ordering = "id ASC";
let query = format!(r#"SELECT mf.*,
        (ml.id, ml."name") AS "language",
        array_agg((case when ms.id > 0 then (ms.id, ms."name") end)) AS "speaker"
    FROM media_files mf
    INNER JOIN media_languages ml ON ml.id = mf.lang_id
    LEFT JOIN media_file_speakers mfs ON mfs.media_file_id = mf.id
    LEFT JOIN media_speakers ms ON ms.id = mfs.media_speaker_id
    GROUP BY mf.id, ml.id
    ORDER BY {}
    "#, ordering);

let data: Vec<MediaFile> = sqlx::query_as(&query).fetch_all(conn).await?;

In this example speaker is optional, that is why I use case when ms.id > 0 ....

@frederikhors
Copy link

frederikhors commented Jan 11, 2023

Is there any new information, features or references for one-to-many or many-to-many relationships with query_as! since the last activity here? I'm interested in a seemingly straightforward case where one struct has a member which is a Vec of another struct, for example. I've seen snippets around array_agg and type hinting within the SQL, but I'm not able to successfully compile to deserialize the result so far.

Did you find a way? @shanesveller

rtyler added a commit to rtyler/synchronik that referenced this issue Jan 30, 2023
Things I've learned today:

* The [sqlx
  documentation](https://docs.rs/sqlx/0.6.2/sqlx/sqlite/types/index.html#uuid)
  is *lying* about its `uuid` support. Basically `query_as!` does not
  ser/deserialize `Uuid` properly in/out of Sqlite with `TEXT` _or_ `BLOB`
* There are [no useful
  examples](launchbadge/sqlx#1014) of doing nested
  struct queries in sqlx at the moment
@renato145
Copy link

I was just needing to do a simple 1:many query and ended up using "array_agg" in the query and filtering empty values, then, I need to replace nulls with empty arrays:

#[derive(Debug, Clone, sqlx::Type)]
pub struct WorkplaceSchedule {
    pub id: Uuid,
    pub start: NaiveTime,
    pub finish: NaiveTime,
    pub n_positions: i32,
}

#[derive(Debug, Clone)]
pub struct WorkplaceSchedules {
    pub id: Uuid,
    pub name: String,
    pub schedules: Vec<WorkplaceSchedule>,
}

let res = sqlx::query_as!(
        WorkplaceSchedules,
        r#"
        SELECT
            w.id, w.name,
            COALESCE(
                array_agg((s.id, s."start", s.finish, ws.n_positions)) FILTER (WHERE s.id IS NOT NULL),
                '{}'
            ) AS "schedules!: Vec<WorkplaceSchedule>"
        FROM workplaces w
        LEFT JOIN workplace_schedules ws 
            ON w.id = ws.workplace_id 
        LEFT JOIN schedules s
            ON ws.schedule_id = s.id
        GROUP BY w.id
        "#
    )
    .fetch_all(&pool)
    .await
    .expect("Failed to fetch query.");

@frantisek-heca
Copy link

frantisek-heca commented Mar 19, 2024

@jb-alvarado
I wonder where exactly have you found documentation you mentioned in your last post? I haven't found this exact type of problem solving anywhere yet. All I see are many examples of this type (column1, column2) as "media_language!: Lang" in the documentation. Which implies various derives of Type or FromRow magics (from a newcomer point of view) + confusion about usage of Option<> vs Type derive does not allow Option fields.. and so on.
Just wondering about your statement that it is somehow clear in the docs.

@jb-alvarado
Copy link

@frantisek-heca there is a section about manuell implementation it not give a more advanced example, but is a starting point. Here in the issues you found also some examples and explanations, also about the issue:

Option<> vs Type derive does not allow Option fields

I don't know if this problem still exists, as I remember was not an issue by sqlx itself. I implemented my own type for the problem, here an example:

impl<'r> ::sqlx::decode::Decode<'r, ::sqlx::Postgres> for MediaSeries {
    fn decode(
        value: ::sqlx::postgres::PgValueRef<'r>,
    ) -> ::std::result::Result<
        Self,
        ::std::boxed::Box<
            dyn ::std::error::Error + 'static + ::std::marker::Send + ::std::marker::Sync,
        >,
    > {
        let mut decoder = ::sqlx::postgres::types::PgRecordDecoder::new(value)?;
        let id = decoder.try_decode::<i32>()?;
        let name = decoder.try_decode::<String>()?;
        let trailer_id = decoder.try_decode::<i32>()?;
        let screening_pause = decoder.try_decode::<bool>()?;
        let description = decoder.try_decode::<Option<String>>()?;
        ::std::result::Result::Ok(MediaSeries {
            id,
            name,
            trailer_id,
            screening_pause,
            description,
        })
    }
}

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