# SQLBoiler [![License](https://img.shields.io/badge/license-BSD-blue.svg)](https://github.com/vattle/sqlboiler/blob/master/LICENSE) [![GoDoc](https://godoc.org/github.com/vattle/sqlboiler?status.svg)](https://godoc.org/github.com/vattle/sqlboiler) [![CircleCI](https://circleci.com/gh/vattle/sqlboiler.svg?style=shield)](https://circleci.com/gh/vattle/sqlboiler) [![Go Report Card](https://goreportcard.com/badge/vattle/sqlboiler)](http://goreportcard.com/report/vattle/sqlboiler) SQLBoiler is a tool to generate a Go data model tailored to your database schema. It is a "database-first" ORM as opposed to "code-first" (like gorm/gorp). That means you must first create your database schema. Please use something like goose or some other migration tool to manage this part of the database's lifecycle. ## Why another ORM Well... ## About SQL Boiler ### Features - Full model generation - High performance through generation - Extremely fast code generation - Uses boil.Executor (simple interface, sql.DB, sqlx.DB etc. compatible) - Easy workflow (models can always be regenerated, full auto-complete) - Strongly typed querying (usually no converting or binding to pointers) - Hooks (Before/After Create/Select/Update/Delete/Upsert) - Automatic CreatedAt/UpdatedAt - Relationships/Associations - Eager loading (recursive) - Transactions - Raw SQL fallbacks - Compatibility tests (Run against your own DB schema) - Debug logging ### Supported Databases - PostgreSQL *Note: Seeking contributors for other database engines.* ### A Small Taste For a comprehensive list of available operations and examples please see [Features & Examples](#features--examples). ```go import ( // Import this so we don't have to use qm.Limit etc. . "github.com/vattle/sqlboiler/boil/qm" ) // Open handle to database like normal db, err := sql.Open("postgres", "dbname=fun user=abc") if err != nil { return err } // Query all users users, err := models.Users(db).All() // Panic-able if you like to code that way users := models.Users(db).AllP() // More complex query users, err := models.Users(db, Where("age > ?", 30), Limit(5), Offset(6)).All() // Ultra complex query users, err := models.Users(db, Select("id", "name"), InnerJoin("credit_cards c on c.user_id = users.id"), Where("age > ?", 30), AndIn("c.kind in ?", "visa", "mastercard"), Or("email like ?", "%aol.com%"), GroupBy("id", "name"), Having("count(c.id) > ?", 2), Limit(5), Offset(6), ).All() // Use any "boil.Executor" implementation (*sql.DB, *sql.Tx, data-dog mock db) // for any query. tx, err := db.Begin() if err != nil { return err } users, err := models.Users(tx).All() // Relationships user, err := models.Users(db).One() if err != nil { return err } movies, err := user.FavoriteMovies(db).All() // Eager loading users, err := models.Users(db, Load("FavoriteMovies")).All() if err != nil { return err } fmt.Println(len(users.R.FavoriteMovies)) ``` ## Requirements & Pro Tips ### Requirements * Table names and column names should use `snake_case` format. * At the moment we require `snake_case` table names and column names. This is a recommended default in Postgres. We can reassess this for future database drivers. * Join tables should use a *composite primary key*. * For join tables to be used transparently for relationships your join table must have a *composite primary key* that encompasses both foreign table foreign keys. For example, on a join table named `user_videos` you should have: `primary key(user_id, video_id)`, with both `user_id` and `video_id` being foreign key columns to the users and videos tables respectively. ### Pro Tips * Foreign key column names should end with `_id`. * Foreign key column names in the format `x_id` will generate clearer method names. It is advisable to use this naming convention whenever it makes sense for your database schema. * If you never plan on using the hooks functionality you can disable generation of this feature using the `--no-hooks` flag. This will save you some binary size. ## Getting started #### Download ```shell go get -u -t github.com/vattle/sqlboiler ``` #### Configuration Create a configuration file. Because the project uses [viper](github.com/spf13/viper), TOML, JSON and YAML are all supported. Environment variables are also able to be used. We will assume TOML for the rest of the documentation. The configuration file should be named `sqlboiler.toml` and is searched for in the following directories in this order: - `./` - `$XDG_CONFIG_HOME/sqlboiler/` - `$HOME/.config/sqlboiler/` We require you pass in the `postgres` configuration via the configuration file rather than env vars. There is no command line argument support for database configuration. Values given under the `postgres` block are passed directly to the [pq](github.com/lib/pq) driver. Here is a rundown of all the different values that can go in that section: | Name | Required | Default | | --- | --- | --- | | dbname | yes | none | | host | yes | none | | port | no | 5432 | | user | yes | none | | pass | no | none | | sslmode | no | "require" | You can also pass in these top level configuration values if you would prefer not to pass them through the command line or environment variables: | Name | Default | | --- | --- | | basedir | none | | pkgname | "models" | | output | "models" | | exclude | [ ] | | debug | false | | no-hooks | false | | no-auto-timestamps | false | Example: ```toml [postgres] dbname="dbname" host="localhost" port=5432 user="dbusername" pass="dbpassword" ``` #### Initial Generation After creating a configuration file that points at the database we want to generate models for, we can invoke the sqlboiler command line utility. ```text SQL Boiler generates a Go ORM from template files, tailored to your database schema. Complete documentation is available at http://github.com/vattle/sqlboiler Usage: sqlboiler [flags] Examples: sqlboiler postgres Flags: -b, --basedir string The base directory templates and templates_test folders are -d, --debug Debug mode prints stack traces on error -x, --exclude stringSlice Tables to be excluded from the generated package (default []) --no-auto-timestamps Disable automatic timestamps for created_at/updated_at --no-hooks Disable hooks feature for your models -o, --output string The name of the folder to output to (default "models") -p, --pkgname string The name you wish to assign to your generated package (default "models") ``` Follow the steps below to do some basic model generation. Once we've generated our models, we can run the compatibility tests which will exercise the entirety of the generated code. This way we can ensure that our database is compatible with sqlboiler. If you find there are some failing tests, please check the [Diagnosing Problems](#diagnosing-problems) section. ```sh # Generate our models and exclude the migrations table sqlboiler -x goose_migrations postgres # Run the generated tests go test ./models # This requires an administrator postgres user because of some # voodoo we do to disable triggers for the generated test db ``` ## Diagnosing Problems The most common causes of problems and panics are: - Forgetting to exclude tables you do not want included in your generation, like migration tables. - Tables without a primary key. All tables require one. - Forgetting foreign key constraints on your columns that reference other tables. - The compatibility tests that run against your own DB schema require a superuser, ensure the user supplied in your config has adequate privileges. - A nil or closed database handle. Ensure your passed in `boil.Executor` is not nil. - If you decide to use the `G` variant of functions instead, make sure you've initialized your global database handle using `boil.SetDB()`. For errors with other causes, it may be simple to debug yourself by looking at the generated code. Setting `boil.DebugMode` to `true` can help with this. You can change the output using `boil.DebugWriter` (defaults to `os.Stdout`). If you're still stuck and/or you think you've found a bug, feel free to leave an issue and we'll do our best to help you. ## Features & Examples Most examples in this section will be demonstrated using the following schema, structs and variables: ```sql CREATE TABLE pilots ( id integer NOT NULL, name text NOT NULL, ); ALTER TABLE pilots ADD CONSTRAINT pilot_pkey PRIMARY KEY (id); CREATE TABLE jets ( id integer NOT NULL, pilot_id integer NOT NULL, age integer NOT NULL, name text NOT NULL, color text NOT NULL, ); ALTER TABLE jets ADD CONSTRAINT jet_pkey PRIMARY KEY (id); ALTER TABLE jets ADD CONSTRAINT pilots_fkey FOREIGN KEY (pilot_id) REFERENCES pilots(id); CREATE TABLE languages ( id integer NOT NULL, language text NOT NULL ); ALTER TABLE languages ADD CONSTRAINT language_pkey PRIMARY KEY (id); -- Join table CREATE TABLE pilot_languages ( pilot_id integer NOT NULL, language_id integer NOT NULL ); -- Composite primary key ALTER TABLE pilot_languages ADD CONSTRAINT pilot_language_pkey PRIMARY KEY (pilot_id, language_id); ALTER TABLE pilot_languages ADD CONSTRAINT pilots_fkey FOREIGN KEY (pilot_id) REFERENCES pilots(id); ALTER TABLE pilot_languages ADD CONSTRAINT languages_fkey FOREIGN KEY (language_id) REFERENCES languages(id); ``` The generated model structs for this schema look like the following. Note that I've included the relationship structs as well so you can see how it all pieces together, but these are unexported and not something you should ever need to touch directly: ```go type Pilot struct { ID int `boil:"id" json:"id" toml:"id" yaml:"id"` Name string `boil:"name" json:"name" toml:"name" yaml:"name"` R *pilotR `boil:"-" json:"-" toml:"-" yaml:"-"` } type pilotR struct { Licenses LicenseSlice Languages LanguageSlice Jets JetSlice } type Jet struct { ID int `boil:"id" json:"id" toml:"id" yaml:"id"` PilotID int `boil:"pilot_id" json:"pilot_id" toml:"pilot_id" yaml:"pilot_id"` Age int `boil:"age" json:"age" toml:"age" yaml:"age"` Name string `boil:"name" json:"name" toml:"name" yaml:"name"` Color string `boil:"color" json:"color" toml:"color" yaml:"color"` R *jetR `boil:"-" json:"-" toml:"-" yaml:"-"` } type jetR struct { Pilot *Pilot } type Language struct { ID int `boil:"id" json:"id" toml:"id" yaml:"id"` Language string `boil:"language" json:"language" toml:"language" yaml:"language"` R *languageR `boil:"-" json:"-" toml:"-" yaml:"-"` } type languageR struct { Pilots PilotSlice } ``` ```go // Open handle to database like normal db, err := sql.Open("postgres", "dbname=fun user=abc") if err != nil { return err } ``` ### Automatic CreatedAt/UpdatedAt If your generated SQLBoiler models package can find columns with the names `created_at` or `updated_at` it will automatically set them to `time.Now()` in your database, and update your object appropriately. To disable this feature use `--no-auto-timestamps`. Note: You can set the timezone for this feature by calling `boil.SetLocation()` #### Overriding Automatic Timestamps * **Insert** * Timestamps for both `updated_at` and `created_at` that are zero values will be set automatically. * To set the timestamp to null, set `Valid` to false and `Time` to a non-zero value. This is somewhat of a work around until we can devise a better solution in a later version. * **Update** * The `updated_at` column will always be set to `time.Now()`. If you need to override this value you will need to fall back to another method in the meantime: `boil.SQL()`, overriding `updated_at` in all of your objects using a hook, or create your own wrapper. * **Upsert** * `created_at` will be set automatically if it is a zero value, otherwise your supplied value will be used. To set `created_at` to `null`, set `Valid` to false and `Time` to a non-zero value. * The `updated_at` column will always be set to `time.Now()`. ### Query Building We generate "Starter" methods for you. These methods are named as the plural versions of your model, for example: `models.Jets()`. Starter methods are used to build queries using our [Query Mod System](#query-mod-system). They take a collection of [Query Mods](#query-mod-system) as parameters, and end with a call to a [Finisher](#finishers) method. Here are a few examples: ```go // SELECT COUNT(*) FROM pilots; count, err := models.Pilots().Count() // SELECT * FROM "pilots" LIMIT 5; pilots, err := models.Pilots(qm.Limit(5)).All() // DELETE FROM "pilots" WHERE "id"=$1; err := models.Pilots(qm.Where("id=?", 1)).DeleteAll() ``` As you can see, [Query Mods](#query-mods) allow you to modify your queries, and [Finishers](#finishers) allow you to execute the final action. If you plan on executing the same query with the same values using the query builder, you should do so like the following to utilize caching: ```go // Instead of this: for i := 0; i < 10; i++ { pilots := models.Pilots(qm.Where("id > ?", 5), qm.Limit(5)).All() } // You should do this query := models.Pilots(qm.Where("id > ?", 5), qm.Limit(5)) for i := 0; i < 10; i++ { pilots := query.All() } // Every execution of All() after the first will use a cached version of // the built query that short circuits the query builder all together. // This allows you to save on performance. ``` ### Query Mod System The query mod system allows you to modify queries created with [Starter](#query-building) methods when performing query building. Here is a list of all of your generated query mods using examples: ```go // Dot import so we can access query mods directly instead of prefixing with "qm." import . "github.com/vattle/sqlboiler/boil/qm" // Use a raw query against a generated struct (Pilot in this example) // If this query mod exists in your call, it will override the others. // "?" placeholders are not supported here, use "$1, $2" etc. SQL("select * from pilots where id=$1", 10) models.Pilots(SQL("select * from pilots where id=$1", 10)).All() Select("id", "name") // Select specific columns. From("pilots as p") // Specify the FROM table manually, can be useful for doing complex queries. // WHERE clause building Where("name=?", "John") And("age=?", 24) Or("height=?", 183) // WHERE IN clause building WhereIn("name, age in ?", "John" 24, "Tim", 33) // Generates: WHERE ("name","age") IN (($1,$2),($3,$4)) AndIn("weight in ?", 84) OrIn("height in ?", 183, 177, 204) InnerJoin("pilots p on jets.pilot_id=?", 10) GroupBy("name") OrderBy("age, height") Having("count(jets) > 2") Limit(15) Offset(5) // Explicit locking For("update nowait") // Eager Loading -- Load takes the relationship name, ie the struct field name of the // Relationship struct field you want to load. Load("Languages") // If it's a ToOne relationship it's in singular form, ToMany is plural. ``` Note: We don't force you to break queries apart like this if you don't want to, the following is also valid and supported by query mods that take a clause: ```go Where("(name=? OR age=?) AND height=?", "John", 24, 183) ``` ### Function Variations You will find that most functions have the following variations. We've used the ```Delete``` method to demonstrate: ```go // Set the global db handle for G method variants. boil.SetDB(db) pilot, _ := models.FindPilot(db, 1) err := pilot.Delete(db) // Regular variant, takes a db handle (boil.Executor interface). pilot.DeleteP(db) // Panic variant, takes a db handle and panics on error. err := pilot.DeleteG() // Global variant, uses the globally set db handle (boil.SetDB()). pilot.DeleteGP() // Global&Panic variant, combines the global db handle and panic on error. ``` Note that it's slightly different for query building. ### Finishers Here are a list of all of the finishers that can be used in combination with [Query Building](#query-building). Finishers all have `P` (panic) [method variations](#function-variations). To specify your db handle use the `G` or regular variation of the [Starter](#query-building) method. ```go // These are called like the following: models.Pilots(db).All() One() // Retrieve one row as object (same as LIMIT(1)) All() // Retrieve all rows as objects (same as SELECT * FROM) Count() // Number of rows (same as COUNT(*)) UpdateAll(models.M{"name": "John", "age": 23}) // Update all rows matching the built query. DeleteAll() // Delete all rows matching the built query. Exists() // Returns a bool indicating whether the row(s) for the built query exists. Bind(&myObj) // Bind the results of a query to your own struct object. ``` ### Raw Query We provide `boil.SQL()` for executing raw queries. Generally you will want to use `Bind()` with this, like the following: ```go boil.SQL(db, "select * from pilots where id=$1", 5).Bind(&obj) ``` You can use your own structs or a generated struct as a parameter to Bind. Bind supports both a single object for single row queries and a slice of objects for multiple row queries. ### Binding The `Bind()` [Finisher](#finisher) allows the results of a query built with the [Raw SQL](#raw-query) method or the [Query Builder](#query-building) methods to be bound to your generated struct objects, or your own custom struct objects. This can be useful for complex queries, queries that only require a small subset of data and have no need for the rest of the object variables, or custom join struct objects like the following: ```go // Custom object using two generated structs type PilotAndJet struct { models.Pilot `boil:",bind"` models.Jet `boil:",bind"` } var paj PilotAndJet boil.SQL("select pilots.*, jets.* from pilots inner join jets on jets.pilot_id=?", 1).Bind(&paj) ``` ```go // Custom object to select subset of data type JetInfo struct { AgeSum int `boil:"age_sum"` Count int `boil:"juicy_count"` } var info JetInfo boil.SQL("select sum(age) as "age_sum", count(*) as "juicy_count" from jets").Bind(&info) ``` We support the following struct tag modes for `Bind()` control: ```go type CoolObject struct { // Don't specify a name, Bind will attempt snake_case conversion. Frog int // Specify an alternative db column name, can be whatever you like. Cat int `boil:"kitten"` // Attempt to bind to members inside Dog if they // cannot be found on this outer layer first. Dog `boil:"bind"` // Ignore this member, do not attempt to bind it. Bird `boil:"-"` } ``` Note that structs take either `bind` or `-`, and regular members take an optional alternative column name. ### Hooks We support the use of hooks for Before and After query execution. Every generated package that includes hooks has the following `HookPoints` defined: ```go const ( BeforeInsertHook HookPoint = iota + 1 BeforeUpdateHook BeforeDeleteHook BeforeUpsertHook AfterInsertHook AfterSelectHook AfterUpdateHook AfterDeleteHook AfterUpsertHook ) ``` To register a hook for your model you will need to create the hook function, and attach it with the `AddModelHook` method. Here is an example of a before insert hook: ```go // Define my hook function func myHook(exec boil.Executor, p *Pilot) { // Do stuff } // Register my before insert hook for pilots models.AddPilotHook(boil.BeforeInsertHook, myHook) ``` Your `ModelHook` will always be defined as `func(boil.Executor, *Model)` Please be aware that if your project has no need for hooks they can be disabled on generation using the `--no-hooks` flag. Doing so will save you some binary size on compilation. ### Transactions The `boil.Executor` interface implements `sql.Tx`, as well as most other database driver implementations. This makes using transactions very simple: ```go tx, err := db.Begin() if err != nil { return err } users, _ := models.Pilots(tx).All() users.DeleteAll(tx) // Rollback or commit tx.Commit() tx.Rollback() ``` ### Debug Logging Debug logging will print your generated SQL statement and the arguments it is using. Debug logging can be toggled on globally by setting the following global variable to `true`: ```go boil.DebugMode = true // Optionally set the writer as well. Defaults to os.Stdout fh, _ := os.Open("debug.txt") boil.DebugWriter = fh ``` Note: Debug output is messy at the moment. This is something we want to address. ### Select Select is done through [Query Building](#query-building) and [Find](#find). Here's a short example: ```go // Select one pilot pilot, err := models.Pilots(db, qm.Where("name=?", "Tim")).One() // Select many jets jets, err := models.Jets(db, qm.Where("age > ?", 20)).All() ``` ### Find Find is used to find a single row by primary key: ```go // Retrieve pilot with all columns filled pilot, err := models.PilotFind(db, 1) // Retrieve a subset of column values jet, err := models.JetFind(db, 1, "name", "color") ``` ### Insert The main thing to be aware of with `Insert` is how the `whitelist` operates. If no whitelist argument is provided, `Insert` will abide by the following rules: - Insert all columns **without** a default value in the database. - Insert all columns with a non-zero value in the struct that have a default value in the database. On the other hand, if a whitelist is provided, we will only insert the columns specified in the whitelist. Also note that your object will automatically be updated with any missing default values from the database after the `Insert` is finished executing. This includes auto-incrementing column values. ```go var p1 models.Pilot p1.Name = "Larry" err := p1.Insert(db) // Insert the first pilot with name "Larry" // p1 now has an ID field set to 1 var p2 models.Pilot p2.Name "Borris" err := p2.Insert(db) // Insert the second pilot with name "Borris" // p2 now has an ID field set to 2 var p3 models.Pilot p3.ID = 25 p3.Name = "Rupert" err := p3.Insert(db) // Insert the third pilot with a specific ID // The id for this row was inserted as 25 in the database. var p4 models.Pilot p4.ID = 0 p4.Name = "Nigel" err := p4.Insert(db, "id", "name") // Insert the fourth pilot with a zero value ID // The id for this row was inserted as 0 in the database. // Note: We had to use the whitelist for this, otherwise // SQLBoiler would presume you wanted to auto-increment ``` ### Update `Update` can be performed on a single object, a slice of objects or as a [Finisher](#finishers) for a collection of rows. `Update` on a single object optionally takes a `whitelist`. The purpose of the whitelist is to specify which columns in your object should be updated in the database. If no `whitelist` argument is provided, `Update` will update every column except for `primary key` columns. If a `whitelist` argument is provided, `update` will only update the columns specified. ```go // Find a pilot and update his name pilot, _ := models.FindPilot(db, 1) pilot.Name = "Neo" err := pilot.Update(db) // Update a slice of pilots to have the name "Smith" pilots, _ := models.Pilots(db).All() err := pilots.UpdateAll(db, models.M{"name": "Smith"}) // Update all pilots in the database to to have the name "Smith" err := models.Pilots(db).UpdateAll(models.M{"name", "Smith"}) ``` ### Delete Delete a single object, a slice of objects or specific objects through [Query Building](#query-building). ```go pilot, _ := models.FindPilot(db, 1) // Delete the pilot from the database err := pilot.Delete(db) // Delete all pilots from the database err := models.Pilots(db).DeleteAll() // Delete a slice of pilots from the database pilots, _ := models.Pilots(db).All() err := pilots.DeleteAll(db) ``` ### Upsert [Upsert](https://www.postgresql.org/docs/9.5/static/sql-insert.html) allows you to perform an insert that optionally performs an update when a conflict is found against existing row values. The `whitelist` operates in the same fashion that it does for [Insert](#insert). If an insert is performed, your object will be updated with any missing default values from the database, such as auto-incrementing column values. ```go var p1 models.Pilot p1.ID = 5 p1.Name = "Gaben" // INSERT INTO pilots ("id", "name") VALUES($1, $2) // ON CONFLICT DO NOTHING err := p1.Upsert(db, false, nil, nil) // INSERT INTO pilots ("id", "name") VALUES ($1, $2) // ON CONFLICT ("id") DO UPDATE SET "name" = EXCLUDED."name" err := p1.Upsert(db, true, []string{"id"}, []string{"name"}) // Set p1.ID to a zero value. We will have to use the whitelist now. p1.ID = 0 p1.Name = "Hogan" // INSERT INTO pilots ("id", "name") VALUES ($1, $2) // ON CONFLICT ("id") DO UPDATE SET "name" = EXCLUDED."name" err := p1.Upsert(db, true, []string{"id"}, []string{"name"}, "id", "name") ``` Note: Passing a different set of column values to the update component is not currently supported. If this feature is important to you let us know and we can consider adding something for this. ### Reload In the event that your objects get out of sync with the database for whatever reason, you can use `Reload` and `ReloadAll` to reload the objects using the primary key values attached to the objects. ```go pilot, _ := models.FindPilot(db, 1) // > Object becomes out of sync for some reason // Refresh the object with the latest data from the db err := pilot.Reload(db) // Reload all objects in a slice pilots, _ := models.Pilots(db).All() err := pilots.ReloadAll(db) ``` Note: `Reload` and `ReloadAll` are not recursive, if you need your relationships reloaded you will need to call the `Reload` methods on those yourself. ### Relationships relationships to one and to many relationship set ops (to one: set, remove, tomany: add, set, remove) eager loading (nested and flat) ## Benchmarks ## FAQ #### Won't compiling models for a huge database be very slow? No, because Go's toolchain - unlike traditional toolchains - makes the compiler do most of the work instead of the linker. This means that when the first `go install` is done it can take a little bit of time because there is a lot of code that is generated. However, because of this work balance between the compiler and linker in Go, linking to that code afterwards in the subsequent compiles is extremely fast.