-
Notifications
You must be signed in to change notification settings - Fork 49
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
Different set of fields to update and insert for Upsert method. #137
Comments
Well............ to be able to do this, we have to first look at what the SQL will look like INSERT INTO products (name, sku, created_at)
VALUES ('name', 'sku', '2020-01-02')
VALUES ('name', 'sku', '2020-01-02')
ON CONFLICT ('sku') DO UPDATE SET updated_at = '2020-01-03' The reason why this isn't easy to do with Bob, is that the methods are designed to be able to do bulk operations. In a bulk operation, we will not be able to set There are a few options. 1. Use the DB to handle timestampsFirst, I would recommend adding Next, I would recommend using triggers for created/updated timestamps. This is what I do, and this is also why Bob does not auto-handle timestamps. I think it is much more robust to do this in the DB. CREATE FUNCTION set_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ LANGUAGE 'plpgsql';
-- Then for each table
CREATE TRIGGER set_updated_at
BEFORE INSERT OR UPDATE ON public.products FOR EACH ROW
EXECUTE PROCEDURE set_updated_at_column();
-- Note that this is INSERT OR UPDATE
-- if you do not want updated_at present on insert, use only BEFORE UPDATE With this setup, you never have to concern yourself with setting timestamps in your code. 2. Build the upsert query by handIf you would prefer to handle timestamps in code, you can handle this case by building the upsert query manually: cols := models.ColumnNames.Products
models.Products.InsertQ(
ctx, db,
im.OnConflict(cols.Products.SKU).DoUpdate().
Set(cols.UpdatedAt, psql.Arg(time.Now())).
SetExcluded(cols.Name),
&models.ProductSetter{
Name: omit.From(model.Name),
SKU: omit.From(model.SKU),
CreatedAt: omit.From(time.Now()),
}.Insert(),
// Add other setters
) |
Oh, thanks!
I think that my example was too specific. Now, i researching for ability to migrate from sqlboiler to bob, because it more flexible and more thoughtful. I think, that the second approach is quite suitable for solving my problem. I need to think about generics and own helper for this situation. Anyway, thank you for your comments and thank you for your great work. |
Thank you |
Unfortunately, I couldn’t implement the functionality I needed using InsertQ. The fact is that the library does not have a method for the DoUpdate() expression, which would take a setter structure as input. Instead of the solution you described from point 2, I think it would be useful to have the following option: cols := models.ColumnNames.Products
models.Products.InsertQ(
ctx, db,
im.OnConflict(cols.Products.SKU).DoUpdate().
SetMany(&models.ProductSetter{
Name: omit.From(model.Name),
UpdatedAt: omit.From(time.Now()),
}).
&models.ProductSetter{
Name: omit.From(model.Name),
SKU: omit.From(model.SKU),
}.Insert(),
// Add other setters
) I tried to implement this functionality in the library, I wanted to prepare a PR, but I just got lost in generics and don’t understand what I’m doing wrong. Perhaps you can suggest a solution? I'll try to show parts from the code with changes, they are small. Type-param added for *dialect.UpdateQuery in file https://github.com/stephenafamo/bob/blob/main/dialect/psql/im/qm.go#L65 // The column to target. Will auto add brackets
func OnConflict(columns ...any) mods.Conflict[*dialect.InsertQuery, *dialect.UpdateQuery] {
return mods.Conflict[*dialect.InsertQuery, *dialect.UpdateQuery](func() clause.Conflict {
return clause.Conflict{
Target: clause.ConflictTarget{
Columns: columns,
},
}
})
}
func OnConflictOnConstraint(constraint string) mods.Conflict[*dialect.InsertQuery, *dialect.UpdateQuery] {
return mods.Conflict[*dialect.InsertQuery, *dialect.UpdateQuery](func() clause.Conflict {
return clause.Conflict{
Target: clause.ConflictTarget{
Constraint: constraint,
},
}
})
} Added type-param for setter, as well as the method itself. https://github.com/stephenafamo/bob/blob/main/mods/conflict.go#L9 type Conflict[
Q interface{ SetConflict(clause.Conflict) },
U interface{ AppendSet(exprs ...any) },
] func() clause.Conflict
.....
func (c Conflict[Q, U]) SetMany(setter interface{ Apply(U) }) Conflict[Q, U] {
conflict := c()
setter.Apply(&conflict.Set) // PROBLEM IS HERE
return Conflict[Q, U](func() clause.Conflict {
return conflict
})
} setter.Apply(&conflict.Set) <-- problem is here. Message from compiler After all, U is an interface with the AppendSet method and the conflict.Set structure contains this method. I have no ideas what's wrong :( |
I can understand the issue, and the mental model you should keep in mind is that the query builder is mostly separate from the code generation. With this in mind, what you can do is implement an func OnProductConflict() bob.Mod[*dialect.InsertQuery] {
cols := models.ColumnNames.Products
// Columns with static values
static := map[string]any{
cols.UpdatedAt: time.Now(),
}
// Columns that use the inserted value
useInserted := []string{cols.CreatedAt}
set := []any{}
for col, val := range static {
set = append(set, psql.Quote(col).EQ(val))
}
for _, col := range useInserted {
set = append(set, psql.Quote(col).EQ(psql.Raw(fmt.Sprintf("EXCLUDED.%s", expr.Quote(col)))))
}
return mods.Conflict[*dialect.InsertQuery](func() clause.Conflict {
return clause.Conflict{
Do: "UPDATE",
Target: clause.ConflictTarget{
Columns: []any{cols.Products.SKU},
},
Set: clause.Set{Set: set},
}
})
} Then you can use this in your models.Products.InsertQ(
ctx, db,
OnProductConflict(), // HERE
&models.ProductSetter{
Name: omit.From(model.Name),
SKU: omit.From(model.SKU),
CreatedAt: omit.From(time.Now()),
}.Insert(),
// Add other setters
) So, once the mod system is understood, you can play around with it and create all sorts of custom mods. This is exactly how You can look at the generated code and see how it looks. |
Wow, exactly! Thank you very much! Now I understand that I chose the wrong way. Your example is useful, but i think, that it very boilerplate. Why? So, in generated code the Insert() method for setters is confusing me. I suggest adding method in file https://github.com/stephenafamo/bob/blob/main/mods/conflict.go: func (c Conflict[Q]) SetMany(exprs ...bob.Expression) Conflict[Q] {
conflict := c()
for _, e := range exprs {
conflict.Set.Set = append(conflict.Set.Set, e)
}
return Conflict[Q](func() clause.Conflict {
return conflict
})
}
// OR/AND method
func (c Conflict[Q]) SetFromClause(cl clause.Set) Conflict[Q] {
conflict := c()
conflict.Set.Set = append(conflict.Set.Set, cl.Set...)
return Conflict[Q](func() clause.Conflict {
return conflict
})
} And in templates for generation i suggest to add something like this (based on my example): func (s ProductSetter) SetClause() clause.Set {
cs := clause.Set{}
if !s.ID.IsUnset() {
cs.AppendSet(expr.OP("=", psql.Quote("id"), psql.Arg(s.ID)))
}
if !s.Name.IsUnset() {
cs.AppendSet(expr.OP("=", psql.Quote("name"), psql.Arg(s.Name)))
}
if !s.SKU.IsUnset() {
cs.AppendSet(expr.OP("=", psql.Quote("sku"), psql.Arg(s.SKU)))
}
if !s.CreatedAt.IsUnset() {
cs.AppendSet(expr.OP("=", psql.Quote("created_at"), psql.Arg(s.CreatedAt)))
}
if !s.UpdatedAt.IsUnset() {
cs.AppendSet(expr.OP("=", psql.Quote("updated_at"), psql.Arg(s.UpdatedAt)))
}
return cs
}
// OR/AND method
func (s ProductSetter) Sets() []bob.Expression {
cs := []bob.Expression{}
if !s.ID.IsUnset() {
cs = append(cs, expr.OP("=", psql.Quote("id"), psql.Arg(s.ID)))
}
if !s.Name.IsUnset() {
cs = append(cs, expr.OP("=", psql.Quote("name"), psql.Arg(s.Name)))
}
if !s.SKU.IsUnset() {
cs = append(cs, expr.OP("=", psql.Quote("sku"), psql.Arg(s.SKU)))
}
if !s.CreatedAt.IsUnset() {
cs = append(cs, expr.OP("=", psql.Quote("created_at"), psql.Arg(s.CreatedAt)))
}
if !s.UpdatedAt.IsUnset() {
cs = append(cs, expr.OP("=", psql.Quote("updated_at"), psql.Arg(s.UpdatedAt)))
}
return cs
} As a result it then can be used like this in code: bmodels.Product.InsertQ(
ctx, bob.DB{},
im.OnConflict(cols.Products.SKU)
DoUpdate().
SetFromClause(bmodels.ProductSetter{
Name: omit.From(model.Name),
UpdatedAt: omit.From(model.UpdatedAt),
}.SetClause()),
bmodels.ProductSetter{
Name: omit.From(model.Name),
SKU: omit.From(model.SKU),
}.Insert(),
) AND/OR bmodels.Product.InsertQ(
ctx, bob.DB{},
im.OnConflict(cols.Products.SKU)
DoUpdate().
SetMany(bmodels.ProductSetter{
Name: omit.From(model.Name),
UpdatedAt: omit.From(model.UpdatedAt),
}.Sets()...),
bmodels.ProductSetter{
Name: omit.From(model.Name),
SKU: omit.From(model.SKU),
}.Insert(),
) What do think about it? As variant, there it will be usefull to extend standard templates via configuration, as it made in sqlboiler. |
Your suggestion makes a lot of sense!!!! I am leaning more towards using
It is already possible, but unfortunately it is not well documented yet. You would need to write a bit of code yourself. As a matter of fact all the generators are written in the same way. Take a look at |
Yes, now I think that bob.Expression is really a better choice.
Hmm, yes, thanks, this really solution. |
Thank you. I will likely add this soon, right now I'm doing a big refactor to fix some issues with multi-sided user-defined relationships. Once that is done I will likely implement this. |
Your concerns should be addressed by #140, #141 and #142 To make this easier to compose, You should be able to do this now: bmodels.Product.InsertQ(
ctx, bob.DB{},
im.OnConflict(cols.Products.SKU).DoUpdate(
im.Set(bmodels.ProductSetter{
Name: omit.From(model.Name),
UpdatedAt: omit.From(model.UpdatedAt),
}.Expressions()...),
),
bmodels.ProductSetter{
Name: omit.From(model.Name),
SKU: omit.From(model.SKU),
}.InsertMod(),
) |
Hello from sqlboiler :)
In generated code i want to use "Upsert" method, but i want insert one set of fields, but update on conflict different set.
Concrete example:
After code generation
I don't want insert any value in "updated_at" columns while creation, but i want to update it value when updating in conflict.
How can i achieve this in bob?
In sqlboiler for example i simply deal with Whitelist/Blacklist.
This is concrete example, but I'm sure there may be situations when i want insert one field set, but on conflict update completely different fields set.
The text was updated successfully, but these errors were encountered: