├── .gitignore ├── test ├── bats │ ├── keys │ │ ├── id_ed25519.pub │ │ └── id_ed25519 │ ├── test_helper.bash │ └── test.bats ├── sql │ ├── 05reserved.sql │ ├── 04schemas.sql │ ├── 02postfix.sql │ ├── 03stats.sql │ ├── 06collisions.sql │ ├── 00basic.sql │ └── 01nss.sql ├── Dockerfile └── test.sh ├── schema ├── json │ ├── data_user.yml │ ├── data_host.yml │ └── api_schema.yml └── sql │ ├── json-schemas.sql │ ├── access.sql │ ├── stats.sql │ ├── metrics.sql │ ├── reserved.sql │ ├── nss.sql │ ├── schema.sql │ └── api.sql ├── .gitmodules ├── scripts └── build ├── LICENSE.md ├── Makefile ├── README.md ├── docs ├── REQUIREMENTS.md └── DESIGN.md └── docker.mk /.gitignore: -------------------------------------------------------------------------------- 1 | .* 2 | out/* 3 | /schema-dump.psql 4 | -------------------------------------------------------------------------------- /test/bats/keys/id_ed25519.pub: -------------------------------------------------------------------------------- 1 | ssh-ed25519 AAAAC3NzaC1lZDI1NTE5AAAAIKCXEbRyTwfQLhxpt9TMlpZSSGXNwnGmFdpV+yiljd4g user@host 2 | -------------------------------------------------------------------------------- /schema/json/data_user.yml: -------------------------------------------------------------------------------- 1 | $schema: http://json-schema.org/schema# 2 | title: "#! userdb -- Schema for user records auxiliary data" 3 | type: object 4 | properties: 5 | name: 6 | type: string 7 | description: "User's name (GECOS)" 8 | -------------------------------------------------------------------------------- /.gitmodules: -------------------------------------------------------------------------------- 1 | [submodule "tests/plpgunit"] 2 | path = test/sql/plpgunit 3 | url = https://github.com/mixerp/plpgunit 4 | [submodule "postgres-json-schema"] 5 | path = schema/ext/json-schema 6 | url = https://github.com/gavinwahl/postgres-json-schema.git 7 | -------------------------------------------------------------------------------- /schema/sql/json-schemas.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | -- JSON schema for user data 4 | alter table passwd add constraint data_user 5 | check(validate_json_schema($${data_user}$$::jsonb, data)); 6 | 7 | -- JSON schema for host data 8 | alter table hosts add constraint data_host 9 | check(validate_json_schema($${data_host}$$::jsonb, data)); 10 | -------------------------------------------------------------------------------- /test/bats/keys/id_ed25519: -------------------------------------------------------------------------------- 1 | -----BEGIN OPENSSH PRIVATE KEY----- 2 | b3BlbnNzaC1rZXktdjEAAAAABG5vbmUAAAAEbm9uZQAAAAAAAAABAAAAMwAAAAtzc2gtZW 3 | QyNTUxOQAAACCglxG0ck8H0C4cabfUzJaWUkhlzcJxphXaVfsopY3eIAAAAJD+FSnX/hUp 4 | 1wAAAAtzc2gtZWQyNTUxOQAAACCglxG0ck8H0C4cabfUzJaWUkhlzcJxphXaVfsopY3eIA 5 | AAAECQOfvuX29sW9y19bRReuSaYjlagbwTXPlfOnQOJr6YX6CXEbRyTwfQLhxpt9TMlpZS 6 | SGXNwnGmFdpV+yiljd4gAAAADGxydmlja0BtYXlpbQE= 7 | -----END OPENSSH PRIVATE KEY----- 8 | -------------------------------------------------------------------------------- /scripts/build: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env python3 2 | import string, yaml, json, sys, os 3 | 4 | in_dir = sys.argv[1] 5 | 6 | data = sys.stdin.read() 7 | 8 | for name in ("user", "host"): 9 | with open("{}/json/data_%s.yml".format(in_dir) % name, "r") as schema: 10 | json_data = json.dumps(yaml.safe_load(schema), indent=4) 11 | assert "$$" not in json_data 12 | data = data.replace("{data_%s}" % name, json_data) 13 | 14 | sys.stdout.write(data) 15 | -------------------------------------------------------------------------------- /schema/sql/access.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | create user "ssh_auth" inherit; 4 | comment on role "ssh_auth" is 5 | $$Access for ssh via AuthorizedKeysCommand$$; 6 | alter role "ssh_auth" with login; 7 | grant select on table 8 | public."group", 9 | public."passwd", 10 | public."aux_groups" 11 | to "ssh_auth"; 12 | 13 | create user "mail" inherit; 14 | comment on role "mail" is 15 | $$Access for MTAs like Postfix$$; 16 | alter role "mail" with login; 17 | -------------------------------------------------------------------------------- /schema/sql/stats.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | -- Create the host statistics view 4 | -- This is what the statistics API endpoint must expose, formated as JSON. 5 | create view host_statistics as 6 | select name, users, maxusers, data 7 | from hosts 8 | join ( 9 | select count(1) as users, 10 | host 11 | from passwd 12 | group by host 13 | ) 14 | as count 15 | on (count.host = hosts.name) 16 | ; 17 | -------------------------------------------------------------------------------- /test/sql/05reserved.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | -- Negative test for `reserved_usernames`: 4 | -- check that reserved names cannot be inserted. 5 | create function unit_tests.reserved_usernames() 6 | returns test_result as $$ 7 | declare message test_result; 8 | begin 9 | begin 10 | insert into passwd (name, host, shell) 11 | values ('noc', 'fo0.hashbang.sh','/bin/zsh' ); 12 | return assert.fail('Successfully inserted invalid user.'); 13 | exception 14 | when check_violation then 15 | return assert.ok('End of test.'); 16 | end; 17 | end $$ language plpgsql; 18 | -------------------------------------------------------------------------------- /test/sql/04schemas.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | -- Negative tests for the JSON schemas: 4 | -- check invalid data cannot be inserted 5 | 6 | -- Fails because of invalid required JSON data. 7 | CREATE FUNCTION unit_tests.json_hosts() 8 | RETURNS test_result AS $$ 9 | BEGIN 10 | BEGIN 11 | insert into hosts (name, data) values ('invalid.hashbang.sh', '{}'::jsonb); 12 | RETURN assert.fail('Successfully inserted invalid host'); 13 | EXCEPTION 14 | WHEN check_violation THEN 15 | RETURN assert.ok('End of test.'); 16 | END; 17 | END $$ LANGUAGE plpgsql; 18 | 19 | -- Users now have no required JSON data. 20 | -------------------------------------------------------------------------------- /test/Dockerfile: -------------------------------------------------------------------------------- 1 | FROM debian:buster 2 | 3 | RUN adduser admin && \ 4 | apt-get clean && \ 5 | apt-get update && \ 6 | apt-get install -y --force-yes \ 7 | sudo \ 8 | bats \ 9 | curl \ 10 | nano \ 11 | vim-nox \ 12 | postgresql-client &&\ 13 | rm -rf /var/lib/apt/lists/* /tmp/* /var/tmp/* 14 | 15 | ADD . /home/admin/ 16 | 17 | RUN \ 18 | chown -R admin:admin /home/admin && \ 19 | echo '%admin ALL=(ALL) NOPASSWD:ALL' >> /etc/sudoers 20 | 21 | USER admin 22 | 23 | WORKDIR /home/admin 24 | 25 | ENV LANG=C.UTF-8 \ 26 | TZ=UTC \ 27 | TERM=xterm-256color \ 28 | USER="admin" \ 29 | HOME="/home/admin" 30 | 31 | CMD ["/bin/bash", "/home/admin/test.sh"] 32 | -------------------------------------------------------------------------------- /test/sql/02postfix.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | -- Query used by Postfix 4 | CREATE FUNCTION unit_tests.postfix() 5 | RETURNS test_result AS $$ 6 | DECLARE message test_result; 7 | DECLARE result boolean; 8 | DECLARE passwd_host text; 9 | BEGIN 10 | SELECT host FROM passwd WHERE name = 'testuser' INTO passwd_host; 11 | 12 | SELECT * FROM assert.is_equal(passwd_host, 'testbox.hashbang.sh') INTO message, result; 13 | IF result = false THEN RETURN message; END IF; 14 | 15 | SELECT host FROM passwd WHERE name = 'testadmin' INTO passwd_host; 16 | SELECT * FROM assert.is_equal(passwd_host, 'fo0.hashbang.sh') INTO message, result; 17 | IF result = false THEN RETURN message; END IF; 18 | 19 | RETURN assert.ok('End of test.'); 20 | END $$ LANGUAGE plpgsql; 21 | -------------------------------------------------------------------------------- /test/test.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | set -e 3 | 4 | run() { 5 | normal='\e[0m' 6 | yellow='\e[33m' 7 | printf "${yellow}%s${normal}\n" "$*" >&2 8 | "$@" 9 | } 10 | 11 | if ! command -v psql 2>/dev/null; then 12 | echo "No PostgreSQL utilities in PATH" >&2 13 | exit 1 14 | fi 15 | 16 | [ -n "${PGDATABASE+x}" ] || export PGDATABASE="userdb" 17 | [ -n "${PGHOST+x}" ] || export PGHOST="localhost" 18 | [ -n "${PGPORT+x}" ] || export PGPORT="5432" 19 | 20 | psql="/usr/bin/psql --set ON_ERROR_STOP=1" 21 | 22 | until pg_isready; do 23 | echo "Waiting on PostgreSQL to start..." 24 | sleep 1; 25 | done; 26 | 27 | for file in sql/plpgunit/install/1.install-unit-test.sql sql/*.sql; do 28 | run ${psql} -f "${file}" 29 | done 30 | 31 | run ${psql} -c "\ 32 | BEGIN TRANSACTION; \ 33 | SELECT * FROM unit_tests.begin(); 34 | END TRANSACTION; \ 35 | " 36 | 37 | run bats bats/test.bats 38 | -------------------------------------------------------------------------------- /test/bats/test_helper.bash: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | setup(){ 4 | psql -c "insert into hosts (name,maxusers) values ('test.hashbang.sh','500');"; 5 | } 6 | 7 | teardown(){ 8 | psql -c "delete from passwd;"; 9 | psql -c "delete from hosts;"; 10 | } 11 | 12 | base64_url_encode(){ 13 | data=${1?} 14 | echo -n "${data}" \ 15 | | openssl base64 -e -A \ 16 | | sed 's/\+/-/g' \ 17 | | sed 's/\//_/g' \ 18 | | sed -E 's/=+$//' 19 | } 20 | 21 | jwt_sig(){ 22 | data=${1?} 23 | secret=${2?} 24 | signature=$( \ 25 | echo -n "${data}" \ 26 | | openssl dgst -sha256 -hmac "${secret}" -binary \ 27 | | openssl base64 -e -A \ 28 | | sed 's/\+/-/g' \ 29 | | sed 's/\//_/g' \ 30 | | sed -E 's/=+$//' 31 | ) 32 | echo -n "${data}"."${signature}" 33 | } 34 | 35 | jwt_token(){ 36 | role=${1:-role} 37 | secret=${2:-a_test_only_postgrest_jwt_secret} 38 | header="$(base64_url_encode '{"alg":"HS256"}')" 39 | payload="$(base64_url_encode '{"role":"'"${role}"'"}')" 40 | echo -n "$(jwt_sig "${header}.${payload}" "${secret}")" 41 | } 42 | -------------------------------------------------------------------------------- /LICENSE.md: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2020-2021 Hashbang Inc. 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /schema/sql/metrics.sql: -------------------------------------------------------------------------------- 1 | -- label_value can be any sequence of UTF-8 characters, but the backslash (\), 2 | -- double-quote ("), and line feed (\n) characters have to be escaped as \\, 3 | -- \", and \n, respectively. 4 | create function escape_label(text) returns text 5 | language sql as $$ 6 | select regexp_replace($1, E'[\\"\n]', '\\\&', 'g'); 7 | $$ 8 | immutable; 9 | 10 | create view v1.metrics as 11 | select 'hosts_count' as metric, count(*) as "value" from hosts 12 | union select 'passwd_count' as metric, count(*) as "value" from passwd 13 | union select 'passwd_shell_count{shell="' || escape_label(data->>'shell') || '"}' as metric, count(*) as "value" from passwd 14 | group by data->>'shell' 15 | union select 'passwd_host_count{host="' || escape_label(host) || '"}' as metric, count(*) as "value" from passwd 16 | group by host 17 | union select 'groups_count{group="' || escape_label("group".name) || '"}' as metric, count(*) as "value" from aux_groups 18 | join "group" on "group".gid = aux_groups.gid 19 | group by "group".name; 20 | alter view v1."metrics" owner to api; 21 | grant select on table v1."metrics" to "api-anon"; 22 | 23 | create function v1.metrics() returns text 24 | language sql as $$ 25 | select string_agg(metric || ' ' || "value" || ' ' || (extract(epoch from current_timestamp) * 1000)::bigint, E'\n') from v1.metrics; 26 | $$ 27 | stable; 28 | comment on function v1.metrics() is 29 | $$Metrics for ingestion by Prometheus$$; 30 | -------------------------------------------------------------------------------- /schema/json/data_host.yml: -------------------------------------------------------------------------------- 1 | $schema: http://json-schema.org/schema# 2 | title: "#! userdb -- Schema for host records auxiliary data" 3 | type: object 4 | properties: 5 | location: 6 | type: string 7 | description: "Server's location" 8 | 9 | coordinates: 10 | description: "Server's GPS coordinates" 11 | properties: 12 | lat: 13 | type: number 14 | minimum: -90 15 | maximum: 90 16 | lon: 17 | type: number 18 | minimum: -180 19 | maximum: 180 20 | required: [lat, lon] 21 | 22 | inet: 23 | description: "Server's IP address(es)" 24 | minItems: 1 25 | items: 26 | type: string 27 | oneOf: 28 | - pattern: ^((25[0-5]|2[0-4][0-9]|[01]?[0-9][0-9]?)\.){3}(25[0-5]|2[0-4][0-9]|[01]?[0-9][0-9]?)$ 29 | # IPv4 30 | - pattern: ^(([0-9a-fA-F]{1,4}:){7,7}[0-9a-fA-F]{1,4}|([0-9a-fA-F]{1,4}:){1,7}:|([0-9a-fA-F]{1,4}:){1,6}:[0-9a-fA-F]{1,4}|([0-9a-fA-F]{1,4}:){1,5}(:[0-9a-fA-F]{1,4}){1,2}|([0-9a-fA-F]{1,4}:){1,4}(:[0-9a-fA-F]{1,4}){1,3}|([0-9a-fA-F]{1,4}:){1,3}(:[0-9a-fA-F]{1,4}){1,4}|([0-9a-fA-F]{1,4}:){1,2}(:[0-9a-fA-F]{1,4}){1,5}|[0-9a-fA-F]{1,4}:((:[0-9a-fA-F]{1,4}){1,6})|:((:[0-9a-fA-F]{1,4}){1,7}|:)|fe80:(:[0-9a-fA-F]{0,4}){0,4}%[0-9a-zA-Z]{1,}|::(ffff(:0{1,4}){0,1}:){0,1}((25[0-5]|(2[0-4]|1{0,1}[0-9]){0,1}[0-9])\.){3,3}(25[0-5]|(2[0-4]|1{0,1}[0-9]){0,1}[0-9])|([0-9a-fA-F]{1,4}:){1,4}:((25[0-5]|(2[0-4]|1{0,1}[0-9]){0,1}[0-9])\.){3,3}(25[0-5]|(2[0-4]|1{0,1}[0-9]){0,1}[0-9]))$ 31 | # IPv6. I'm very sorry 32 | uniqueItems: True 33 | 34 | required: [location, coordinates, inet] 35 | -------------------------------------------------------------------------------- /schema/sql/reserved.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | -- An helper for bulk-importing the data 3 | create temp table tmp_table ( 4 | "name" text unique not null 5 | ); 6 | 7 | create function pg_temp.import_reserved() returns void 8 | language plpgsql as $$ 9 | begin 10 | insert into reserved_usernames 11 | select * 12 | from tmp_table 13 | where name ~ '^[a-z][a-z0-9]{0,30}$' 14 | and not exists(select 1 from reserved_usernames 15 | where reserved_usernames.name = tmp_table.name); 16 | truncate tmp_table; 17 | end$$; 18 | 19 | -- reserve names in ldpreload.com, RFC2142, and common conventions 20 | insert into tmp_table (name) values 21 | ('abuse'), 22 | ('admin'), 23 | ('administrator'), 24 | ('autoconfig'), 25 | ('broadcasthost'), 26 | ('ftp'), 27 | ('hostmaster'), 28 | ('imap'), 29 | ('info'), 30 | ('is'), 31 | ('isatap'), 32 | ('it'), 33 | ('localdomain'), 34 | ('localhost'), 35 | ('mail'), 36 | ('mailer-daemon'), 37 | ('marketing'), 38 | ('mis'), 39 | ('news'), 40 | ('nobody'), 41 | ('noc'), 42 | ('noreply'), 43 | ('pop'), 44 | ('pop3'), 45 | ('postmaster'), 46 | ('root'), 47 | ('sales'), 48 | ('security'), 49 | ('smtp'), 50 | ('ssladmin'), 51 | ('ssladministrator'), 52 | ('sslwebmaster'), 53 | ('support'), 54 | ('sysadmin'), 55 | ('team'), 56 | ('usenet'), 57 | ('uucp'), 58 | ('webmaster'), 59 | ('wpad'), 60 | ('www'); 61 | 62 | select pg_temp.import_reserved(); 63 | -------------------------------------------------------------------------------- /test/sql/03stats.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | -- Check the host statistics view 4 | 5 | CREATE FUNCTION unit_tests.check_host_stats() 6 | RETURNS test_result AS $$ 7 | DECLARE message test_result; 8 | DECLARE result boolean; 9 | 10 | DECLARE host_data jsonb; 11 | DECLARE host_maxusers integer; 12 | DECLARE host_name text; 13 | DECLARE view_data jsonb; 14 | DECLARE view_maxusers integer; 15 | DECLARE view_name text; 16 | DECLARE view_users integer; 17 | DECLARE count_users integer; 18 | DECLARE h varchar; 19 | BEGIN 20 | FOR h in (SELECT name FROM hosts) 21 | LOOP 22 | SELECT * FROM hosts WHERE name = h 23 | INTO host_name, host_maxusers, host_data; 24 | 25 | SELECT * FROM host_statistics WHERE name = h 26 | INTO view_name, view_users, view_maxusers, view_data; 27 | 28 | SELECT COUNT(*) FROM passwd WHERE host = h 29 | INTO count_users; 30 | 31 | SELECT * FROM assert.is_equal(host_data, view_data) INTO message, result; 32 | IF result = false THEN RETURN message; END IF; 33 | 34 | SELECT * FROM assert.is_equal(host_maxusers, view_maxusers) INTO message, result; 35 | IF result = false THEN RETURN message; END IF; 36 | 37 | SELECT * FROM assert.is_equal(host_name, view_name) INTO message, result; 38 | IF result = false THEN RETURN message; END IF; 39 | 40 | SELECT * FROM assert.is_equal(view_users, count_users) INTO message, result; 41 | IF result = false THEN RETURN message; END IF; 42 | END LOOP; 43 | RETURN assert.ok('End of test.'); 44 | END $$ LANGUAGE plpgsql; 45 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | include docker.mk 2 | 3 | PG_DUMP ?= pg_dump 4 | PSQL ?= psql 5 | 6 | .PHONY: help 7 | help: 8 | @echo "build - compile/order all sql files to out directory" 9 | @echo "fetch - fetch submodules" 10 | @echo "fetch-latest - fetch submodules at latest upstream master refs" 11 | @echo "test - run tests with in-place PostgreSQL" 12 | @echo "install - Setup schemas on local system PostgreSQL" 13 | @echo "clean - Delete generated files" 14 | @echo "develop - Load schema into temp db and launch shell" 15 | @echo "" 16 | @$(MAKE) -s docker-help 17 | 18 | out/json-schemas.sql: schema/sql/json-schemas.sql 19 | mkdir -p $(@D) 20 | ./scripts/build schema < "$<" > "$@" 21 | 22 | .PHONY: build 23 | build: out/json-schemas.sql 24 | 25 | schema/ext/json-schema/%: 26 | git submodule update --init --recursive $(@D) 27 | 28 | test/sql/plpgunit/%: 29 | git submodule update --init --recursive $(@D) 30 | 31 | .PHONY: fetch 32 | fetch: schema/ext/json-schema/ test/sql/plpgunit/ 33 | 34 | .PHONY: fetch-latest 35 | fetch-latest: 36 | git submodule foreach 'git checkout master && git pull' 37 | 38 | SCHEMA_FILES := \ 39 | schema/sql/schema.sql \ 40 | schema/sql/access.sql \ 41 | schema/sql/api.sql \ 42 | schema/sql/metrics.sql \ 43 | schema/sql/nss.sql \ 44 | schema/sql/reserved.sql \ 45 | schema/sql/stats.sql \ 46 | schema/ext/json-schema/postgres-json-schema--0.1.0.sql \ 47 | out/json-schemas.sql 48 | 49 | .PHONY: install 50 | install: $(SCHEMA_FILES) 51 | $(PSQL) -v ON_ERROR_STOP=1 $(foreach file,$(SCHEMA_FILES),-f $(file)); 52 | 53 | schema-dump.psql: 54 | $(PG_DUMP) -s > $@ 55 | 56 | .PHONY: test 57 | test: \ 58 | docker-test-build \ 59 | docker-restart \ 60 | docker-test \ 61 | docker-stop 62 | 63 | .PHONY: test-shell 64 | test-shell: \ 65 | docker-test-build \ 66 | docker-restart \ 67 | docker-test-shell \ 68 | docker-stop 69 | 70 | .PHONY: clean 71 | clean: 72 | rm -rf out 73 | -------------------------------------------------------------------------------- /schema/json/api_schema.yml: -------------------------------------------------------------------------------- 1 | definitions: 2 | username: 3 | type: string 4 | pattern: "^[a-z][a-z0-9]{0,30}$" 5 | 6 | hostname: 7 | type: string 8 | pattern: "^([a-z0-9]+\.)+hashbang\.sh$" 9 | 10 | captcha: 11 | challenge: 12 | description: CAPTCHA descriptor 13 | type: object 14 | required: [challenge, token] 15 | properties: 16 | challenge: 17 | type: string 18 | description: Human-readable challenge 19 | token: 20 | type: string 21 | description: Opaque challenge descriptor 22 | 23 | response: 24 | description: CAPTCHA solution 25 | type: object 26 | required: [token, answer] 27 | properties: 28 | token: 29 | type: string 30 | description: Opaque challenge descriptor 31 | answer: 32 | type: string 33 | description: Solution of the text-based CAPTCHA 34 | 35 | 36 | links: 37 | - description: Request a one-time CAPTCHA 38 | href: /captcha 39 | method: POST 40 | targetSchema: {$ref: "#/definitions/captcha/challenge"} 41 | schema: 42 | type: object 43 | required: [user] 44 | properties: 45 | user: {$ref: "#/definitions/username"} 46 | 47 | - description: Create a new user 48 | href: /user/create 49 | method: POST 50 | schema: 51 | type: object 52 | required: [user, host] 53 | properties: 54 | user: {$ref: "#/definitions/username"} 55 | host: {$ref: "#/definitions/hostname"} 56 | allOf: 57 | - $ref: "#/definitions/captcha/response" 58 | - $ref: "data_user.yml" 59 | 60 | - description: Request server infos 61 | href: /server/stats 62 | method: GET 63 | targetSchema: 64 | type: object 65 | patternProperties: 66 | "^([a-z0-9]+\.)+hashbang\.sh$": 67 | type: object 68 | required: [currentUsers, maxUsers] 69 | properties: 70 | currentUsers: 71 | type: integer 72 | minimum: 0 73 | maxUsers: 74 | type: integer 75 | minimum: 0 76 | # Include the host_data schema 77 | allOf: [{$ref: "data_host.yaml"}] 78 | -------------------------------------------------------------------------------- /schema/sql/nss.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | create user "nss_pgsql"; 4 | comment on role "nss_pgsql" is 5 | $$Intended for nss-pgsql NSS module$$; 6 | alter role "nss_pgsql" with login; 7 | grant select on 8 | public."passwd", 9 | public."aux_groups", 10 | public."group" 11 | to "nss_pgsql"; 12 | 13 | create schema nss_pgsql; 14 | 15 | create view nss_pgsql.groupmember as 16 | select 17 | name as username, 18 | uid as gid 19 | from public.passwd 20 | union 21 | select 22 | name as usernames, 23 | aux_groups.gid as gid 24 | from public.passwd inner join public.aux_groups 25 | on (passwd.uid = aux_groups.uid); 26 | 27 | create view nss_pgsql.passwd as 28 | select 29 | name, 30 | 'x' as "passwd", 31 | data->>'name' as "gecos", 32 | '/home/' || name as "dir", 33 | data->>'shell' as "shell", 34 | uid, 35 | uid as gid 36 | from public.passwd; 37 | grant select on nss_pgsql.passwd to nss_pgsql; 38 | 39 | create view nss_pgsql."group" as 40 | select 41 | passwd.name, 42 | 'x' as passwd, 43 | passwd.uid as gid, 44 | ARRAY[passwd.name] as members 45 | from public.passwd 46 | union 47 | select 48 | name, 49 | 'x' as passwd, 50 | gid, 51 | ARRAY( 52 | select passwd.name 53 | from public.passwd inner join public.aux_groups 54 | on (passwd.uid = aux_groups.uid and aux_groups.gid = "group".gid) 55 | ) as members 56 | from public."group"; 57 | grant select on nss_pgsql."group" to nss_pgsql; 58 | 59 | create view nss_pgsql.groups_dyn as 60 | select 61 | name, 62 | gid 63 | from public.aux_groups inner join public.passwd 64 | on (aux_groups.uid = passwd.uid); 65 | grant select on nss_pgsql.groups_dyn to nss_pgsql; 66 | 67 | create view nss_pgsql.shadow as 68 | select 69 | name, 70 | '!' as passwd, 71 | 18086 as lstchg, 72 | 0 as min, 73 | 99999 as max, 74 | 0 as warn, 75 | 99999 as inact, 76 | 0 as expire, 77 | 0 as flag 78 | from public.passwd; 79 | grant select on nss_pgsql.shadow to nss_pgsql; 80 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # #! User Database # 2 | 3 | 4 | 5 | [![TravisCI][travis-badge]][travis-status] 6 | [![IRC][irc-badge]][irc] 7 | [![PostgreSQL][postgresql-badge]][postgresql] 8 | [![License][license-badge]][license-status] 9 | 10 | [postgresql-badge]: https://img.shields.io/badge/postgresql-9.4-blue.svg 11 | [postgresql]: https://www.postgresql.org/docs/9.4/static/index.html 12 | [irc-badge]: https://img.shields.io/badge/irc-%23%21%20on%20hashbang-blue.svg 13 | [irc]: https://webirc.hashbang.sh/ 14 | [travis-badge]: https://travis-ci.org/hashbang/userdb.svg?branch=master 15 | [travis-status]: https://travis-ci.org/hashbang/userdb 16 | [license-badge]: https://img.shields.io/github/license/hashbang/userdb.svg 17 | [license-status]: LICENSE.md 18 | 19 | ## About ## 20 | 21 | This repo contains the schema, design and requirements for our 22 | PostgreSQL-based user database. 23 | 24 | ## Requirements ## 25 | 26 | - PostgreSQL 9.4+ 27 | 28 | ## Installation ## 29 | 30 | This will setup userdb as the `userdb` database on a local PostgreSQL. 31 | 32 | ``` 33 | make install 34 | ``` 35 | 36 | ## Development ## 37 | 38 | Drops you into a fresh PostgreSQL shell with latest schema: 39 | 40 | ``` 41 | make develop 42 | ``` 43 | 44 | ## Testing ## 45 | 46 | ``` 47 | make test 48 | ``` 49 | 50 | ## Contribution ## 51 | 52 | Please consider the following when submitting contributions: 53 | 54 | - Observe the [Design Requirements]. 55 | - Update the [Design Documentation] whenever designing new features 56 | or modifying their implementation. 57 | - Follow the [SQL Style Guide]. 58 | - Use Pull Requests for all changes. 59 | - Pull Requests are only merged when all tests pass **when merged with 60 | master**. This is [the “not rocket science” rule] of software. 61 | - When designing new features, add tests for them right away. 62 | 63 | Feel free to reach out to us with ideas or to get help contributing. We 64 | are totally happy with something taking longer to do, if you learn 65 | something in the process. It is the reason #! exists. 66 | 67 | [Design Requirements]: REQUIREMENTS.md 68 | [Design Documentation]: DESIGN.md 69 | [SQL Style Guide]: STYLEGUIDE.md 70 | [the “not rocket science” rule]: https://graydon2.dreamwidth.org/1597.html 71 | 72 | ## Notes ## 73 | 74 | Questions/Comments? 75 | 76 | Please learn and reach out to us via the following: 77 | 78 | - IRC: [ircs://irc.hashbang.sh:6697/#!](https://chat.hashbang.sh) 79 | - E-Mail: [team@hashbang.sh](mailto:team@hashbang.sh) 80 | - Issue Tracker: 81 | - Documentation: 82 | - Shell Services: 83 | -------------------------------------------------------------------------------- /test/bats/test.bats: -------------------------------------------------------------------------------- 1 | load test_helper 2 | 3 | 4 | @test "Can connect to userdb PostgreSQL" { 5 | sleep 1 6 | run pg_isready -U postgres -h userdb; 7 | [ "$status" -eq 0 ] 8 | echo "$output" | grep "accepting connections" 9 | } 10 | 11 | @test "Can connect to userdb PostgREST" { 12 | run curl http://userdb-postgrest:3000 13 | [ "$status" -eq 0 ] 14 | echo "$output" | grep "swagger" 15 | } 16 | 17 | @test "Cannot create user anonymously via PostgREST" { 18 | run curl http://userdb-postgrest:3000/passwd \ 19 | -H "Content-Type:application/json" \ 20 | -X POST \ 21 | --data-binary @- <<-EOF 22 | { 23 | "name": "testuser", 24 | "host": "test.hashbang.sh", 25 | "data": { 26 | "shell": "/bin/bash", 27 | "ssh_keys": ["$(cat bats/keys/id_ed25519.pub)"] 28 | } 29 | } 30 | EOF 31 | [ "$status" -eq 0 ] 32 | echo "$output" | grep "permission denied" 33 | } 34 | 35 | @test "Can not create user with invalid host and valid auth via PostgREST" { 36 | 37 | run curl http://userdb-postgrest:3000/passwd \ 38 | -H "Content-Type: application/json" \ 39 | -H "Authorization: Bearer $(jwt_token 'api-user-create')" \ 40 | -X POST \ 41 | --data-binary @- <<-EOF 42 | { 43 | "name": "testuser42", 44 | "host": "invalidbox.hashbang.sh", 45 | "data": { 46 | "shell": "/bin/bash", 47 | "ssh_keys": ["$(cat bats/keys/id_ed25519.pub)"] 48 | } 49 | } 50 | EOF 51 | [ "$status" -eq 0 ] 52 | echo "$output" | grep "violates foreign key constraint" 53 | } 54 | 55 | @test "Can create user with a valid host and valid auth via PostgREST" { 56 | 57 | run curl http://userdb-postgrest:3000/passwd \ 58 | -H "Content-Type: application/json" \ 59 | -H "Authorization: Bearer $(jwt_token 'api-user-create')" \ 60 | -X POST \ 61 | --data-binary @- <<-EOF 62 | { 63 | "name": "testuser42", 64 | "host": "test.hashbang.sh", 65 | "data": { 66 | "shell": "/bin/bash", 67 | "ssh_keys": ["$(cat bats/keys/id_ed25519.pub)"] 68 | } 69 | } 70 | EOF 71 | [ "$status" -eq 0 ] 72 | 73 | run curl http://userdb-postgrest:3000/passwd?name=eq.testuser42 74 | echo "$output" | grep "testuser42" 75 | } 76 | 77 | @test "Can create user with a valid host and and SSH key via PostgREST" { 78 | 79 | run curl http://userdb-postgrest:3000/signup \ 80 | -H "Content-Type: application/json" \ 81 | -H "Authorization: Bearer $(jwt_token 'api-user-create')" \ 82 | -X POST \ 83 | --data-binary @- <<-EOF 84 | { 85 | "name": "testuser43", 86 | "host": "test.hashbang.sh", 87 | "shell": "/bin/zsh", 88 | "keys": ["$(cat bats/keys/id_ed25519.pub)"] 89 | } 90 | EOF 91 | [ "$status" -eq 0 ] 92 | 93 | run curl http://userdb-postgrest:3000/passwd?name=eq.testuser43 94 | echo "$output" | grep "testuser43" 95 | } 96 | -------------------------------------------------------------------------------- /test/sql/06collisions.sql: -------------------------------------------------------------------------------- 1 | -- Negative tests for `check_hosts_for_hosts`, `check_invalid_name_for_passwd`, 2 | -- `check_invalid_name_for_group`, `check_reserved_username`, and 3 | -- `check_taken_username` 4 | 5 | create function unit_tests.check_hosts_for_hosts() 6 | returns test_result as $$ 7 | begin 8 | insert into hosts (name, maxusers) values ('06invalid.hashbang.sh', 1); 9 | insert into passwd (name, host) values ('ryan', '06invalid.hashbang.sh'); 10 | begin 11 | update hosts set maxusers = 0 where name = '06invalid.hashbang.sh'; 12 | return assert.fail('Successfully changed maxusers to be less than users'); 13 | exception 14 | when foreign_key_violation then 15 | return assert.ok('End of test.'); 16 | end; 17 | end $$ language plpgsql; 18 | 19 | create function unit_tests.check_invalid_name_for_passwd() 20 | returns test_result as $$ 21 | begin 22 | insert into hosts (name, maxusers) values ('061invalid.hashbang.sh', 1); 23 | insert into "group" (gid, name) values (600, 'grouptest06'); 24 | begin 25 | insert into passwd (name, host) values ('grouptest06', '061invalid.hashbang.sh'); 26 | return assert.fail('Successfully added group name collision from user'); 27 | exception 28 | when check_violation then 29 | return assert.ok('End of test.'); 30 | end; 31 | end $$ language plpgsql; 32 | 33 | create function unit_tests.check_invalid_name_for_group() 34 | returns test_result as $$ 35 | begin 36 | insert into hosts (name, maxusers) values ('062invalid.hashbang.sh', 1); 37 | insert into passwd (name, host) values ('passwdtest06', '062invalid.hashbang.sh'); 38 | begin 39 | insert into "group" (gid, name) values (601, 'passwdtest06'); 40 | return assert.fail('Successfully added passwd name collision from group'); 41 | exception 42 | when check_violation then 43 | return assert.ok('End of test.'); 44 | end; 45 | end $$ language plpgsql; 46 | 47 | create function unit_tests.check_reserved_username() 48 | returns test_result as $$ 49 | begin 50 | insert into reserved_usernames (name) values ('user063'); 51 | insert into hosts (name, maxusers) values ('063invalid.hashbang.sh', 1); 52 | begin 53 | insert into passwd (name, host) values ('user063', '063invalid.hashbang.sh'); 54 | return assert.fail('Successfully registered reserved name'); 55 | exception 56 | when check_violation then 57 | return assert.ok('End of test.'); 58 | end; 59 | end $$ language plpgsql; 60 | 61 | create function unit_tests.check_taken_username() 62 | returns test_result as $$ 63 | begin 64 | insert into hosts (name, maxusers) values ('064invalid.hashbang.sh', 1); 65 | insert into passwd (name, host) values ('user064', '064invalid.hashbang.sh'); 66 | begin 67 | insert into reserved_usernames (name) values ('user064'); 68 | return assert.fail('Successfully reserved a registered name'); 69 | exception 70 | when check_violation then 71 | return assert.ok('End of test.'); 72 | end; 73 | end $$ language plpgsql; 74 | -------------------------------------------------------------------------------- /docs/REQUIREMENTS.md: -------------------------------------------------------------------------------- 1 | # #! User Database -- Requirements # 2 | 3 | See 4 | 5 | # About 6 | 7 | This document describes the requirements for our user database. 8 | Understanding the design goals is an important part of understanding the 9 | engineering trade-offs made there. 10 | 11 | # Data 12 | 13 | A user has several kinds of associated data: 14 | - relational data, which might be involved in `WHERE` conditions or `JOIN`s: 15 | `uid`, `gid`, `username` and `host`; 16 | - non-relational data: SSH keys, full name, preferred shell, ... 17 | - users may add additional data without specific cooperation from the #! admins, 18 | facilitating the construction of new, non-core services 19 | (finger, GPG key discovery, ...) 20 | 21 | Each user has a primary group, that shares the same id and name. 22 | 23 | Administrators may define auxiliary groups (such as `adm` or `sudo`) 24 | and any user can belong to any number of auxiliary groups. 25 | 26 | Lastly, the DB needs to keep track of per-server information, namely its 27 | `hostname`, IP address and location. This is in part intended for consumption 28 | by the [stats API](https://hashbang.sh/server/stats). 29 | 30 | 31 | # Properties 32 | 33 | ## Immediate 34 | 35 | These requirements **must** be achieved before deployment: 36 | 37 | - Availability 38 | - Users do not lose access to the shell servers if part of the infra goes down. 39 | - Loss of any part of the infrastructure is recoverable with limited data loss. 40 | 41 | - Consistency 42 | - Changes in the userdb must occur in some coherent ordering, and reads must 43 | respect it. In particular, it is not possible to observe partial updates. 44 | - The data held in the database must be internally coherent: for instance, 45 | a user may not belong to a group that does not exist. 46 | 47 | - Maintainability 48 | - Avoid custom implementations of standard modules (NSS, PAM, ...) 49 | whenever possible and reasonable. 50 | - Minimize the amount of components that have knowledge of the database 51 | implementation, and make the others rely on a more abstract API. 52 | 53 | - Privilege separation 54 | - All data must be non-readable, non-writeable, by default. 55 | - Each service/component must have the least possible access (read, write, ...), 56 | restricted to the data it needs to manipulate. 57 | 58 | - No-downtime deployment 59 | - The initial deployment must be achievable without disrupting core services 60 | (shell access, IRC, ...), and must minimize the disruption to auxiliary 61 | services (mail, ...). 62 | - Any later update/maintainance of the system must be achievable without 63 | disrupting read-availability of the user DB. Having a short window where 64 | users cannot edit their records or signup is acceptable. 65 | 66 | 67 | ## Long-term 68 | 69 | These requirements **must** be *achievable*: 70 | 71 | - Privilege separation 72 | - Unprivileged `hashbangctl` can only modify the user's own data 73 | - Remote service authentication: local (shell) users should be able to authenticate 74 | transparently and securely to remote (#!) services (SMTP, IRC, ...). 75 | 76 | 77 | # Services 78 | 79 | The following services need to interact with the user DB: 80 | - OpenSSH, through `AuthorizedKeysCommand`; 81 | - `mail.hashbang.sh` needs to extract host info for mail routing; 82 | - `hashbang.sh` needs to extract statistics; 83 | - user creation. 84 | -------------------------------------------------------------------------------- /docker.mk: -------------------------------------------------------------------------------- 1 | NAMESPACE ?= userdb 2 | POSTGRES_USER ?= postgres 3 | POSTGRES_DB ?= postgres 4 | IMAGE_POSTGRES ?= postgres:latest 5 | IMAGE_POSTGREST ?= postgrest/postgrest:v7.0.1@sha256:2a10713acc388f9a64320443e949eb87a0424ab280e68c4ed4a6d0653c001586 6 | 7 | .PHONY: docker-help 8 | docker-help: 9 | @echo "docker-start - Start service containers" 10 | @echo "docker-stop - Stop service containers" 11 | @echo "docker-test - run tests from a predictable test container" 12 | @echo "docker-test-build - build test container" 13 | @echo "docker-test-shell - run shell from a test container" 14 | @echo "docker-schema-dump - dump the schema of the database running in docker" 15 | 16 | .PHONY: docker-restart 17 | docker-restart: docker-stop docker-start 18 | 19 | .PHONY: docker-start 20 | docker-start: 21 | docker network inspect $(NAMESPACE) \ 22 | || docker network create $(NAMESPACE) 23 | # Start database 24 | docker run \ 25 | --detach=true \ 26 | --name=$(NAMESPACE)-postgres \ 27 | --network=$(NAMESPACE) \ 28 | --env POSTGRES_DB=$(POSTGRES_DB) \ 29 | --env POSTGRES_USER=$(POSTGRES_USER) \ 30 | --env POSTGRES_PASSWORD=test_password \ 31 | -p 5432:5432 \ 32 | $(IMAGE_POSTGRES) 33 | ## Wait for database to be up 34 | docker run \ 35 | --rm \ 36 | --network=$(NAMESPACE) \ 37 | --env PGHOST=$(NAMESPACE)-postgres \ 38 | --env PGDATABASE=$(POSTGRES_DB) \ 39 | --env PGUSER=$(POSTGRES_USER) \ 40 | --env PGPASSWORD=test_password \ 41 | $(IMAGE_POSTGRES) sh -c 'until pg_isready; do sleep 1; done' 42 | # Load schema 43 | $(MAKE) -f Makefile \ 44 | PSQL="docker run \ 45 | --rm \ 46 | --network=$(NAMESPACE) \ 47 | --env PGHOST=$(NAMESPACE)-postgres \ 48 | --env PGDATABASE=$(POSTGRES_DB) \ 49 | --env PGUSER=$(POSTGRES_USER) \ 50 | --env PGPASSWORD=test_password \ 51 | -v `pwd`:`pwd` \ 52 | -w `pwd` \ 53 | $(IMAGE_POSTGRES) psql" \ 54 | install 55 | # Start web API 56 | docker run \ 57 | --rm \ 58 | --detach=true \ 59 | --name $(NAMESPACE)-postgrest \ 60 | --network=$(NAMESPACE) \ 61 | --env PGRST_DB_URI="postgres://$(POSTGRES_USER):test_password@$(NAMESPACE)-postgres/$(POSTGRES_DB)" \ 62 | --env PGRST_DB_SCHEMA="v1" \ 63 | --env PGRST_DB_ANON_ROLE="api-anon" \ 64 | --env PGRST_JWT_SECRET="a_test_only_postgrest_jwt_secret" \ 65 | -p 3000:3000 \ 66 | $(IMAGE_POSTGREST) 67 | 68 | .PHONY: docker-stop 69 | docker-stop: 70 | docker inspect -f '{{.State.Running}}' $(NAMESPACE)-postgres 2>/dev/null \ 71 | && docker rm -f $(NAMESPACE)-postgres || true 72 | docker inspect -f '{{.State.Running}}' $(NAMESPACE)-postgrest 2>/dev/null \ 73 | && docker rm -f $(NAMESPACE)-postgrest || true 74 | 75 | .PHONY: docker-log 76 | docker-log: 77 | docker logs -f $(NAMESPACE)-postgres 78 | 79 | .PHONY: docker-schema-dump 80 | docker-schema-dump: 81 | $(MAKE) -f Makefile \ 82 | PG_DUMP="docker run \ 83 | --rm \ 84 | --network=$(NAMESPACE) \ 85 | --env PGHOST=$(NAMESPACE)-postgres \ 86 | --env PGDATABASE=$(POSTGRES_DB) \ 87 | --env PGUSER=$(POSTGRES_USER) \ 88 | --env PGPASSWORD=test_password \ 89 | $(IMAGE_POSTGRES) pg_dump" \ 90 | schema-dump.psql 91 | 92 | .PHONY: docker-test 93 | docker-test: docker-stop docker-start docker-test-build 94 | docker run \ 95 | -it \ 96 | --rm \ 97 | --hostname=$(NAMESPACE)-test \ 98 | --name $(NAMESPACE)-test \ 99 | --network=$(NAMESPACE) \ 100 | --env PGHOST=$(NAMESPACE)-postgres \ 101 | --env PGDATABASE=$(POSTGRES_DB) \ 102 | --env PGUSER=$(POSTGRES_USER) \ 103 | --env PGPASSWORD=test_password \ 104 | local/$(NAMESPACE)-test 105 | 106 | .PHONY: docker-test-shell 107 | docker-test-shell: docker-stop docker-start docker-test-build 108 | docker run \ 109 | --rm \ 110 | -it \ 111 | --hostname=$(NAMESPACE)-test-shell \ 112 | --name $(NAMESPACE)-test-shell \ 113 | --network=$(NAMESPACE) \ 114 | --env PGHOST=$(NAMESPACE)-postgres \ 115 | --env PGDATABASE=$(POSTGRES_DB) \ 116 | --env PGUSER=$(POSTGRES_USER) \ 117 | --env PGPASSWORD=test_password \ 118 | local/$(NAMESPACE)-test \ 119 | bash 120 | 121 | .PHONY: docker-test-build 122 | docker-test-build: 123 | docker build -t local/$(NAMESPACE)-test test/ 124 | -------------------------------------------------------------------------------- /test/sql/00basic.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | -- Basic operations populating the database. 4 | 5 | CREATE FUNCTION unit_tests.create_hosts() 6 | RETURNS test_result AS $$ 7 | DECLARE message test_result; 8 | DECLARE result boolean; 9 | DECLARE host_name text; 10 | BEGIN 11 | insert into hosts (name, data) values ('testbox.hashbang.sh', '{ 12 | "inet": ["192.0.2.4"], 13 | "coordinates": { 14 | "lat": 0, 15 | "lon": 0 16 | }, 17 | "location": "NULL island", 18 | "maxUsers": 1000 19 | }'::jsonb) returning name INTO host_name; 20 | insert into hosts (name, data) values ('fo0.hashbang.sh', '{ 21 | "inet": ["192.0.2.6"], 22 | "coordinates": { 23 | "lat": 1, 24 | "lon": 2 25 | }, 26 | "location": "Disk Dr.", 27 | "maxUsers": 1000 28 | }'::jsonb); 29 | SELECT * FROM assert.is_equal(host_name,'testbox.hashbang.sh') INTO message, result; 30 | IF result = false THEN RETURN message; END IF; 31 | 32 | RETURN assert.ok('End of test.'); 33 | END $$ LANGUAGE plpgsql; 34 | 35 | 36 | CREATE FUNCTION unit_tests.create_groups() 37 | RETURNS test_result AS $$ 38 | DECLARE message test_result; 39 | DECLARE result boolean; 40 | DECLARE group_gid integer; 41 | BEGIN 42 | insert into "group" (gid, name) values (27, 'sudo') RETURNING gid INTO group_gid; 43 | SELECT * FROM assert.is_equal(group_gid, 27) INTO message, result; 44 | IF result = false THEN RETURN message; END IF; 45 | 46 | insert into "group" (gid, name) values (4, 'adm') RETURNING gid INTO group_gid; 47 | SELECT * FROM assert.is_equal(group_gid, 4) INTO message, result; 48 | IF result = false THEN RETURN message; END IF; 49 | 50 | RETURN assert.ok('End of test.'); 51 | END $$ LANGUAGE plpgsql; 52 | 53 | 54 | CREATE FUNCTION unit_tests.create_users() 55 | RETURNS test_result AS $$ 56 | DECLARE testbox integer; 57 | DECLARE message test_result; 58 | DECLARE result boolean; 59 | DECLARE passwd_name text; 60 | BEGIN 61 | insert into passwd (name, host, shell) values ('testuser', 'testbox.hashbang.sh', '/usr/sbin/nologin'); 62 | insert into passwd (name, host, shell) values ('testuser2', 'testbox.hashbang.sh', '/bin/sh') returning name INTO passwd_name; 63 | SELECT * FROM assert.is_equal(passwd_name,'testuser2') INTO message, result; 64 | IF result = false THEN RETURN message; END IF; 65 | 66 | RETURN assert.ok('End of test.'); 67 | END $$ LANGUAGE plpgsql; 68 | 69 | CREATE FUNCTION unit_tests.add_user_to_group() 70 | RETURNS test_result AS $$ 71 | DECLARE testbox integer; 72 | DECLARE user_id integer; 73 | DECLARE message test_result; 74 | DECLARE result boolean; 75 | DECLARE passwd_name text; 76 | BEGIN 77 | insert into passwd (name, host, shell, data) 78 | values ('testadmin', 'fo0.hashbang.sh', '/bin/zsh', '{"name": "Just an admin."}') 79 | RETURNING uid INTO user_id; 80 | 81 | insert into aux_groups (uid, gid) values (user_id, 27); -- 27 is sudo 82 | insert into aux_groups (uid, gid) values (user_id, 4); -- 4 is adm 83 | 84 | SELECT "name" 85 | FROM passwd JOIN aux_groups 86 | USING (uid) WHERE (gid = 27) 87 | INTO passwd_name; 88 | SELECT * FROM assert.is_equal(passwd_name,'testadmin') INTO message, result; 89 | IF result = false THEN RETURN message; END IF; 90 | 91 | RETURN assert.ok('End of test.'); 92 | END $$ LANGUAGE plpgsql; 93 | 94 | CREATE FUNCTION unit_tests.add_public_key_to_user() 95 | RETURNS test_result AS $$ 96 | DECLARE testbox integer; 97 | DECLARE key_fingerprint text; 98 | DECLARE user_id integer; 99 | DECLARE message test_result; 100 | DECLARE result boolean; 101 | DECLARE passwd_name text; 102 | BEGIN 103 | select "uid" from passwd where name = 'testuser' into user_id; 104 | 105 | insert into ssh_public_key (type, key, comment, uid) 106 | values ( 107 | 'ssh-ed25519', 108 | 'AAAAC3NzaC1lZDI1NTE5AAAAIKCXEbRyTwfQLhxpt9TMlpZSSGXNwnGmFdpV+yiljd4g', 109 | 'Some key', 110 | user_id 111 | ); 112 | 113 | SELECT "fingerprint" 114 | FROM passwd JOIN ssh_public_key 115 | USING (uid) WHERE (name = 'testuser') 116 | INTO key_fingerprint; 117 | SELECT * FROM assert.is_equal( 118 | key_fingerprint, 119 | '\xa464a5d8f04368c85a46216a422553c39177396ca23e0d2e44c819da9dc57c2d' 120 | ) INTO message, result; 121 | IF result = false THEN RETURN message; END IF; 122 | 123 | RETURN assert.ok('End of test.'); 124 | END $$ LANGUAGE plpgsql; 125 | -------------------------------------------------------------------------------- /schema/sql/schema.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | -- hosts table 4 | create domain hostname_t text check ( 5 | value ~ '^([a-z0-9]+\.)+hashbang\.sh$' 6 | ); 7 | 8 | create table "hosts" ( 9 | "name" hostname_t primary key, 10 | "maxusers" integer check(maxusers >= 0), 11 | "data" jsonb -- extra data added in the stats answer 12 | -- conforms to the host_data.yaml schema 13 | ); 14 | 15 | -- data for NSS' passwd 16 | -- there is an implicit primary group for each user 17 | -- UID and GID ranges conform to Debian policy: 18 | -- https://www.debian.org/doc/debian-policy/ch-opersys.html#s9.2.2 19 | create sequence user_id minvalue 4000 maxvalue 59999 no cycle; 20 | 21 | create domain username_t text check ( 22 | value ~ '^[a-z][a-z0-9]{0,30}$' 23 | ); 24 | 25 | create type shell as enum ( 26 | '/bin/sh', 27 | '/bin/bash', 28 | '/usr/bin/bash', 29 | '/bin/rbash', 30 | '/usr/bin/rbash', 31 | '/bin/dash', 32 | '/usr/bin/dash', 33 | '/bin/ksh93', 34 | '/usr/bin/ksh93', 35 | '/bin/rksh93', 36 | '/usr/bin/rksh93', 37 | '/usr/bin/fish', 38 | '/bin/mksh', 39 | '/usr/bin/mksh', 40 | '/bin/mksh-static', 41 | '/usr/lib/klibc/bin/mksh-static', 42 | '/bin/zsh', 43 | '/usr/bin/zsh', 44 | '/bin/tcsh', 45 | '/usr/bin/tcsh', 46 | '/usr/sbin/nologin' 47 | ); 48 | 49 | create table "passwd" ( 50 | "uid" integer primary key 51 | check((uid >= 1000 and uid < 60000) or (uid > 65535 and uid < 4294967294)) 52 | default nextval('user_id'), 53 | "name" username_t unique not null, 54 | "created_at" timestamptz default now(), 55 | "host" text not null references hosts (name), 56 | "shell" shell default '/bin/bash', 57 | "data" jsonb -- conforms to the user_data.yaml schema 58 | check(length(data::text) < 1048576), -- max 1M 59 | "banned" bool not null default false 60 | ); 61 | 62 | alter sequence user_id owned by passwd.uid; 63 | 64 | -- auxiliary groups 65 | create table "group" ( 66 | "gid" integer primary key check(gid < 1000 or (gid >= 60000 and gid < 65000)), 67 | "name" username_t unique not null 68 | ); 69 | 70 | create table "aux_groups" ( 71 | "uid" int4 not null references passwd (uid) on delete cascade, 72 | "gid" int4 not null references "group" (gid) on delete cascade, 73 | primary key ("uid", "gid") 74 | ); 75 | 76 | create type ssh_key_type as enum ( 77 | -- list extracted from sshd(8) 78 | 'sk-ecdsa-sha2-nistp256@openssh.com', 79 | 'ecdsa-sha2-nistp256', 80 | 'ecdsa-sha2-nistp384', 81 | 'ecdsa-sha2-nistp521', 82 | 'sk-ssh-ed25519@openssh.com', 83 | 'ssh-ed25519', 84 | 'ssh-dsa', 85 | 'ssh-rsa', 86 | 'ssh-ecdsa', -- not supported, but some users still have this kind of key 87 | 'ssh-dss' -- not supported, but some users still have this kind of key 88 | ); 89 | 90 | create domain ssh_sha256_fingerprint bytea check (length(value) = 32); 91 | 92 | create table "ssh_public_key" ( 93 | "fingerprint" ssh_sha256_fingerprint not null, 94 | "type" ssh_key_type not null, 95 | "key" text unique not null check(length(key) < 4096), 96 | "comment" text null check (length(comment) < 100), 97 | "uid" integer references passwd (uid) on delete cascade 98 | ); 99 | 100 | create table "openpgp_public_key" ( 101 | "uid" integer references passwd (uid) on delete cascade, 102 | "ascii_armoured_public_key" text 103 | ); 104 | 105 | create function ssh_public_key_hash() returns trigger as $$ 106 | declare 107 | key_fp bytea; 108 | begin 109 | key_fp = sha256(decode(new.key, 'base64')); 110 | if new.fingerprint is not null and new.fingerprint != key_fp then 111 | raise exception 'fingerprint does not match expected key'; 112 | end if; 113 | new.fingerprint = key_fp; 114 | return new; 115 | end; 116 | $$ language plpgsql; 117 | create trigger ssh_public_key_update 118 | before insert or update of key, fingerprint on ssh_public_key 119 | for each row execute procedure ssh_public_key_hash(); 120 | 121 | -- prevent creation/update of a user/host if the number of users 122 | -- in the group 'users' that have that host 123 | -- is equal to the maxUsers for that host 124 | create function check_hosts_for_hosts() returns trigger 125 | language plpgsql as $$ 126 | begin 127 | if ((select count(*) from passwd where passwd.host = new.name) > new.maxusers) then 128 | raise foreign_key_violation using message = 'current maxUsers too high for host: '||new.name; 129 | end if; 130 | return new; 131 | end $$; 132 | create constraint trigger max_users_on_host 133 | after update on hosts 134 | for each row 135 | when (old.maxusers <> new.maxusers) 136 | execute procedure check_hosts_for_hosts(); 137 | 138 | -- prevent creation/update of a user if the number of users 139 | -- associated to that host is equal to maxUsers 140 | create function check_max_users() returns trigger 141 | language plpgsql as $$ 142 | begin 143 | if (tg_op = 'INSERT' or old.host <> new.host) and 144 | (select count(*) from passwd where passwd.host = new.host) > (select "maxusers" from hosts where hosts.name = new.host) then 145 | raise foreign_key_violation using message = 'maxUsers reached for host: '||new.host; 146 | end if; 147 | return new; 148 | end $$; 149 | create constraint trigger max_users 150 | after insert or update on passwd 151 | for each row execute procedure check_max_users(); 152 | 153 | -- prevent users and groups sharing the same name 154 | create function check_invalid_name_for_passwd() returns trigger 155 | language plpgsql as $$ 156 | begin 157 | if (exists(select 1 from "group" where new.name = name)) then 158 | raise check_violation using message = 'group name already exists: '||new.name; 159 | end if; 160 | return new; 161 | end $$; 162 | create constraint trigger check_name_exists_passwd 163 | after insert or update on passwd 164 | for each row 165 | execute procedure check_invalid_name_for_passwd(); 166 | 167 | create function check_invalid_name_for_group() returns trigger 168 | language plpgsql as $$ 169 | begin 170 | if (exists(select 1 from passwd where new.name = name)) then 171 | raise check_violation using message = 'username already exists: '||new.name; 172 | end if; 173 | return new; 174 | end $$; 175 | create constraint trigger check_name_exists_group 176 | after insert or update on "group" 177 | for each row 178 | execute procedure check_invalid_name_for_group(); 179 | 180 | -- prevent users from taking names which are typically reserved 181 | create table "reserved_usernames" ( 182 | "name" username_t unique not null 183 | ); 184 | create function check_reserved_username() returns trigger 185 | language plpgsql as $$ 186 | begin 187 | if (exists(select 1 from reserved_usernames where name = new.name)) then 188 | raise check_violation using message = 'username reserved: '||new.name; 189 | end if; 190 | return new; 191 | end $$; 192 | create constraint trigger check_reserved_username 193 | after insert on passwd 194 | for each row 195 | execute procedure check_reserved_username(); 196 | 197 | -- prevent inserting a reserved username that is already taken by a user 198 | create function check_taken_username() returns trigger 199 | language plpgsql as $$ 200 | begin 201 | if (exists(select 1 from passwd where name = new.name)) then 202 | raise check_violation using message = 'A user with that name exists: '||new.name; 203 | end if; 204 | return new; 205 | end $$; 206 | create constraint trigger check_taken_username 207 | after insert on reserved_usernames 208 | for each row 209 | execute procedure check_taken_username(); 210 | -------------------------------------------------------------------------------- /schema/sql/api.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | create schema pgcrypto; 3 | create extension if not exists pgcrypto schema pgcrypto; 4 | 5 | create user "api" noinherit; 6 | comment on role api is 7 | $$API role used for API abstractions like PostgREST$$; 8 | alter role "api" with login; 9 | grant usage on schema public to api; 10 | grant select,insert,update,delete on table 11 | public."reserved_usernames", 12 | public."hosts", 13 | public."passwd", 14 | public."aux_groups", 15 | public."group", 16 | public."ssh_public_key", 17 | public."openpgp_public_key" 18 | to "api"; 19 | 20 | create role "api-anon"; 21 | comment on role "api-anon" is 22 | $$Internal api-anonymous read access for API$$; 23 | grant usage on sequence user_id to "api-anon"; 24 | grant "api-anon" to "api"; 25 | grant select on table public."reserved_usernames" to "api-anon"; 26 | 27 | create role "api-user-create"; 28 | comment on role "api-user-create" is 29 | $$Intended for use with user creation systems$$; 30 | grant usage on sequence "user_id" to "api-user-create"; 31 | grant "api-user-create" to "api"; 32 | grant "api-anon" to "api-user-create"; 33 | 34 | create schema v1; 35 | grant create,usage on schema v1 to api; 36 | grant usage on schema v1 to "api-anon"; 37 | 38 | create view v1.hosts as 39 | select 40 | hosts.name, 41 | hosts.maxusers, 42 | hosts.data 43 | from public.hosts; 44 | comment on view v1.hosts is 45 | $$Contains the hashbang servers$$; 46 | comment on column v1.hosts.name is 47 | $$Host's domain name$$; 48 | comment on column v1.hosts.maxusers is 49 | $$The maximum users supported by this server$$; 50 | comment on column v1.hosts.data is 51 | $$Extra data added in the stats answer.$$; 52 | alter view v1."hosts" owner to api; 53 | grant select on table v1."hosts" to "api-anon"; 54 | 55 | create view v1.passwd as 56 | select 57 | uid, 58 | name, 59 | host, 60 | shell, 61 | data 62 | from public.passwd; 63 | comment on view v1.passwd is 64 | $$Users$$; 65 | comment on column v1.passwd.uid is 66 | $$User's unique ID$$; 67 | comment on column v1.passwd.host is 68 | $$User's 'home' host$$; 69 | comment on column v1.passwd.shell is 70 | $$User's configured shell$$; 71 | comment on column v1.passwd.data is 72 | $$Extra user data$$; 73 | alter view v1."passwd" owner to api; 74 | grant select on table v1."passwd" to "api-anon"; 75 | grant insert("name","host","data") on table v1."passwd" to "api-user-create"; 76 | 77 | create view v1."group" as 78 | select 79 | gid, 80 | name 81 | from public."group"; 82 | comment on view v1."group" is 83 | $$Groups$$; 84 | comment on column v1."group".gid is 85 | $$Group ID$$; 86 | comment on column v1."group".name is 87 | $$Group Name$$; 88 | alter view v1."group" owner to api; 89 | grant select on table v1."group" to "api-anon"; 90 | 91 | create view v1.aux_groups as 92 | select 93 | uid, 94 | gid 95 | from public.aux_groups; 96 | comment on view v1.aux_groups is 97 | $$User<>Group relationships$$; 98 | comment on column v1.aux_groups.uid is 99 | $$User ID$$; 100 | comment on column v1.aux_groups.gid is 101 | $$Group ID$$; 102 | alter view v1."aux_groups" owner to api; 103 | grant select on table v1."aux_groups" to "api-anon"; 104 | 105 | create view v1.ssh_public_key as 106 | select 107 | encode(fingerprint, 'hex') as fingerprint, 108 | encode(fingerprint, 'base64') as base64_fingerprint, 109 | type, 110 | key, 111 | comment, 112 | uid 113 | from public.ssh_public_key; 114 | comment on view v1.ssh_public_key is 115 | $$SSH public keys for users$$; 116 | comment on column v1.ssh_public_key.fingerprint is 117 | $$Hex fingerprint for public key$$; 118 | comment on column v1.ssh_public_key.base64_fingerprint is 119 | $$Base64 fingerprint for public key$$; 120 | comment on column v1.ssh_public_key.type is 121 | $$Type of SSH key (dsa/rsa/ecdsa/ed25519/u2f)$$; 122 | comment on column v1.ssh_public_key.key is 123 | $$Public key formatted as OpenSSH public key format$$; 124 | comment on column v1.ssh_public_key.comment is 125 | $$Comment from the third field of the OpenSSH public key format$$; 126 | comment on column v1.ssh_public_key.uid is 127 | $$User ID the key is currently linked to$$; 128 | alter view v1."ssh_public_key" owner to api; 129 | grant select on table v1."ssh_public_key" to "api-anon"; 130 | 131 | -- PGP Key 132 | create view v1.openpgp_public_key as 133 | select 134 | uid, 135 | pgcrypto.dearmor(ascii_armoured_public_key) as key, 136 | ascii_armoured_public_key 137 | from public.openpgp_public_key; 138 | comment on view v1.openpgp_public_key is 139 | $$PGP public keys for users$$; 140 | comment on column v1.openpgp_public_key.key is 141 | $$PGP public key$$; 142 | comment on column v1.openpgp_public_key.ascii_armoured_public_key is 143 | $$ASCII armoured PGP key$$; 144 | comment on column v1.openpgp_public_key.uid is 145 | $$User ID the key is currently linked to$$; 146 | grant insert("uid", "ascii_armoured_public_key") on table v1."openpgp_public_key" to "api-user-create"; 147 | 148 | create function insert_pgp_key() returns trigger as $$ 149 | begin 150 | insert into public.openpgp_public_key (uid, ascii_armoured_public_key) 151 | values (new.uid, new.ascii_armoured_public_key); 152 | return new; 153 | end 154 | $$ language plpgsql security definer; 155 | 156 | create trigger insert_pgp_key 157 | instead of insert on v1.openpgp_public_key 158 | for each row 159 | execute procedure insert_pgp_key(); 160 | 161 | alter view v1."openpgp_public_key" owner to api; 162 | grant select on table v1."openpgp_public_key" to "api-anon"; 163 | 164 | 165 | -- User signup 166 | create view v1.signup as 167 | select 168 | p.name as name, 169 | p.host as host, 170 | p.uid as uid, 171 | array_agg(keys.type || ' ' || keys.key) as keys, 172 | p.shell as shell 173 | from 174 | public.passwd p 175 | left join public.ssh_public_key keys on p.uid = keys.uid 176 | group by p.name, p.host, p.uid, p.shell; 177 | comment on view v1.signup is 178 | $$Route for POSTable signup$$; 179 | comment on column v1.signup.name is 180 | $$Username$$; 181 | comment on column v1.signup.host is 182 | $$User's default home system$$; 183 | comment on column v1.signup.keys is 184 | $$User's raw SSH keys$$; 185 | comment on column v1.signup.shell is 186 | $$User's default shell$$; 187 | 188 | create function signup() returns trigger as $$ 189 | declare 190 | new_user_id int; 191 | temp_key_type text; 192 | temp_key_value text; 193 | temp_key_comment text; 194 | key text; 195 | begin 196 | insert into public.passwd (name, host, shell) 197 | values (new.name, new.host, new.shell) 198 | returning uid into new_user_id; 199 | for key in select * from unnest(new.keys) 200 | loop 201 | temp_key_type = split_part(key, ' ', 1); 202 | temp_key_value = split_part(key, ' ', 2); 203 | temp_key_comment = split_part(key, ' ', 3); 204 | insert into public.ssh_public_key (type, key, comment, uid) 205 | values (temp_key_type::ssh_key_type, temp_key_value, temp_key_comment, new_user_id); 206 | end loop; 207 | return new; 208 | end 209 | $$ language plpgsql security definer; 210 | 211 | create trigger signup 212 | instead of insert on v1.signup 213 | for each row 214 | execute procedure signup(); 215 | 216 | alter view v1."signup" owner to api; 217 | grant select on table v1."signup" to "api-anon"; 218 | grant insert("name", "host", "shell", "keys") on table v1."signup" to "api-user-create"; 219 | -------------------------------------------------------------------------------- /docs/DESIGN.md: -------------------------------------------------------------------------------- 1 | # #! User Database -- Design document # 2 | 3 | See 4 | 5 | # About 6 | 7 | This document describes the design of our PostgreSQL user database. 8 | 9 | Understanding the design goals and requirements is an important part of 10 | understanding the engineering trade-offs made there, so please read read 11 | the [requirements](REQUIREMENTS.md) first. 12 | 13 | # Design goals 14 | 15 | This design leans strongly towards consistency of the data, enforced 16 | as much as possible at the database level. 17 | 18 | Part of this appears in the use of foreign keys, and range or value constraints, 19 | preventing applications from inserting (or modifying) data that violates those 20 | constraints. 21 | 22 | Less apparent manifestations appear in the design of the database schema: 23 | - User's primary groups are known to have the same id and name as the users, 24 | and as such are not stored explicitely; such an inconsistency caused the 25 | [“group 3000” bug](https://github.com/hashbang/provisor/pull/25). 26 | - Data duplication is systematically avoided, as it is a major cause of 27 | inconsistencies in databases; the schema is even in 28 | [project-join normal form](https://en.wikipedia.org/wiki/Fifth_normal_form). 29 | 30 | 31 | # Replication 32 | 33 | In a single-master deployment, PostgreSQL has hot replication features that 34 | allow to immediately propagate changes to (a configurable number of) replicas, 35 | possibly before the change is commited on the master. 36 | 37 | Using a local PostgreSQL instance on each shell server, acting as a local replica, 38 | immediately fulfills the availability requirements: 39 | - each server holds a read-only copy of the database, so users can login 40 | regardless of whether the DB master is available; 41 | - should the DB master be lost, the most up-to-date replica of the DB 42 | can be either promoted to the role of master, or (preferrably) copied 43 | to the new master instance. The most recent instance can be 44 | discovered by comparing `pg_last_xlog_receive_location` values. 45 | 46 | Moreover, single-master PostgreSQL provides the usual ACID consistency guarantees. 47 | 48 | 49 | # Database schema 50 | 51 | The database schema is provided in [`schema.sql`](schema.sql). 52 | 53 | DB constraints are used to enforce, as much as possible, consistency. 54 | For instance: 55 | - uids must be valid and unique; 56 | - usernames must be unique and follow the proper syntax rules; 57 | - a user's host must exist. 58 | 59 | User records have an optional `data` column, that can hold 60 | additional, non-relational data as a (binary-encoded) JSON object. 61 | 62 | *NOTE:* Rows in `group` and `passwd` shouldn't share a `name`. 63 | Can this be expressed as a constraint? 64 | 65 | 66 | # Data representation 67 | 68 | In the `passwd` and `hosts` tables, a `data` (binary) JSON object holds 69 | some non-relational data. The rationale for this is two-fold: 70 | - the `data` object can be easily extended with additional information 71 | without having to modify the schema (or even coordinate with the administrators); 72 | - the `data` object can easily be passed across JSON-based APIs. 73 | 74 | The `data` objects for [users](schemas/user_data.yml) and 75 | [host](schemas/host_data.yml) must obey certain JSON schemata, for 76 | several reasons: 77 | - Some fields, like `shell` or `ssh_keys`, are used by #! 78 | infrastructure; validating the JSON objects prevents users from 79 | accidentally losing access to their own account in this way. 80 | - The host `data` object is directly added to data that is exposed on 81 | a public API. This avoids breaking the public API accidentally 82 | simply by changing the data. 83 | - More generally, once a convention is widely adopted by #! users, it 84 | can be formalised into a JSON schema and enforced, making the data 85 | format of user records more interoperable. 86 | 87 | Corresponding constraints (`data_host` and `data_user`) are generated 88 | and added to the schema, using [postgres-json-schema] for validation. 89 | 90 | *NOTE:* Yes, I'm aware I serialized the JSON Schema as YAML. 91 | Yes, it's legit. 92 | 93 | [postgres-json-schema]: https://github.com/gavinwahl/postgres-json-schema 94 | 95 | 96 | # Permissions 97 | 98 | Moreso than separating permissions on a per-server basis, permissions 99 | should be assigned on a per-service basis, and follow the least 100 | privilege principle. 101 | 102 | 103 | ## Shell servers 104 | 105 | A shell server hosts several components that get different access rights to the DB: 106 | - `pgsql`: the DB server itself need a DB user with the `replication` privilege. 107 | It gives complete read access to the database (from the master), and nothing else. 108 | - `ssh`: needs read access to the `passwd.{name,data}` columns. 109 | - `nss`: needs read access to `passwd`, `group` and `aux_groups`. 110 | - `hashbangctl`: needs write access to the `passwd.data` column. 111 | 112 | 113 | ## `hashbang.sh` 114 | 115 | The website fulfills two complementary (and independent) roles: 116 | - user creation: `INSERT` privilege in the `passwd` table; 117 | - statistics: read-only access to a `hosts_stats` view, created as follows: 118 | 119 | ```postgres 120 | CREATE VIEW hosts_stats AS 121 | SELECT hosts.id, hosts.name, agg.count FROM hosts 122 | JOIN (SELECT host, count(distinct id) as count FROM passwd GROUP BY host) AS agg 123 | ON agg.host = hosts.id 124 | ``` 125 | 126 | 127 | ## `mail.hashbang.sh` 128 | 129 | The mail server only needs read access to `passwd.{name,host}` and `hosts`. 130 | 131 | 132 | # Service integration 133 | 134 | ## Shell servers 135 | 136 | On the shell servers, integrating the new auth DB involves three things: 137 | - having Postgres installed and configured for streaming replication; 138 | - having `libnss-pgsql` configured as a NSS provider: this makes all 139 | users in the DB visible in the `getpwent(3)` functions family, making 140 | them “be there on the system”; 141 | - having a script set as SSH `AuthorizedKeysCommand` that queries for a 142 | user's `passwd.data` and pipe it to `jq '.ssh_keys | .[]'`. 143 | 144 | 145 | ### `libnss-pgsql` configuration 146 | 147 | The main part of the configuration of `libnss-pgsql` is to set the queries 148 | used to retrieve information from the database. Passwords are systematically 149 | set to be `!`: this is a value that cannot possibly match any password hash 150 | in `crypt(3)` format. 151 | 152 | Extracting user information is fairly straightforward: 153 | 154 | # Returns (name, passwd, gecos, dir, shell, uid, gid) for a given name or uid, or all 155 | getpwnam = SELECT "name", '!', "data"->>'name', '/home/' || "name", "data"->>'shell', uid, uid FROM passwd WHERE name = $1 156 | getpwuid = SELECT "name", '!', "data"->>'name', '/home/' || "name", "data"->>'shell', uid, uid FROM passwd WHERE uid = $1 157 | allusers = SELECT "name", '!', "data"->>'name', '/home/' || "name", "data"->>'shell', uid, uid FROM passwd 158 | 159 | 160 | Retrieving group-related data is a bit harder, as there as two kinds of groups: 161 | - a user's primary group shares the same name and id (and has a single user); 162 | - an auxiliary group is described in the `group` table. 163 | 164 | ``` 165 | # Returns (name, passwd, gid) for a given name or gid, or all 166 | getgrnam = SELECT name, '!', gid FROM group WHERE name = $1 167 | UNION SELECT name, '!', uid FROM passwd WHERE name = $1 168 | getgrgid = SELECT name, '!', gid FROM group WHERE gid = $1 169 | UNION SELECT name, '!', uid FROM passwd WHERE uid = $1 170 | allgroups = SELECT name, '!', gid FROM group 171 | UNION SELECT name, '!', uid FROM passwd 172 | ``` 173 | 174 | Finally, we need a query to link together users and auxiliary groups: 175 | 176 | # Returns all auxiliary group ids a user is a member of 177 | groups_dyn = SELECT gid FROM passwd JOIN aux_groups USING (uid) WHERE name = $1 178 | 179 | # Returns all uids belonging to a given group 180 | getgroupmembersbygid = SELECT name FROM passwd WHERE uid = $1 181 | UNION SELECT name FROM passwd JOIN aux_groups USING (uid) WHERE gid = $1 182 | 183 | 184 | ## `mail.hashbang.sh` 185 | 186 | We can se directly Postfix's Postgres support to use a specific query as 187 | a virtual table; `pgsql:/etc/postfix/pgsql-aliases.cf` can be specified 188 | as `virtual_alias_map`. 189 | 190 | The `pgsql-aliases.cf` config file itself would look like this: 191 | 192 | # The hosts that Postfix will try to connect to 193 | hosts = localhost 194 | 195 | # The user name and password to log into the pgsql server. 196 | user = someone 197 | password = some_password 198 | 199 | # The database name on the servers. 200 | dbname = userdb 201 | 202 | # Query the user's host and return user@host 203 | domain = hashbang.sh 204 | query = SELECT host FROM passwd WHERE name='%U' 205 | result_format = %U@%s 206 | -------------------------------------------------------------------------------- /test/sql/01nss.sql: -------------------------------------------------------------------------------- 1 | -- -*- mode: sql; sql-product: postgres -*- 2 | 3 | -- Test the queries used by libnss_pgsql -- 4 | 5 | /* Return (name, passwd, gecos, dir, shell, uid, gid) 6 | * for a given name or uid. 7 | */ 8 | CREATE FUNCTION unit_tests.getpwnam() 9 | RETURNS test_result AS $$ 10 | DECLARE message test_result; 11 | DECLARE result boolean; 12 | DECLARE user_uid integer; 13 | DECLARE user_gid integer; 14 | DECLARE user_home text; 15 | DECLARE user_name text; 16 | DECLARE user_pass text; 17 | DECLARE user_shell text; 18 | DECLARE user_gecos text; 19 | BEGIN 20 | SELECT "name", '!', "data"->>'name', '/home/' || "name", "shell", uid, uid 21 | FROM passwd 22 | WHERE name = 'testadmin' 23 | INTO user_name, user_pass, user_gecos, user_home, user_shell, user_uid, user_gid; 24 | 25 | SELECT * FROM assert.is_equal(user_name, 'testadmin') INTO message, result; 26 | IF result = false THEN RETURN message; END IF; 27 | 28 | SELECT * FROM assert.is_equal(user_pass, '!') INTO message, result; 29 | IF result = false THEN RETURN message; END IF; 30 | 31 | SELECT * FROM assert.is_equal(user_gecos, 'Just an admin.') INTO message, result; 32 | IF result = false THEN RETURN message; END IF; 33 | 34 | SELECT * FROM assert.is_equal(user_home, '/home/testadmin') INTO message, result; 35 | IF result = false THEN RETURN message; END IF; 36 | 37 | SELECT * FROM assert.is_equal(user_shell, '/bin/zsh') INTO message, result; 38 | IF result = false THEN RETURN message; END IF; 39 | 40 | SELECT * FROM assert.is_equal(user_uid, user_gid) INTO message, result; 41 | IF result = false THEN RETURN message; END IF; 42 | 43 | -- End of test 44 | RETURN assert.ok('End of test.'); 45 | END $$ LANGUAGE plpgsql; 46 | 47 | CREATE FUNCTION unit_tests.getpwuid() 48 | RETURNS test_result AS $$ 49 | DECLARE message test_result; 50 | DECLARE result boolean; 51 | DECLARE user_uid integer; 52 | DECLARE user_gid integer; 53 | DECLARE user_home text; 54 | DECLARE user_name text; 55 | DECLARE user_pass text; 56 | DECLARE user_shell text; 57 | DECLARE user_gecos text; 58 | BEGIN 59 | -- Get uid 60 | SELECT uid 61 | FROM passwd 62 | WHERE "name" = 'testadmin' 63 | INTO user_uid; 64 | 65 | -- Query for getpwuid 66 | SELECT "name", '!', "data"->>'name', '/home/' || "name", "shell", uid, uid 67 | FROM passwd 68 | WHERE uid = user_uid 69 | INTO user_name, user_pass, user_gecos, user_home, user_shell, user_uid, user_gid; 70 | 71 | SELECT * FROM assert.is_equal(user_name, 'testadmin') INTO message, result; 72 | IF result = false THEN RETURN message; END IF; 73 | 74 | SELECT * FROM assert.is_equal(user_pass, '!') INTO message, result; 75 | IF result = false THEN RETURN message; END IF; 76 | 77 | SELECT * FROM assert.is_equal(user_gecos, 'Just an admin.') INTO message, result; 78 | IF result = false THEN RETURN message; END IF; 79 | 80 | SELECT * FROM assert.is_equal(user_home, '/home/testadmin') INTO message, result; 81 | IF result = false THEN RETURN message; END IF; 82 | 83 | SELECT * FROM assert.is_equal(user_shell, '/bin/zsh') INTO message, result; 84 | IF result = false THEN RETURN message; END IF; 85 | 86 | SELECT * FROM assert.is_equal(user_uid, user_gid) INTO message, result; 87 | IF result = false THEN RETURN message; END IF; 88 | 89 | -- End of test 90 | RETURN assert.ok('End of test.'); 91 | END $$ LANGUAGE plpgsql; 92 | 93 | -- TODO: test for `allusers` 94 | 95 | 96 | /* Get (name, passwd, gid) for a given group 97 | * selected by id 98 | */ 99 | CREATE FUNCTION unit_tests.getgrgid_usergroup() 100 | RETURNS test_result AS $$ 101 | DECLARE message test_result; 102 | DECLARE result boolean; 103 | DECLARE user_uid integer; 104 | DECLARE group_gid integer; 105 | DECLARE group_name text; 106 | DECLARE group_pass text; 107 | BEGIN 108 | -- Get uid 109 | SELECT uid 110 | FROM passwd 111 | WHERE "name" = 'testadmin' 112 | INTO user_uid; 113 | 114 | -- Query for getgrgid 115 | SELECT * FROM ( 116 | SELECT name, '!', gid 117 | FROM "group" 118 | WHERE gid = user_uid 119 | UNION 120 | SELECT name, '!', uid 121 | FROM passwd 122 | WHERE uid = user_uid 123 | ) AS temp INTO group_name, group_pass, group_gid; 124 | 125 | SELECT * FROM assert.is_equal(group_name, 'testadmin') INTO message, result; 126 | IF result = false THEN RETURN message; END IF; 127 | 128 | SELECT * FROM assert.is_equal(group_pass, '!') INTO message, result; 129 | IF result = false THEN RETURN message; END IF; 130 | 131 | SELECT * FROM assert.is_equal(group_gid, user_uid) INTO message, result; 132 | IF result = false THEN RETURN message; END IF; 133 | 134 | -- End of test 135 | RETURN assert.ok('End of test.'); 136 | END $$ LANGUAGE plpgsql; 137 | 138 | CREATE FUNCTION unit_tests.getgrgid_systemgroup() 139 | RETURNS test_result AS $$ 140 | DECLARE message test_result; 141 | DECLARE result boolean; 142 | DECLARE group_gid integer; 143 | DECLARE group_name text; 144 | DECLARE group_pass text; 145 | BEGIN 146 | -- Get uid 147 | SELECT gid 148 | FROM "group" 149 | WHERE "name" = 'sudo' 150 | INTO group_gid; 151 | 152 | -- Query for getgrgid 153 | SELECT * FROM ( 154 | SELECT name, '!', gid 155 | FROM "group" 156 | WHERE gid = group_gid 157 | UNION 158 | SELECT name, '!', uid 159 | FROM passwd 160 | WHERE uid = group_gid 161 | ) AS temp INTO group_name, group_pass, group_gid; 162 | 163 | SELECT * FROM assert.is_equal(group_name, 'sudo') INTO message, result; 164 | IF result = false THEN RETURN message; END IF; 165 | 166 | SELECT * FROM assert.is_equal(group_pass, '!') INTO message, result; 167 | IF result = false THEN RETURN message; END IF; 168 | 169 | SELECT * FROM assert.is_equal(group_gid, 27) INTO message, result; 170 | IF result = false THEN RETURN message; END IF; 171 | 172 | -- End of test 173 | RETURN assert.ok('End of test.'); 174 | END $$ LANGUAGE plpgsql; 175 | 176 | 177 | /* Get (name, passwd, gid) for a given group 178 | * selected by name 179 | */ 180 | CREATE FUNCTION unit_tests.getgrnam_usergroup() 181 | RETURNS test_result AS $$ 182 | DECLARE message test_result; 183 | DECLARE result boolean; 184 | DECLARE user_uid integer; 185 | DECLARE group_gid integer; 186 | DECLARE group_name text; 187 | DECLARE group_pass text; 188 | BEGIN 189 | -- Get uid 190 | SELECT uid 191 | FROM passwd 192 | WHERE "name" = 'testadmin' 193 | INTO user_uid; 194 | 195 | -- Query for getgrnam 196 | SELECT * FROM ( 197 | SELECT name, '!', gid 198 | FROM "group" 199 | WHERE name = 'testadmin' 200 | UNION 201 | SELECT name, '!', uid 202 | FROM passwd 203 | WHERE name = 'testadmin' 204 | ) AS temp INTO group_name, group_pass, group_gid; 205 | 206 | SELECT * FROM assert.is_equal(group_name, 'testadmin') INTO message, result; 207 | IF result = false THEN RETURN message; END IF; 208 | 209 | SELECT * FROM assert.is_equal(group_pass, '!') INTO message, result; 210 | IF result = false THEN RETURN message; END IF; 211 | 212 | SELECT * FROM assert.is_equal(group_gid, user_uid) INTO message, result; 213 | IF result = false THEN RETURN message; END IF; 214 | 215 | -- End of test 216 | RETURN assert.ok('End of test.'); 217 | END $$ LANGUAGE plpgsql; 218 | 219 | CREATE FUNCTION unit_tests.getgrnam_systemgroup() 220 | RETURNS test_result AS $$ 221 | DECLARE message test_result; 222 | DECLARE result boolean; 223 | DECLARE group_gid integer; 224 | DECLARE group_name text; 225 | DECLARE group_pass text; 226 | BEGIN 227 | -- Query for getgrnam 228 | SELECT * FROM ( 229 | SELECT name, '!', gid 230 | FROM "group" 231 | WHERE name = 'sudo' 232 | UNION 233 | SELECT name, '!', uid 234 | FROM passwd 235 | WHERE name = 'sudo' 236 | ) AS temp INTO group_name, group_pass, group_gid; 237 | 238 | SELECT * FROM assert.is_equal(group_name, 'sudo') INTO message, result; 239 | IF result = false THEN RETURN message; END IF; 240 | 241 | SELECT * FROM assert.is_equal(group_pass, '!') INTO message, result; 242 | IF result = false THEN RETURN message; END IF; 243 | 244 | SELECT * FROM assert.is_equal(group_gid, 27) INTO message, result; 245 | IF result = false THEN RETURN message; END IF; 246 | 247 | -- End of test 248 | RETURN assert.ok('End of test.'); 249 | END $$ LANGUAGE plpgsql; 250 | 251 | /* groups_dyn returns all /auxiliary/ gids 252 | * that a user is a member of 253 | */ 254 | CREATE FUNCTION unit_tests.groups_dyn() 255 | RETURNS test_result AS $$ 256 | DECLARE message test_result; 257 | DECLARE result boolean; 258 | DECLARE useruid integer; 259 | DECLARE usergid integer; 260 | BEGIN 261 | SELECT uid 262 | FROM passwd 263 | WHERE name = 'testadmin' 264 | INTO useruid; 265 | 266 | -- Query for groups_dyn 267 | SELECT gid 268 | FROM passwd JOIN aux_groups USING (uid) 269 | WHERE name = 'testadmin' 270 | INTO usergid; 271 | 272 | SELECT * FROM assert.is_not_equal(usergid, useruid) INTO message, result; 273 | IF result = false THEN RETURN message; END IF; 274 | 275 | -- End of test 276 | RETURN assert.ok('End of test.'); 277 | END $$ LANGUAGE plpgsql; 278 | 279 | 280 | /* groups_dyn returns all users (by name) 281 | * that are member of a given group (by gid) 282 | */ 283 | CREATE FUNCTION unit_tests.getgroupmembersbygid() 284 | RETURNS test_result AS $$ 285 | DECLARE message test_result; 286 | DECLARE result boolean; 287 | DECLARE user_name text; 288 | BEGIN 289 | -- Query for getgroupmembersbygid 290 | SELECT name 291 | FROM passwd JOIN aux_groups USING (uid) 292 | WHERE gid = 27 -- sudo 293 | INTO user_name; 294 | 295 | SELECT * FROM assert.is_equal(user_name, 'testadmin') INTO message, result; 296 | IF result = false THEN RETURN message; END IF; 297 | 298 | -- End of test 299 | RETURN assert.ok('End of test.'); 300 | END $$ LANGUAGE plpgsql; 301 | --------------------------------------------------------------------------------