Commit fca48375 authored by ale's avatar ale

Merge branch 'sql' into 'master'

SQL support

See merge request !4
parents f095fa5e 20cb3ed8
Pipeline #2654 passed with stages
in 1 minute and 49 seconds
......@@ -167,7 +167,7 @@ user, with the following attributes:
convenience)
* `groups` is a list of group names that the user belongs to
## LDAP Backend
## LDAP backend
The *ldap* backend will look up user information in a LDAP database.
The backend connects to a single LDAP server and requires the
......@@ -231,6 +231,102 @@ App-specific passwords should be encoded as colon-separated strings:
The password should be encrypted. The comment is a free-form string
set by the user to tell the various credentials apart.
## SQL backend
The SQL backend allows you to use a SQL database to store user
information. It can adapt to any schema, provided that you can write
the queries it expects.
The parameters for the SQL backend configuration are:
* `driver` is the name of the database/sql driver (currently it must
be one of `sqlite3`, `mysql` or `postgres`, the built-in drivers)
* `db_uri` is the database URI (a.k.a. DSN), whose exact syntax will
depend on the chosen driver. Check out the documentation for the
database/sql [sqlite](https://github.com/mattn/go-sqlite3),
[mysql](https://github.com/go-sql-driver/mysql) and
[postgres](https://godoc.org/github.com/lib/pq) drivers.
### Query definition
Each service can specify a set of different SQL queries. It can be
configured with the following attributes:
* `queries` holds the map of SQL queries that tell the auth-server
how to query your database.
The known queries are identified by name. It does not matter what
operations you do as long as the queries take the expected input
substitution parameters, and return rows with the expected number of
fields (column names do not matter). You should use the parameter
substitution symbol `?` as placeholder for query parameters.
* `get_user` takes a single parameter (the user name) and must return
a single row with *email*, *password*, *TOTP secret* and *shard*
fields for the matching user.
* `get_user_groups` takes a single parameter (the user name) and must
return rows with a single *group_name* field corresponding to the
user's group memberships.
* `get_user_u2f` takes a single parameter (user name) and must return
the user's U2F registrations as rows with *public_key* and
*key_handle* fields, in their native binary format.
* `get_user_asp` takes a single parameter (user name) and must return
the user's application-specific passwords as rows with *service* and
*password* fields.
The only mandatory query is *get_user*, if the other ones are not
specified the associated fields will be empty.
### Example database schema
The following could be a (very simple) example database schema for a
case where usernames are also email addresses, with support for all
authentication features:
```sql
CREATE TABLE users (
email text NOT NULL,
password text NOT NULL,
totp_secret text,
shard text
);
CREATE UNIQUE INDEX users_email_idx ON users(email);
CREATE TABLE group_memberships (
email text NOT NULL,
group_name text NOT NULL
);
CREATE INDEX group_memberships_idx ON group_memberships(email);
CREATE TABLE u2f_registrations (
email text NOT NULL,
key_handle blob NOT NULL,
public_key blob NOT NULL
);
CREATE INDEX u2f_registrations_idx ON u2f_registrations(email);
CREATE TABLE service_passwords (
email text NOT NULL,
service text NOT NULL,
password text NOT NULL
);
CREATE INDEX service_passwords_idx ON service_passwords(email);
```
With this schema, one could use the following configuration for a
service:
```yaml
services:
example:
challenge_response: true
backends:
- backend: sql
params:
queries:
get_user: "SELECT email, password, totp_secret, shard FROM users WHERE email = ?"
get_user_groups: "SELECT group_name FROM group_memberships WHERE email = ?"
get_user_u2f: "SELECT public_key, key_handle FROM u2f_registrations WHERE email = ?"
get_user_asp: "SELECT service, password FROM service_passwords WHERE email = ?"
```
# Usage
......
......@@ -149,8 +149,10 @@ func createBackends(config *Config) (map[string]userBackend, error) {
b, err = newFileBackend(config, params)
case "ldap":
b, err = newLDAPBackend(config, params)
case "sql":
b, err = newSQLBackend(config, params)
default:
err = fmt.Errorf("unknown backend %s", name)
err = fmt.Errorf("unknown backend type %s", name)
}
if err != nil {
return nil, err
......
......@@ -40,7 +40,6 @@ func createTestServer(t testing.TB, configFiles map[string]string) *testServer {
if err != nil {
t.Fatal("NewServer():", err)
}
srv.Close()
return &testServer{
tmpdir: tmpdir,
......@@ -49,6 +48,7 @@ func createTestServer(t testing.TB, configFiles map[string]string) *testServer {
}
func (s *testServer) Close() {
s.srv.Close()
_ = os.RemoveAll(s.tmpdir)
}
......
package server
import (
"context"
"database/sql"
"errors"
"log"
"github.com/tstranex/u2f"
"gopkg.in/yaml.v2"
_ "github.com/go-sql-driver/mysql"
_ "github.com/lib/pq"
_ "github.com/mattn/go-sqlite3"
ct "git.autistici.org/ai3/go-common/ldap/compositetypes"
)
// Names for the known SQL queries.
const (
sqlQueryGetUser = "get_user"
sqlQueryGetGroups = "get_user_groups"
sqlQueryGetU2F = "get_user_u2f"
sqlQueryGetASP = "get_user_asp"
)
// Default SQL queries.
var defaultSQLQueries = map[string]string{
sqlQueryGetUser: `
SELECT email, password, totp_secret, '' AS shard FROM users WHERE name = ?
`,
}
type sqlConfig struct {
Driver string `yaml:"driver"`
URI string `yaml:"db_uri"`
}
type sqlServiceConfig struct {
Queries map[string]string `yaml:"queries"`
}
type sqlBackend struct {
db *sql.DB
}
type sqlServiceBackend struct {
db *sql.DB
stmts map[string]*sql.Stmt
}
func compileStatements(db *sql.DB, queries map[string]string) (map[string]*sql.Stmt, error) {
m := make(map[string]*sql.Stmt)
for name, query := range queries {
stmt, err := db.Prepare(query)
if err != nil {
return nil, err
}
m[name] = stmt
}
return m, nil
}
func newSQLBackend(config *Config, params yaml.MapSlice) (*sqlBackend, error) {
var sc sqlConfig
if err := unmarshalMapSlice(params, &sc); err != nil {
return nil, err
}
if sc.Driver == "" {
return nil, errors.New("driver is empty")
}
db, err := sql.Open(sc.Driver, sc.URI)
if err != nil {
return nil, err
}
return &sqlBackend{
db: db,
}, nil
}
func (b *sqlBackend) Close() {
b.db.Close()
}
func (b *sqlBackend) NewServiceBackend(spec *BackendSpec) (serviceBackend, error) {
var sc sqlServiceConfig
if err := unmarshalMapSlice(spec.Params, &sc); err != nil {
return nil, err
}
return newSQLServiceBackend(b.db, &sc)
}
func newSQLServiceBackend(db *sql.DB, sc *sqlServiceConfig) (*sqlServiceBackend, error) {
// Apply default queries.
for name, q := range defaultSQLQueries {
if _, ok := sc.Queries[name]; !ok {
sc.Queries[name] = q
}
}
// Compile the SQL statements.
stmts, err := compileStatements(db, sc.Queries)
if err != nil {
return nil, err
}
return &sqlServiceBackend{
db: db,
stmts: stmts,
}, nil
}
func (b *sqlServiceBackend) GetUser(ctx context.Context, name string) (*User, bool) {
tx, err := b.db.Begin()
if err != nil {
return nil, false
}
defer tx.Rollback() // nolint
user := User{Name: name}
// Use NullStrings for optional fields.
var nullableTOTP, nullableShard sql.NullString
row := tx.Stmt(b.stmts[sqlQueryGetUser]).QueryRow(name)
if err := row.Scan(&user.Email, &user.EncryptedPassword, &nullableTOTP, &nullableShard); err != nil {
return nil, false
}
if nullableTOTP.Valid {
user.TOTPSecret = nullableTOTP.String
}
if nullableShard.Valid {
user.Shard = nullableShard.String
}
// Now read the one-to-many relations.
if groups, err := b.getUserGroups(tx, name); err == nil {
user.Groups = groups
}
if regs, err := b.getUserU2FRegistrations(tx, name); err == nil {
user.U2FRegistrations = regs
}
if asps, err := b.getUserASPs(tx, name); err == nil {
user.AppSpecificPasswords = asps
}
return &user, true
}
func (b *sqlServiceBackend) getUserU2FRegistrations(tx *sql.Tx, name string) ([]u2f.Registration, error) {
stmt, ok := b.stmts[sqlQueryGetU2F]
if !ok {
return nil, nil
}
rows, err := tx.Stmt(stmt).Query(name)
if err != nil {
return nil, err
}
defer rows.Close()
// Use the compositetypes.U2FRegistration type to decode the
// U2F registration public key data into a usable format.
var out []u2f.Registration
for rows.Next() {
var ctr ct.U2FRegistration
if err := rows.Scan(&ctr.PublicKey, &ctr.KeyHandle); err != nil {
continue
}
reg, err := ctr.Decode()
if err != nil {
log.Printf("invalid u2f registration: %v", err)
continue
}
out = append(out, *reg)
}
return out, nil
}
func (b *sqlServiceBackend) getUserASPs(tx *sql.Tx, name string) ([]*AppSpecificPassword, error) {
stmt, ok := b.stmts[sqlQueryGetASP]
if !ok {
return nil, nil
}
rows, err := tx.Stmt(stmt).Query(name)
if err != nil {
return nil, err
}
defer rows.Close()
var out []*AppSpecificPassword
for rows.Next() {
var asp AppSpecificPassword
if err := rows.Scan(&asp.Service, &asp.EncryptedPassword); err != nil {
continue
}
out = append(out, &asp)
}
return out, nil
}
func (b *sqlServiceBackend) getUserGroups(tx *sql.Tx, name string) ([]string, error) {
stmt, ok := b.stmts[sqlQueryGetGroups]
if !ok {
return nil, nil
}
rows, err := tx.Stmt(stmt).Query(name)
if err != nil {
return nil, err
}
defer rows.Close()
var out []string
for rows.Next() {
var group string
if err := rows.Scan(&group); err != nil {
continue
}
out = append(out, group)
}
return out, nil
}
package server
import (
"context"
"database/sql"
"fmt"
"io/ioutil"
"os"
"path/filepath"
"testing"
"git.autistici.org/id/auth"
)
var (
testConfigTemplateWithSimpleDB = `---
backends:
sql:
driver: sqlite3
db_uri: "%s"
services:
test:
backends:
- backend: sql
params:
queries:
get_user: "SELECT email, password, '' AS totp_secret, '' AS shard FROM users WHERE email = ?"
`
testConfigTemplateWithFullDB = `---
backends:
sql:
driver: sqlite3
db_uri: "%s"
services:
test:
backends:
- backend: sql
params:
queries:
get_user: "SELECT email, password, totp_secret, '' AS shard FROM users WHERE name = ?"
interactive:
challenge_response: true
backends:
- backend: sql
params:
queries:
get_user: "SELECT email, password, totp_secret, '' AS shard FROM users WHERE name = ?"
get_user_groups: "SELECT group_name FROM group_membership WHERE name = ?"
get_user_u2f: "SELECT public_key, key_handle FROM u2f_registrations WHERE name = ?"
get_user_asp: "SELECT service, password FROM asps WHERE name = ?"
`
)
func withTestDB(t testing.TB, schema string) (func(), string) {
dir, err := ioutil.TempDir("", "")
if err != nil {
t.Fatal(err)
}
dbPath := filepath.Join(dir, "test.db")
db, err := sql.Open("sqlite3", dbPath)
if err != nil {
t.Fatalf("sql.Open: %v", err)
}
_, err = db.Exec(schema)
if err != nil {
t.Fatalf("sql error: %v", err)
}
db.Close()
return func() {
os.RemoveAll(dir)
}, dbPath
}
func TestBackend_SQL_SimpleSchema(t *testing.T) {
// Test a minimal database schema.
cleanup, dbPath := withTestDB(t, `
CREATE TABLE users (
email text,
password text
);
CREATE UNIQUE INDEX users_idx ON users(email);
INSERT INTO users (email, password) VALUES (
'test@example.com', '$s$16384$8$1$c479e8eb722f1b071efea7826ccf9c20$96d63ebed0c64afb746026f56f71b2a1f8796c73141d2d6b1958d4ea26c60a0b'
);
`)
defer cleanup()
conf := fmt.Sprintf(testConfigTemplateWithSimpleDB, dbPath)
s := createTestServer(t, map[string]string{
"config.yml": conf,
})
defer s.Close()
client := &clientAdapter{s.srv}
resp, err := client.Authenticate(context.Background(), &auth.Request{
Service: "test",
Username: "test@example.com",
Password: []byte("password"),
})
if err != nil {
t.Fatalf("Authenticate: %v", err)
}
if resp.Status != auth.StatusOK {
t.Fatalf("authentication failed: %v", resp.Status)
}
}
func TestBackend_SQL(t *testing.T) {
// Full schema that can run standard authentication tests.
cleanup, dbPath := withTestDB(t, `
CREATE TABLE users (
name text,
email text,
totp_secret text,
password text
);
CREATE UNIQUE INDEX users_name_idx ON users(name);
CREATE TABLE group_membership (
name text,
group_name text
);
CREATE INDEX group_membership_idx ON group_membership(name);
CREATE TABLE u2f_registrations (
name text,
key_handle blob,
public_key blob
);
CREATE INDEX u2f_registrations_idx ON u2f_registrations(name);
CREATE TABLE asps (
name text,
service text,
password text
);
CREATE INDEX asp_idx ON asps(name);
INSERT INTO users (name, email, totp_secret, password) VALUES (
'testuser', 'testuser@example.com', NULL, '$s$16384$8$1$c479e8eb722f1b071efea7826ccf9c20$96d63ebed0c64afb746026f56f71b2a1f8796c73141d2d6b1958d4ea26c60a0b'), (
'2fauser', '2fauser@example.com', 'O32OBVS5BL5EAPB5', '$s$16384$8$1$c479e8eb722f1b071efea7826ccf9c20$96d63ebed0c64afb746026f56f71b2a1f8796c73141d2d6b1958d4ea26c60a0b');
INSERT INTO group_membership (name, group_name) VALUES (
'testuser', 'group1'), (
'2fauser', 'group2');
INSERT INTO u2f_registrations (name, key_handle, public_key) VALUES (
'2fauser', X'25ca255c0e8a6a88a13bc56ec52ba0b424f98f287eea516e5972e41403def2cf6ab33c5332f0c0b499fc826620f6e18efa49a381aa7587496572196aaa30a92b', X'0498ee4565cd348031cf36ee3549b63b5ea23b5e7ea6f297e7cccaeba99983d185110fb94fa6455c82d3e5c8d0be10be71308d76062fb5fa50d3ea8228048f0037');
`)
defer cleanup()
conf := fmt.Sprintf(testConfigTemplateWithFullDB, dbPath)
s := createTestServer(t, map[string]string{
"config.yml": conf,
})
defer s.Close()
runAuthenticationTest(t, &clientAdapter{s.srv})
}
# This is the official list of Go-MySQL-Driver authors for copyright purposes.
# If you are submitting a patch, please add your name or the name of the
# organization which holds the copyright to this list in alphabetical order.
# Names should be added to this file as
# Name <email address>
# The email address is not required for organizations.
# Please keep the list sorted.
# Individual Persons
Aaron Hopkins <go-sql-driver at die.net>
Achille Roussel <achille.roussel at gmail.com>
Alexey Palazhchenko <alexey.palazhchenko at gmail.com>
Andrew Reid <andrew.reid at tixtrack.com>
Arne Hormann <arnehormann at gmail.com>
Asta Xie <xiemengjun at gmail.com>
Bulat Gaifullin <gaifullinbf at gmail.com>
Carlos Nieto <jose.carlos at menteslibres.net>
Chris Moos <chris at tech9computers.com>
Craig Wilson <craiggwilson at gmail.com>
Daniel Montoya <dsmontoyam at gmail.com>
Daniel Nichter <nil at codenode.com>
Daniël van Eeden <git at myname.nl>
Dave Protasowski <dprotaso at gmail.com>
DisposaBoy <disposaboy at dby.me>
Egor Smolyakov <egorsmkv at gmail.com>
Evan Shaw <evan at vendhq.com>
Frederick Mayle <frederickmayle at gmail.com>
Gustavo Kristic <gkristic at gmail.com>
Hajime Nakagami <nakagami at gmail.com>
Hanno Braun <mail at hannobraun.com>
Henri Yandell <flamefew at gmail.com>
Hirotaka Yamamoto <ymmt2005 at gmail.com>
ICHINOSE Shogo <shogo82148 at gmail.com>
Ilia Cimpoes <ichimpoesh at gmail.com>
INADA Naoki <songofacandy at gmail.com>
Jacek Szwec <szwec.jacek at gmail.com>
James Harr <james.harr at gmail.com>
Jeff Hodges <jeff at somethingsimilar.com>
Jeffrey Charles <jeffreycharles at gmail.com>
Jerome Meyer <jxmeyer at gmail.com>
Jian Zhen <zhenjl at gmail.com>
Joshua Prunier <joshua.prunier at gmail.com>
Julien Lefevre <julien.lefevr at gmail.com>
Julien Schmidt <go-sql-driver at julienschmidt.com>
Justin Li <jli at j-li.net>
Justin Nuß <nuss.justin at gmail.com>
Kamil Dziedzic <kamil at klecza.pl>
Kevin Malachowski <kevin at chowski.com>
Kieron Woodhouse <kieron.woodhouse at infosum.com>
Lennart Rudolph <lrudolph at hmc.edu>
Leonardo YongUk Kim <dalinaum at gmail.com>
Linh Tran Tuan <linhduonggnu at gmail.com>
Lion Yang <lion at aosc.xyz>
Luca Looz <luca.looz92 at gmail.com>
Lucas Liu <extrafliu at gmail.com>
Luke Scott <luke at webconnex.com>
Maciej Zimnoch <maciej.zimnoch at codilime.com>
Michael Woolnough <michael.woolnough at gmail.com>
Nicola Peduzzi <thenikso at gmail.com>
Olivier Mengué <dolmen at cpan.org>
oscarzhao <oscarzhaosl at gmail.com>
Paul Bonser <misterpib at gmail.com>
Peter Schultz <peter.schultz at classmarkets.com>
Rebecca Chin <rchin at pivotal.io>
Reed Allman <rdallman10 at gmail.com>
Richard Wilkes <wilkes at me.com>
Robert Russell <robert at rrbrussell.com>
Runrioter Wung <runrioter at gmail.com>
Shuode Li <elemount at qq.com>
Simon J Mudd <sjmudd at pobox.com>
Soroush Pour <me at soroushjp.com>
Stan Putrya <root.vagner at gmail.com>
Stanley Gunawan <gunawan.stanley at gmail.com>
Steven Hartland <steven.hartland at multiplay.co.uk>
Thomas Wodarek <wodarekwebpage at gmail.com>
Tim Ruffles <timruffles at gmail.com>
Tom Jenkinson <tom at tjenkinson.me>
Xiangyu Hu <xiangyu.hu at outlook.com>
Xiaobing Jiang <s7v7nislands at gmail.com>
Xiuming Chen <cc at cxm.cc>
Zhenye Xie <xiezhenye at gmail.com>
# Organizations
Barracuda Networks, Inc.
Counting Ltd.
GitHub Inc.
Google Inc.
InfoSum Ltd.
Keybase Inc.
Percona LLC
Pivotal Inc.
Stripe Inc.
Multiplay Ltd.
## Version 1.4 (2018-06-03)
Changes:
- Documentation fixes (#530, #535, #567)
- Refactoring (#575, #579, #580, #581, #603, #615, #704)
- Cache column names (#444)
- Sort the DSN parameters in DSNs generated from a config (#637)
- Allow native password authentication by default (#644)
- Use the default port if it is missing in the DSN (#668)
- Removed the `strict` mode (#676)
- Do not query `max_allowed_packet` by default (#680)
- Dropped support Go 1.6 and lower (#696)
- Updated `ConvertValue()` to match the database/sql/driver implementation (#760)
- Document the usage of `0000-00-00T00:00:00` as the time.Time zero value (#783)
- Improved the compatibility of the authentication system (#807)
New Features:
- Multi-Results support (#537)
- `rejectReadOnly` DSN option (#604)
- `context.Context` support (#608, #612, #627, #761)
- Transaction isolation level support (#619, #744)
- Read-Only transactions support (#618, #634)
- `NewConfig` function which initializes a config with default values (#679)
- Implemented the `ColumnType` interfaces (#667, #724)
- Support for custom string types in `ConvertValue` (#623)
- Implemented `NamedValueChecker`, improving support for uint64 with high bit set (#690, #709, #710)
- `caching_sha2_password` authentication plugin support (#794, #800, #801, #802)
- Implemented `driver.SessionResetter` (#779)
- `sha256_password` authentication plugin support (#808)
Bugfixes:
- Use the DSN hostname as TLS default ServerName if `tls=true` (#564, #718)
- Fixed LOAD LOCAL DATA INFILE for empty files (#590)
- Removed columns definition cache since it sometimes cached invalid data (#592)
- Don't mutate registered TLS configs (#600)
- Make RegisterTLSConfig concurrency-safe (#613)
- Handle missing auth data in the handshake packet correctly (#646)
- Do not retry queries when data was written to avoid data corruption (#302, #736)
- Cache the connection pointer for error handling before invalidating it (#678)
- Fixed imports for appengine/cloudsql (#700)
- Fix sending STMT_LONG_DATA for 0 byte data (#734)
- Set correct capacity for []bytes read from length-encoded strings (#766)
- Make RegisterDial concurrency-safe (#773)
## Version 1.3 (2016-12-01)
Changes:
- Go 1.1 is no longer supported
- Use decimals fields in MySQL to format time types (#249)
- Buffer optimizations (#269)
- TLS ServerName defaults to the host (#283)
- Refactoring (#400, #410, #437)
- Adjusted documentation for second generation CloudSQL (#485)
- Documented DSN system var quoting rules (#502)
- Made statement.Close() calls idempotent to avoid errors in Go 1.6+ (#512)
New Features:
- Enable microsecond resolution on TIME, DATETIME and TIMESTAMP (#249)
- Support for returning table alias on Columns() (#289, #359, #382)
- Placeholder interpolation, can be actived with the DSN parameter `interpolateParams=true` (#309, #318, #490)
- Support for uint64 parameters with high bit set (#332, #345)
- Cleartext authentication plugin support (#327)
- Exported ParseDSN function and the Config struct (#403, #419, #429)
- Read / Write timeouts (#401)
- Support for JSON field type (#414)
- Support for multi-statements and multi-results (#411, #431)
- DSN parameter to set the driver-side max_allowed_packet value manually (#489)
- Native password authentication plugin support (#494, #524)
Bugfixes:
- Fixed handling of queries without columns and rows (#255)
- Fixed a panic when SetKeepAlive() failed (#298)
- Handle ERR packets while reading rows (#321)
- Fixed reading NULL length-encoded integers in MySQL 5.6+ (#349)
- Fixed absolute paths support in LOAD LOCAL DATA INFILE (#356)
- Actually zero out bytes in handshake response (#378)
- Fixed race condition in registering LOAD DATA INFILE handler (#383)
- Fixed tests with MySQL 5.7.9+ (#380)
- QueryUnescape TLS config names (#397)
- Fixed "broken pipe" error by writing to closed socket (#390)
- Fixed LOAD LOCAL DATA INFILE buffering (#424)
- Fixed parsing of floats into float64 when placeholders are used (#434)
- Fixed DSN tests with Go 1.7+ (#459)
- Handle ERR packets while waiting for EOF (#473)
- Invalidate connection on error while discarding additional results (#513)