├── README.md └── pg2go.sql /README.md: -------------------------------------------------------------------------------- 1 | [pg2go] is a [PostgreSQL] script that generates [Go] struct definitions for all 2 | tables in a database. 3 | 4 | It is designed to be run directly against a database using the official `psql` command, and the output of that redirected to a new `.go` source file. 5 | 6 | Here is an example Unix shell session demonstrating this (it interacts with a hypothetical database called `blogdb`): 7 | 8 | ```shell 9 | DB=blogdb 10 | OUT_FILE="types_$DB.go" 11 | 12 | echo "package main" >"$OUT_FILE" 13 | psql --quiet --tuples-only --no-align --dbname "$DB" --file pg2go.sql >>"$OUT_FILE" 14 | 15 | goimports -w "$OUT_FILE" || gofmt -w "$OUT_FILE" 16 | ``` 17 | 18 | Finally, we can peek at the contents of the generated `.go` file using the `head` command: 19 | 20 | ```shell 21 | head -n 22 types_blogdb.go 22 | ``` 23 | 24 | ```go 25 | package main 26 | 27 | import ( 28 | "database/sql" 29 | "time" 30 | ) 31 | 32 | type Author struct { 33 | ID int `db:"id" json:"id"` 34 | Created time.Time `db:"created" json:"created"` 35 | Name string `db:"name" json:"name"` 36 | Admin bool `db:"admin" json:"admin"` 37 | LoginEmail string `db:"login_email" json:"login_email"` 38 | LoginSalt []byte `db:"login_salt" json:"login_salt"` 39 | LoginKey []byte `db:"login_key" json:"login_key"` 40 | } 41 | 42 | type Comment struct { 43 | ID int `db:"id" json:"id"` 44 | Created time.Time `db:"created" json:"created"` 45 | Post int `db:"post" json:"post"` 46 | Author int `db:"author" json:"author"` 47 | ``` 48 | 49 | # Notes 50 | 51 | Using the [goimports] command rather than the standard `gofmt` command to format the resultant file has the benefit of automatically adding import statements for packages if and only if they are used in what was generated (e.g. `"time"` for `time.Time` & `"database/sql"` for `sql.NullString`). 52 | 53 | Struct fields are tagged `db:"..."` for [package sqlx][sqlx] to pick up on, should you wish to use it. Similarly, `json:"..."` for the standard library package `encoding/json`. 54 | 55 | An [attempt](https://github.com/frou/pg2go/blob/master/pg2go.sql#L83) is made to singularize plural table names. 56 | 57 | If `NEED_GO_TYPE_FOR_...` shows up in the resultant file then add a case for that type name to the `type_pg2go` function in `pg2go.sql`. 58 | 59 | If the tables you're interested in aren't in the default `'public'` schema of your database, then search and replace that text in `pg2go.sql`. 60 | 61 | ## Support for Enums 62 | 63 | When the database schema has something like: 64 | 65 | ```plpgsql 66 | CREATE TYPE post_status AS ENUM ('draft', 'live', 'retracted'); 67 | 68 | CREATE TABLE post ( 69 | -- ... 70 | status post_status NOT NULL 71 | -- ... 72 | ); 73 | ``` 74 | 75 | The resultant file will contain: 76 | 77 | ```go 78 | type Post struct { 79 | // ... 80 | Status string `db:"status" json:"status"` // Postgres enum. Use with the PostStatus* constants. 81 | // ... 82 | } 83 | 84 | // ... 85 | 86 | const ( 87 | PostStatusDraft = "draft" 88 | PostStatusLive = "live" 89 | PostStatusRetracted = "retracted" 90 | ) 91 | ``` 92 | 93 | A value other than one of those constants will be rejected by Postgres when performing an `INSERT` or `UPDATE`. 94 | 95 | # License 96 | 97 | ```text 98 | The MIT License 99 | 100 | Copyright (c) 2015 Duncan Holm 101 | 102 | Permission is hereby granted, free of charge, to any person obtaining a copy 103 | of this software and associated documentation files (the "Software"), to deal 104 | in the Software without restriction, including without limitation the rights 105 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 106 | copies of the Software, and to permit persons to whom the Software is 107 | furnished to do so, subject to the following conditions: 108 | 109 | The above copyright notice and this permission notice shall be included in all 110 | copies or substantial portions of the Software. 111 | 112 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 113 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 114 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 115 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 116 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 117 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 118 | SOFTWARE. 119 | ``` 120 | 121 | [pg2go]: https://github.com/frou/pg2go 122 | [postgresql]: https://www.postgresql.org 123 | [psql]: http://www.postgresql.org/docs/current/static/app-psql.html 124 | [goimports]: https://godoc.org/golang.org/x/tools/cmd/goimports 125 | [go]: https://www.golang.org 126 | [sqlx]: https://github.com/jmoiron/sqlx 127 | -------------------------------------------------------------------------------- /pg2go.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION name_pg2go(nm text, exported boolean) RETURNS text AS $$ 2 | SELECT CASE 3 | WHEN lower(nm) IN ('id', 'uid') THEN 4 | CASE WHEN exported THEN upper(nm) ELSE lower(nm) END 5 | WHEN exported THEN 6 | -- snake_case -> PascalCase 7 | replace(initcap(replace(nm, '_', ' ')), ' ', '') 8 | ELSE 9 | -- snake_case -> camelCase 10 | lower(substring(nm, 1, 1)) || substring(name_pg2go(nm, true), 2) 11 | END 12 | $$ 13 | LANGUAGE SQL 14 | IMMUTABLE; 15 | 16 | CREATE FUNCTION type_pg2go(typ text, nullable boolean) RETURNS text AS $$ 17 | SELECT CASE 18 | WHEN nullable THEN 19 | CASE typ 20 | WHEN 'bigint' THEN 'sql.NullInt64' 21 | WHEN 'boolean' THEN 'sql.NullBool' 22 | WHEN 'double precision' THEN 'sql.NullFloat64' 23 | WHEN 'integer' THEN 'sql.NullInt64' 24 | WHEN 'numeric' THEN 'sql.NullInt64' 25 | WHEN 'real' THEN 'sql.NullFloat64' 26 | WHEN 'smallint' THEN 'sql.NullInt64' 27 | 28 | WHEN 'bytea' THEN '[]byte' 29 | WHEN 'character varying' THEN 'sql.NullString' 30 | WHEN 'character' THEN 'sql.NullString' 31 | WHEN 'text' THEN 'sql.NullString' 32 | 33 | WHEN 'date' THEN 'sql.NullTime' 34 | WHEN 'time with time zone' THEN 'sql.NullTime' 35 | WHEN 'time without time zone' THEN 'sql.NullTime' 36 | WHEN 'timestamp with time zone' THEN 'sql.NullTime' 37 | WHEN 'timestamp without time zone' THEN 'sql.NullTime' 38 | 39 | ELSE 'NEED_GO_TYPE_FOR_NULLABLE_' || replace(typ, ' ', '_') 40 | END 41 | ELSE 42 | CASE typ 43 | WHEN 'bigint' THEN 'int' 44 | WHEN 'boolean' THEN 'bool' 45 | WHEN 'double precision' THEN 'float64' 46 | WHEN 'integer' THEN 'int' 47 | WHEN 'numeric' THEN 'int' 48 | WHEN 'real' THEN 'float32' 49 | WHEN 'smallint' THEN 'int' 50 | 51 | WHEN 'bytea' THEN '[]byte' 52 | WHEN 'character varying' THEN 'string' 53 | WHEN 'character' THEN 'string' 54 | WHEN 'text' THEN 'string' 55 | 56 | WHEN 'date' THEN 'time.Time' 57 | WHEN 'time with time zone' THEN 'time.Time' 58 | WHEN 'time without time zone' THEN 'time.Time' 59 | WHEN 'timestamp with time zone' THEN 'time.Time' 60 | WHEN 'timestamp without time zone' THEN 'time.Time' 61 | 62 | ELSE 'NEED_GO_TYPE_FOR_' || replace(typ, ' ', '_') 63 | END 64 | END; 65 | $$ 66 | LANGUAGE SQL 67 | IMMUTABLE; 68 | 69 | ------------------------------------------------------------ 70 | 71 | SELECT E'\n// Code generated by github.com/frou/pg2go ; DO NOT EDIT.\n'; 72 | 73 | WITH structs AS ( 74 | WITH db_extract AS ( 75 | SELECT table_name, 76 | column_name, 77 | data_type, 78 | data_type = 'USER-DEFINED' AS is_udt, 79 | udt_name, 80 | is_nullable 81 | FROM information_schema.columns 82 | WHERE table_schema = 'public' 83 | ORDER BY table_schema, table_name, ordinal_position 84 | ) 85 | SELECT name_pg2go(regexp_replace(table_name, '([^aeiou])s$', '\1'), 86 | true) AS type_identifier, 87 | string_agg(E'\t' || name_pg2go(column_name, true) || ' ' 88 | || type_pg2go(CASE WHEN is_udt THEN 'text' 89 | ELSE data_type END, 90 | is_nullable::boolean) 91 | || ' `db:"' || column_name || '"' 92 | || ' json:"'|| column_name || '"`' 93 | || CASE WHEN is_udt THEN ' // Postgres enum. ' 94 | || 'Use with the ' || name_pg2go(udt_name, true) 95 | || '* constants.' ELSE '' END, 96 | E'\n') AS agg_fields 97 | FROM db_extract GROUP BY table_name 98 | ORDER BY table_name 99 | ) 100 | SELECT 'type ' || type_identifier || E' struct {\n' || agg_fields || E'\n}\n' 101 | FROM structs; 102 | 103 | ------------------------------------------------------------ 104 | 105 | WITH constant_groups AS ( 106 | WITH db_extract AS ( 107 | SELECT typname, enumlabel 108 | FROM pg_enum JOIN pg_type ON pg_enum.enumtypid = pg_type.oid 109 | ) 110 | SELECT string_agg(E'\t' || name_pg2go(typname, true) 111 | || name_pg2go(enumlabel, true) || ' = ' 112 | || '"' || enumlabel || '"', E'\n') AS agg_constants 113 | FROM db_extract GROUP BY typname 114 | ORDER BY typname 115 | ) 116 | -- @todo #0 Make generated constants extra type-safe by delcaring a new type 117 | -- (e.g. `type foo string`) then using that type for each of the constants 118 | -- (e.g. `const ( fooBar foo = "..." ...)`). For this to work, I think at 119 | -- least an implementation of https://godoc.org/database/sql/driver#Valuer 120 | -- would have to be generated too. 121 | SELECT E'const (\n' || agg_constants || E'\n)\n' 122 | FROM constant_groups; 123 | 124 | ------------------------------------------------------------ 125 | 126 | DROP FUNCTION name_pg2go(text, boolean); 127 | DROP FUNCTION type_pg2go(text, boolean); 128 | --------------------------------------------------------------------------------