├── CHANGELOG.md ├── LICENSE ├── PostgreSQL ├── README.md ├── check_samdrucker_host_checkins ├── database-postgresql-permissions.sql ├── database-postgresql.sql ├── procedures.sql └── updates-2020.08.28.sql ├── README.md ├── clients ├── README.md ├── samdrucker.conf.sample └── samdrucker.sh ├── database.md ├── samples.txt └── servers ├── README.md └── php ├── apache-config.conf ├── nginx-config.conf ├── samdrucker.conf.sample └── samdrucker.php /CHANGELOG.md: -------------------------------------------------------------------------------- 1 | # Changelog 2 | 3 | ## host table 4 | 5 | Any changes to the `host` table with automatically update the `date_updated` 6 | field. See `update_date_updated` in `PostgreSQL/database-postgresql.sql`. 7 | 8 | ## 0.2.4 9 | 10 | With this release, you can set a host to be not enabled. Perhaps you have a 11 | host which is no longer in use but you want to keep the data. 12 | 13 | When upgrading to this release, be sure to run these scripts: 14 | 15 | * `PostgreSQL/updates-2020.08.28.sql` 16 | * `PostgreSQL/procedures.sql` 17 | 18 | If you want to disable any hosts, this SQL will work: 19 | 20 | ``` 21 | update host set enabled = false where name in ('foo', 'bar'); 22 | ``` 23 | 24 | New versions of the query functions have been created. These take a boolean 25 | parameter as their last arguement. This allows you to query hosts which are 26 | no longer enabled (false). The existing functions will now only query 27 | enabled hosts. You can retain existing behaviour by leaving all hosts 28 | enabled. 29 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2020, Dan Langille 2 | 3 | 4 | Redistribution and use in source and binary forms, with or without 5 | modification, are permitted provided that the following conditions are met: 6 | 7 | 1. Redistributions of source code must retain the above copyright notice, this 8 | list of conditions and the following disclaimer. 9 | 2. Redistributions in binary form must reproduce the above copyright notice, 10 | this list of conditions and the following disclaimer in the documentation 11 | and/or other materials provided with the distribution. 12 | 13 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND 14 | ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED 15 | WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 16 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR 17 | ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES 18 | (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; 19 | LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND 20 | ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT 21 | (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS 22 | SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 23 | -------------------------------------------------------------------------------- /PostgreSQL/README.md: -------------------------------------------------------------------------------- 1 | To deploy a SamDrucker PostgreSQL database: 2 | 3 | - create the PostgreSQL database 4 | - update pg_hba.conf on the PostgreSQL server to allow connections from your webserver 5 | - create the tables via `database-postgresql.sql` 6 | - add the stored procedures with `procedures.sql` 7 | - invoke `database-postgresql-permissions.sql` to configure database permissions 8 | 9 | `check_samdrucker_host_checkins` is a Nagios plugin for verifying that all 10 | known hosts have checked in during the past 25 hours. 11 | -------------------------------------------------------------------------------- /PostgreSQL/check_samdrucker_host_checkins: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | # This script checks for any host which have not checked in during the past 4 | # 25 hours 5 | 6 | # arguments 7 | # * server - IP address or hostname of the PostgreSQL database server 8 | # * database - database name 9 | # * user - database user 10 | # 11 | # port is always the default value: 5432 12 | # 13 | # The password must be in ~.pgpass for the Unix user which runs this script. 14 | # 15 | # For Nagios, that defaults to ~nagios/.pgpass 16 | # 17 | # See https://www.postgresql.org/docs/12/libpq-pgpass.html 18 | # 19 | 20 | # 21 | # arguments used to create simple output of a single value 22 | # and to never issue a password prompt 23 | # 24 | psql="/usr/local/bin/psql --no-align --tuples-only --no-password " 25 | 26 | server=$1 27 | database=$2 28 | user=$3 29 | 30 | # we return zero, all good, by default 31 | result=0 32 | 33 | # the two database queries we will run 34 | query_date_updated="select name, date_updated from host where date_updated < now() - '25 hours'::interval;" 35 | 36 | # how is the host check in data? 37 | 38 | date_updated=`$psql -c "$query_date_updated" --host=$server $database $user` 39 | if [ $? == 0 ] ; then 40 | # uncomment for debugging 41 | # echo all ok with date_updated query 42 | else 43 | # when we hit an error, we do not care about the rest of the checks 44 | echo error on dates query:$? $date_updated 45 | exit 2 46 | fi 47 | 48 | # check the results 49 | 50 | if [ "$date_updated" != "" ] ; then 51 | echo There are hosts not checked in: $date_updated 52 | result=2 53 | fi 54 | 55 | if [ $result == 0 ] ; then 56 | echo All hosts have checked in 57 | fi 58 | 59 | exit $result 60 | -------------------------------------------------------------------------------- /PostgreSQL/database-postgresql-permissions.sql: -------------------------------------------------------------------------------- 1 | -- we create a role, or group 2 | CREATE ROLE delivery NOLOGIN; 3 | 4 | -- we create a user in that group 5 | 6 | CREATE USER postie WITH LOGIN PASSWORD '[change me]' IN ROLE delivery; 7 | 8 | -- we grant permission to the group 9 | 10 | GRANT INSERT, SELECT ON incoming_packages TO GROUP delivery; 11 | GRANT INSERT, SELECT, UPDATE ON host TO GROUP delivery; 12 | GRANT INSERT, SELECT, UPDATE ON package TO GROUP delivery; 13 | GRANT INSERT, SELECT, UPDATE ON package_version TO GROUP delivery; 14 | GRANT INSERT, SELECT, UPDATE, DELETE ON host_package TO GROUP delivery; 15 | 16 | 17 | CREATE ROLE reporting NOLOGIN; 18 | 19 | GRANT SELECT ON host TO GROUP reporting; 20 | -------------------------------------------------------------------------------- /PostgreSQL/database-postgresql.sql: -------------------------------------------------------------------------------- 1 | -- This is designed for PostgreSQL. 2 | 3 | -- temporary table. Might only be used for testing 4 | CREATE TABLE incoming_packages ( 5 | id integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 6 | data json NOT NULL, 7 | date_added timestamp without time zone NOT NULL default timezone('UTC'::text, now()), 8 | client_ip cidr not null default '198.51.100.0' 9 | ); 10 | 11 | 12 | 13 | INSERT INTO incoming_packages (data) values ( 14 | '{ 15 | "name": "foo.example.org", 16 | "os": "FreeBSD", 17 | "version": "12.0-RELEASE-p8", 18 | "repo": "http://pkg.freebsd.org/FreeBSD:12:amd64/latest/", 19 | "packages": [ 20 | "SamDruckerClientShell-0.0.0.2.2019110101", 21 | "anvil-0.0.17", 22 | "ap24-mod_fastcgi-2.4.7.1" 23 | ] 24 | }'); 25 | 26 | -- I am purposely not creating tables for os, version, and repo. 27 | -- 28 | --CREATE TABLE os ( 29 | -- id int PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 30 | -- name text NOT NULL 31 | --); 32 | 33 | CREATE TABLE host ( 34 | id int PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 35 | name text NOT NULL, 36 | os text NOT NULL, 37 | version text NOT NULL, 38 | repo text NOT NULL, 39 | date_updated timestamp without time zone NOT NULL default timezone('UTC'::text, now()), 40 | enabled boolean NOT NULL DEFAULT true, 41 | UNIQUE (name) 42 | ); 43 | 44 | -- this function and the tigger which follows it allows host.date_updated to be current 45 | 46 | CREATE OR REPLACE FUNCTION update_date_updated() 47 | RETURNS TRIGGER AS $$ 48 | BEGIN 49 | NEW.date_updated = timezone('UTC'::text, now()); 50 | RETURN NEW; 51 | END 52 | $$ language 'plpgsql'; 53 | 54 | DROP TRIGGER IF EXISTS update_host_date_updated ON update_host_date_updated; 55 | CREATE TRIGGER update_host_date_updated 56 | BEFORE UPDATE ON host 57 | FOR EACH ROW EXECUTE PROCEDURE update_date_updated(); 58 | 59 | 60 | CREATE TABLE package ( 61 | id int PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 62 | name text NOT NULL, 63 | UNIQUE (name) 64 | ); 65 | 66 | CREATE TABLE package_version ( 67 | id int PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, 68 | package_id int NOT NULL references package(id) ON DELETE CASCADE, 69 | version text NOT NULL, 70 | UNIQUE (package_id, version) 71 | ); 72 | 73 | CREATE TABLE host_package ( 74 | host_id int NOT NULL references host(id) ON DELETE CASCADE, 75 | package_version_id int NOT NULL references package_version(id) ON DELETE CASCADE, 76 | UNIQUE(host_id, package_version_id) 77 | ); 78 | -------------------------------------------------------------------------------- /PostgreSQL/procedures.sql: -------------------------------------------------------------------------------- 1 | -- what packages are installed on this host 2 | -- SELECT * FROM PackagesOnHost('foo.example.org'); 3 | 4 | CREATE OR REPLACE FUNCTION PackagesOnHost(text,boolean) RETURNS SETOF text AS $$ 5 | SELECT P.name || '-' || PV.version 6 | FROM host H JOIN host_package HP ON H.name = $1 AND H.enabled = $2 7 | AND H.id = HP.host_id 8 | JOIN package_version PV ON HP.package_version_id = PV.id 9 | JOIN package P ON PV.package_id = P.id 10 | $$ LANGUAGE SQL STABLE; 11 | 12 | CREATE OR REPLACE FUNCTION PackagesOnHost(text) RETURNS SETOF text AS $$ 13 | SELECT * FROM PackagesOnHost($1, true); 14 | $$ LANGUAGE SQL STABLE; 15 | 16 | -- which hosts have this package in this version installed 17 | -- select * from HostsWithPackage('apr', '1.6.5.1.6.1_1'); 18 | 19 | CREATE OR REPLACE FUNCTION HostsWithPackage(text,text,boolean) RETURNS SETOF text AS $$ 20 | SELECT H.name 21 | FROM package P JOIN package_version PV ON P.name = $1 22 | AND P.id = PV.package_id 23 | AND PV.version = $2 24 | JOIN host_package HP ON PV.id = HP.package_version_id 25 | JOIN host H ON HP.host_id = H.id AND H.enabled = $3 26 | $$ LANGUAGE SQL STABLE; 27 | 28 | 29 | CREATE OR REPLACE FUNCTION HostsWithPackage(text,text) RETURNS SETOF text AS $$ 30 | SELECT * FROM HostsWithPackage($1, $2, true) 31 | $$ LANGUAGE SQL STABLE; 32 | 33 | 34 | -- which hosts have this package. do not include version 35 | -- select * from HostsWithPackage('apr'); 36 | 37 | CREATE OR REPLACE FUNCTION HostsWithPackage(text,boolean) RETURNS SETOF text AS $$ 38 | SELECT H.name 39 | FROM package P JOIN package_version PV ON P.name = $1 40 | AND P.id = PV.package_id 41 | JOIN host_package HP ON PV.id = HP.package_version_id 42 | JOIN host H ON HP.host_id = H.id AND H.enabled = $2 43 | $$ LANGUAGE SQL STABLE; 44 | 45 | CREATE OR REPLACE FUNCTION HostsWithPackage(text) RETURNS SETOF text AS $$ 46 | SELECT * FROM HostsWithPackage($1, true) 47 | $$ LANGUAGE SQL STABLE; 48 | 49 | -- which hosts have this package. do not include version 50 | -- select * from HostsWithPackage('apr'); 51 | 52 | CREATE OR REPLACE FUNCTION HostsWithPackageShowVersion(text,boolean) 53 | RETURNS TABLE(host text, package_version text) AS $$ 54 | SELECT H.name, P.name || '-' || PV.version 55 | FROM package P JOIN package_version PV ON P.name = $1 56 | AND P.id = PV.package_id 57 | JOIN host_package HP ON PV.id = HP.package_version_id 58 | JOIN host H ON HP.host_id = H.id AND H.enabled = $2 59 | $$ LANGUAGE SQL STABLE; 60 | 61 | CREATE OR REPLACE FUNCTION HostsWithPackageShowVersion(text) 62 | RETURNS TABLE(host text, package_version text) AS $$ 63 | SELECT * FROM HostsWithPackageShowVersion($1, true) 64 | $$ LANGUAGE SQL STABLE; 65 | 66 | -- This will be the function which does it all. It takes JSON, and does all the inserts 67 | -- incoming_packages may not be a permanent table. For now, it's there for having JSON 68 | -- I can work on. 69 | 70 | CREATE OR REPLACE FUNCTION HostAddPackages(a_json json, a_client_ip cidr) RETURNS INT AS $$ 71 | DECLARE 72 | l_query text; 73 | l_id integer; 74 | BEGIN 75 | l_query := 'INSERT INTO incoming_packages (data, client_ip) values ($1, $2) RETURNING id'; 76 | EXECUTE l_query 77 | INTO l_id 78 | USING a_json, a_client_ip; 79 | 80 | RETURN l_id; 81 | END 82 | $$ LANGUAGE plpgsql; 83 | 84 | 85 | -- example 86 | -- 87 | -- SELECT HostAddPackages('{ 88 | -- "name": "foo.example.org", 89 | -- "os": "FreeBSD", 90 | -- "version": "12.0-RELEASE-p8", 91 | -- "repo": "http://pkg.freebsd.org/FreeBSD:12:amd64/latest/", 92 | -- "packages": [ 93 | -- "apr-1.6.5.1.6.1_1", 94 | -- "bacula9-client-9.4.3", 95 | -- "bash-5.0.7" 96 | -- ] 97 | -- }', '198.51.100.0'); 98 | -- 99 | -- 100 | 101 | CREATE OR REPLACE FUNCTION HostAddPackages(a_json json, a_client_ip cidr) RETURNS INT AS $$ 102 | DECLARE 103 | l_query text; 104 | l_incoming_packages_id integer; 105 | l_host_id integer; 106 | l_package text; 107 | l_package_name text; 108 | l_package_version text; 109 | l_package_id integer; 110 | l_package_version_id integer; 111 | 112 | BEGIN 113 | -- save the data, just because we can 114 | l_query := 'INSERT INTO incoming_packages (data, client_ip) values ($1, $2) RETURNING id'; 115 | EXECUTE l_query 116 | INTO l_incoming_packages_id 117 | USING a_json, a_client_ip; 118 | 119 | -- save the host, get the id 120 | 121 | l_query := 'INSERT INTO host (name, os, version, repo) 122 | SELECT $1, $2, $3, $4 123 | ON CONFLICT(name) 124 | DO UPDATE SET os = EXCLUDED.os, 125 | version = EXCLUDED.version, 126 | repo = EXCLUDED.repo 127 | RETURNING id'; 128 | 129 | EXECUTE l_query 130 | INTO l_host_id 131 | USING a_json->>'name', a_json->>'os', a_json->>'version', a_json->>'repo'; 132 | 133 | -- delete existing packages for this host 134 | 135 | DELETE FROM host_package 136 | WHERE host_id = l_host_id; 137 | 138 | -- for package in $packages 139 | 140 | FOR l_package IN SELECT * FROM json_array_elements_text(a_json->'packages') 141 | LOOP 142 | -- split package into name and version: 143 | -- for example: sudo-1.8.28p1 144 | -- split on the rightmost hypen. 145 | -- Everything to the left is package name. 146 | -- Everything to the right is version. 147 | 148 | SELECT substring(l_package, '(.+)-[^-]+$') 149 | INTO l_package_name; 150 | 151 | SELECT substring(l_package, '.+-([^-]+)$') 152 | INTO l_package_version; 153 | 154 | l_query := 'INSERT INTO package (name) values ($1) 155 | ON CONFLICT(name) 156 | DO UPDATE SET name = EXCLUDED.name 157 | RETURNING id'; 158 | 159 | EXECUTE l_query 160 | INTO l_package_id 161 | USING l_package_name; 162 | 163 | l_query := 'INSERT INTO package_version (package_id, version) values ($1, $2) 164 | ON CONFLICT ON CONSTRAINT package_version_package_id_version_key 165 | DO UPDATE SET version = EXCLUDED.version 166 | RETURNING id'; 167 | 168 | EXECUTE l_query 169 | INTO l_package_version_id 170 | USING l_package_id, l_package_version; 171 | 172 | l_query := 'INSERT INTO host_package (host_id, package_version_id) values($1, $2) 173 | ON CONFLICT ON CONSTRAINT host_package_host_id_package_version_id_key 174 | DO NOTHING'; 175 | 176 | EXECUTE l_query 177 | USING l_host_id, l_package_version_id; 178 | 179 | END LOOP; 180 | 181 | RETURN l_incoming_packages_id; 182 | END 183 | $$ LANGUAGE plpgsql; 184 | -------------------------------------------------------------------------------- /PostgreSQL/updates-2020.08.28.sql: -------------------------------------------------------------------------------- 1 | -- Column: public.host.enabled 2 | 3 | -- ALTER TABLE public.host DROP COLUMN enabled; 4 | 5 | ALTER TABLE public.host 6 | ADD COLUMN enabled boolean NOT NULL DEFAULT true; 7 | 8 | COMMENT ON COLUMN public.host.enabled 9 | IS 'hosts are enabled by default 10 | when no longer in service, set to false'; 11 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # What is Sam Drucker? 2 | 3 | SamDrucker is a collection of small components which create a centralized 4 | list of all packages on all hosts. 5 | 6 | Each component is designed to be: 7 | 8 | * small 9 | * simple 10 | * easily written 11 | * flexiable 12 | * few, if any, dependencies 13 | 14 | ## The components 15 | 16 | * client - collects the list of packages and posts it to the server 17 | * server - accepts the list of packages and adds it to the database 18 | * database - tables and stored procedures for the catalog of packages 19 | 20 | Each component can be written in whatever languages you want. Collect 21 | the packages in any manner you want. This can be done remotely on the host 22 | or centrally on a management tool, such as Ansible. 23 | 24 | Pick whatever languages you want. 25 | 26 | ## Other ideas 27 | 28 | It was mentioned elsewhere that Ansible or Spacewalk can help here. I want 29 | something completely independent. These tools are great at collecting information. 30 | 31 | I didn't want to use a large number of dependencies or huge packages. 32 | 33 | ## Current status 34 | 35 | A sample client and web service have been created as proof of concept. 36 | They are deployed in my home network, active on about 90 hosts. 37 | 38 | A database schema has been created for PostgreSQL, my database of personal 39 | choice, but this should work on any other database. Patches welcome here. 40 | 41 | ## Next major step 42 | 43 | At present, queries of the database are possible only via command line tools. 44 | 45 | I'd like to create a simple web interface. 46 | 47 | Anyone is weclome to help write this stuff. 48 | 49 | 50 | ## Wiki 51 | 52 | You can read more in [the wiki](https://github.com/dlangille/SamDrucker/wiki). 53 | -------------------------------------------------------------------------------- /clients/README.md: -------------------------------------------------------------------------------- 1 | This directory contains SamDrucker clients in various languages. 2 | 3 | A client needs to: 4 | 5 | 1. construct the `JSON` data 6 | 1. urlencode it 7 | 1. perform an HTTP POST to the SamDrucker server 8 | 9 | You can use whatever tools you want to create a client. 10 | 11 | The scripts and dependencies are listed below: 12 | 13 | `samdrucker.sh` 14 | 15 | * https://github.com/jpmens/jo - for constructing `JSON` from a shell 16 | * curl - for posting to the web server 17 | 18 | -------------------------------------------------------------------------------- /clients/samdrucker.conf.sample: -------------------------------------------------------------------------------- 1 | # the URL for your sam drucker server 2 | SAMDRUCKER_URL="https://samdrucker.example.org/samdrucker.php" 3 | 4 | # the argument expected by your sam drucker server script 5 | SAMDRUCKER_ARG="packages" 6 | 7 | # you might need --cacert for self-signed certs 8 | CURL_OPTIONS="--silent --output /dev/null" 9 | -------------------------------------------------------------------------------- /clients/samdrucker.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | # we want to construct JSON which looks like this: 4 | # { 5 | # "name": "test.example.org", 6 | # "os": "FreeBSD", 7 | # "version": "11.3-RELEASE-p4", 8 | # "repo": "http://pkg.freebsd.org/FreeBSD:113:amd64/latest/", 9 | # "packages": [ 10 | # "apr-1.6.5.1.6.1_1", 11 | # "bacula9-client-9.4.3", 12 | # "bash-5.0.7", 13 | # "rsync-3.1.3_1", 14 | # "serf-1.3.9_3", 15 | # "sqlite3-3.29.0_1" 16 | # ] 17 | # } 18 | # 19 | # I am using the FreeBSD textproc/jo: 20 | # 21 | # $ jo -p name=`hostname` os=`uname` version=`uname -r` repo=`pkg -vv | grep ' url' | cut -f2 -d \"` 22 | # { 23 | # "name": "samdrucker.int.unixathome.org", 24 | # "os": "FreeBSD", 25 | # "version": "12.0-RELEASE-p10", 26 | # "repo": "pkg+http://fedex.unixathome.org/packages/120amd64-default-master-list/" 27 | # } 28 | # 29 | 30 | if [ -r /usr/local/etc/samdrucker/samdrucker.conf ]; then 31 | . /usr/local/etc/samdrucker/samdrucker.conf 32 | fi 33 | 34 | CURL="/usr/local/bin/curl" 35 | CUT="/usr/bin/cut" 36 | GREP="/usr/bin/grep" 37 | JO="/usr/local/bin/jo" 38 | PKG="/usr/sbin/pkg" 39 | 40 | # get list of packages on this host: 41 | 42 | pkg_args="" 43 | PKGS=`$PKG info -q` 44 | for pkg in $PKGS 45 | do 46 | pkg_args="$pkg_args packages[]=$pkg" 47 | done 48 | 49 | hostname=`/bin/hostname` 50 | uname=`/usr/bin/uname` 51 | version=`/bin/freebsd-version` 52 | repo=`/usr/sbin/pkg -vv | $GREP ' url' | $CUT -f2 -d \"` 53 | 54 | # we save this to a file to avoid potential command line arguement overflow 55 | payload=$(mktemp /tmp/SamDrucker.payload.XXXXXX) 56 | $JO -p name=$hostname os=$uname version=$version repo=$repo $pkg_args > $payload 57 | 58 | $CURL $CURL_OPTIONS --data-urlencode ${SAMDRUCKER_ARG}@${payload} $SAMDRUCKER_URL 59 | 60 | # remove the temp file 61 | rm $payload 62 | -------------------------------------------------------------------------------- /database.md: -------------------------------------------------------------------------------- 1 | These are the proposed database tables and corresponding queries. 2 | 3 | host 4 | ==== 5 | ``` 6 | id 7 | name 8 | os 9 | version 10 | repo 11 | ``` 12 | 13 | package 14 | ======= 15 | ``` 16 | id 17 | name (e.g. foo) 18 | ``` 19 | 20 | package_version 21 | =============== 22 | ``` 23 | id 24 | package_id 25 | version (e.g. 1.2.3) 26 | ```` 27 | 28 | host_package 29 | ============ 30 | ``` 31 | host_id 32 | package_version_id 33 | ```` 34 | 35 | Show me hosts with foo-1.2.3 installed. 36 | 37 | ``` 38 | SELECT H.name 39 | FROM package P JOIN package_version PV ON P.name = 'foo' 40 | AND P.id = PV.package_id 41 | AND PV.version = '1.2.3' 42 | JOIN host_package HP ON PV.id = HP.package_version_id 43 | JOIN host H ON PV.host_id = H.id 44 | ORDER BY 1; 45 | ``` 46 | 47 | Show me all packages installed on host bar 48 | 49 | ``` 50 | SELECT P.name || '-' || PV.version 51 | FROM host H JOIN host_package HP ON H.name = 'bar' 52 | AND H.id = HP.host_id 53 | JOIN package_version PV ON HP.package_version_id = PV.id 54 | JOIN package P ON HP.package_id = P.id 55 | ORDER BY 1; 56 | ``` 57 | -------------------------------------------------------------------------------- /samples.txt: -------------------------------------------------------------------------------- 1 | Here are some query samples I've been playing with. 2 | 3 | After inserting this data: 4 | 5 | INSERT INTO incoming_packages (data) values ( 6 | '{ 7 | "name": "foo.example.org", 8 | "os": "FreeBSD", 9 | "version": "12.0-RELEASE-p8", 10 | "repo": "http://pkg.freebsd.org/FreeBSD:12:amd64/latest/", 11 | "packages": { 12 | "package": [ 13 | "apr-1.6.5.1.6.1_1", 14 | [ 15 | "bacula9-client-9.4.3" 16 | ], 17 | [ 18 | "bash-5.0.7" 19 | ] 20 | ] 21 | } 22 | }'); 23 | 24 | I can do this query: 25 | 26 | samdrucker=# select id, data->>'name' from incoming_packages; 27 | id | ?column? 28 | ----+------------------- 29 | 1 | "foo.example.org" 30 | (1 row) 31 | 32 | samdrucker=# 33 | 34 | Insert into host table: 35 | 36 | INSERT INTO host (name, os, version, repo) 37 | SELECT data->>'name', data->>'os', data->>'version', data->>'repo' 38 | FROM incoming_packages 39 | WHERE id = 1; 40 | 41 | View that data: 42 | 43 | samdrucker=# SELECT * FROM host; 44 | id | name | os | version | repo 45 | ----+-------------------+-----------+-------------------+--------------------------------------------------- 46 | 1 | "foo.example.org" | "FreeBSD" | "12.0-RELEASE-p8" | "http://pkg.freebsd.org/FreeBSD:12:amd64/latest/" 47 | (1 row) 48 | 49 | See those "quotes"? That's part of the JSON. That might be an issue on 50 | queries. 51 | 52 | If we do another insert, we get an error, as expected: 53 | 54 | samdrucker=# INSERT INTO hoste (name, os, version, repo) 55 | SELECT data->>'name', data->>'os', data->>'version', data->>'repo' 56 | FROM incoming_packages 57 | WHERE id = 1; 58 | ERROR: duplicate key value violates unique constraint "hoste_name_key" 59 | DETAIL: Key (name)=("foo.example.org") already exists. 60 | samdrucker=# 61 | 62 | Instead, we can do an update 63 | 64 | INSERT INTO host (name, os, version, repo) 65 | SELECT data->>'name', data->>'os', '12.0-RELEASE-p9', data->>'repo' 66 | FROM incoming_packages 67 | WHERE id = 1 68 | ON CONFLICT(name) 69 | DO UPDATE SET os = EXCLUDED.os, 70 | version = EXCLUDED.version, 71 | repo = EXCLUDED.repo; 72 | 73 | Noticed how we have updated the version: 74 | 75 | samdrucker=# SELECT * FROM host; 76 | id | name | os | version | repo 77 | ----+-----------------+---------+-----------------+------------------------------------------------- 78 | 1 | foo.example.org | FreeBSD | 12.0-RELEASE-p9 | http://pkg.freebsd.org/FreeBSD:12:amd64/latest/ 79 | (1 row) 80 | 81 | Inserting the packages 82 | 83 | 1 - split package into name and version: 84 | foo-1.2.3 85 | split on the rightmost hypen. 86 | Everything to the left is package name. 87 | Everything to the right is version. 88 | 89 | Try (.+)-[^-]+$ 90 | 91 | INSERT INTO package (name) values ('apr') 92 | ON CONFLICT(name) 93 | DO NOTHING 94 | RETURNING id; 95 | 96 | INSERT INTO package_version (package_id, version) values (1, '1.6.5.1.6.1_1') 97 | ON CONFLICT ON CONSTRAINT package_version_package_id_version_key 98 | DO NOTHING 99 | RETURNING id; 100 | 101 | INSERT INTO host_package (host_id, package_version_id) values(1, 1); 102 | ON CONFLICT ON CONSTRAINT host_package_host_id_package_version_id_key 103 | DO NOTHING; 104 | 105 | 106 | INSERT INTO package (name) values ('bacula9-client') 107 | ON CONFLICT(name) 108 | DO NOTHING 109 | RETURNING id; 110 | 111 | INSERT INTO package_version (package_id, version) values (5, '9.4.3') 112 | ON CONFLICT ON CONSTRAINT package_version_package_id_version_key 113 | DO NOTHING 114 | RETURNING id; 115 | 116 | INSERT INTO host_package (host_id, package_version_id) values(7, 3) 117 | ON CONFLICT ON CONSTRAINT host_package_host_id_package_version_id_key 118 | DO NOTHING; 119 | 120 | 121 | Now the queries for output: 122 | 123 | What servers have this package installed? 124 | 125 | samdrucker=# SELECT H.name 126 | samdrucker-# FROM package P JOIN package_version PV ON P.name = 'apr' 127 | samdrucker-# AND P.id = PV.package_id 128 | samdrucker-# AND PV.version = '1.6.5.1.6.1_1' 129 | samdrucker-# JOIN host_package HP ON PV.id = HP.package_version_id 130 | samdrucker-# JOIN host H ON HP.host_id = H.id 131 | samdrucker-# ORDER BY 1; 132 | name 133 | ----------------- 134 | foo.example.org 135 | (1 row) 136 | 137 | Or by function: 138 | 139 | # select * from HostsWithPackage('apr'); 140 | hostswithpackage 141 | ------------------ 142 | foo.example.org 143 | (1 row) 144 | 145 | I think including the package version up there might be a good idea. 146 | 147 | What packages are installed on this server: 148 | samdrucker=# SELECT P.name || '-' || PV.version 149 | samdrucker-# FROM host H JOIN host_package HP ON H.name = '"foo.example.org"' 150 | samdrucker-# AND H.id = HP.host_id 151 | samdrucker-# JOIN package_version PV ON HP.package_version_id = PV.id 152 | samdrucker-# JOIN package P ON PV.package_id = P.id 153 | samdrucker-# ORDER BY 1; 154 | ?column? 155 | ------------------- 156 | apr-1.6.5.1.6.1_1 157 | 158 | Or using the function: 159 | 160 | samdrucker=# SELECT * FROM PackagesOnHost('foo.example.org'); 161 | packagesonhost 162 | ---------------------- 163 | apr-1.6.5.1.6.1_1 164 | bacula9-client-9.4.3 165 | (2 rows) 166 | 167 | 168 | Eventually the way you can update the list of packages is like this: 169 | 170 | SELECT HostAddPackages('{ 171 | "name": "foo.example.org", 172 | "os": "FreeBSD", 173 | "version": "12.0-RELEASE-p8", 174 | "repo": "http://pkg.freebsd.org/FreeBSD:12:amd64/latest/", 175 | "packages": { 176 | "package": [ 177 | "apr-1.6.5.1.6.1_1", 178 | [ 179 | "bacula9-client-9.4.3" 180 | ], 181 | [ 182 | "bash-5.0.7" 183 | ] 184 | ] 185 | } 186 | }'); 187 | -------------------------------------------------------------------------------- /servers/README.md: -------------------------------------------------------------------------------- 1 | This directory contains SamDrucker server in various languages. 2 | 3 | A server needs to: 4 | 5 | 1. capture the incoming JSON data 6 | 1. connect to the database 7 | 1. invoke the `HostAddPackages()` function using the JSON 8 | 1. disconnect 9 | 10 | You can use whatever tools you want to create a server. 11 | 12 | The scripts and dependencies are listed below: 13 | 14 | php - `samdrucker.php` 15 | 16 | * `php` - tested with php 7.2 & 7.4 17 | * `php-pgsql` - for PostgreSQL database connection 18 | -------------------------------------------------------------------------------- /servers/php/apache-config.conf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/dlangille/SamDrucker/35eab73d6da9c9ba06b598090cb1dc21f650abe7/servers/php/apache-config.conf -------------------------------------------------------------------------------- /servers/php/nginx-config.conf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/dlangille/SamDrucker/35eab73d6da9c9ba06b598090cb1dc21f650abe7/servers/php/nginx-config.conf -------------------------------------------------------------------------------- /servers/php/samdrucker.conf.sample: -------------------------------------------------------------------------------- 1 | beginTransaction(); 27 | $sql = 'SELECT HostAddPackages(:packages, :client_ip)'; 28 | 29 | $stmt = $dbh->prepare($sql); 30 | # does this need some sanitizing? 31 | $stmt->bindValue(':packages', $_REQUEST['packages']); 32 | $stmt->bindValue(':client_ip', $_SERVER['REMOTE_ADDR']); 33 | 34 | try { 35 | $stmt->execute(); 36 | } catch (PDOException $e){ 37 | echo $e->getMessage(); 38 | } 39 | 40 | $dbh->commit(); 41 | 42 | } catch (PDOException $e){ 43 | // report error message 44 | syslog(LOG_ERR, $e->getMessage()); 45 | } 46 | --------------------------------------------------------------------------------