From 4e3903c0ceb50287b9565e2833984fbfcfc27760 Mon Sep 17 00:00:00 2001 From: Ryan Morton Date: Thu, 3 Aug 2023 16:26:26 -0400 Subject: [PATCH 1/3] feat: add indexes to assets and relations tables - Index on `$.content.Name` for FQDN assets - index on assets.type - index on assets.last_seen - index on relations.last_seen Closes #19 --- migrations/postgres/005_assets_indexes.sql | 23 +++++++++++++++++++ migrations/postgres/006_relations_indexes.sql | 9 ++++++++ migrations/sqlite3/004_assets_indexes.sql | 23 +++++++++++++++++++ migrations/sqlite3/005_relations_indexes.sql | 9 ++++++++ 4 files changed, 64 insertions(+) create mode 100644 migrations/postgres/005_assets_indexes.sql create mode 100644 migrations/postgres/006_relations_indexes.sql create mode 100644 migrations/sqlite3/004_assets_indexes.sql create mode 100644 migrations/sqlite3/005_relations_indexes.sql diff --git a/migrations/postgres/005_assets_indexes.sql b/migrations/postgres/005_assets_indexes.sql new file mode 100644 index 0000000..4bee932 --- /dev/null +++ b/migrations/postgres/005_assets_indexes.sql @@ -0,0 +1,23 @@ +-- +migrate Up + +-- Index the `name` field of the `content` jsonb when type is `FQDN` +-- Assumes the pg_trgm extension is created in the database +CREATE INDEX idx_fqdn_content_name ON assets USING gin ((content->>'name') gin_trgm_ops) WHERE type = 'FQDN'; + +-- Index assets.type +CREATE INDEX idx_assets_type_hash ON assets USING hash (type); + +-- Index created_at +CREATE INDEX idx_as_created_at ON assets (created_at); + +-- Index last_seen +CREATE INDEX idx_as_last_seen ON assets (last_seen); + + +-- +migrate Down + +-- drop all the indexes we just created +DROP INDEX idx_fqdn_content_name; +DROP INDEX idx_assets_type_hash; +DROP INDEX idx_as_created_at; +DROP INDEX idx_as_last_seen; \ No newline at end of file diff --git a/migrations/postgres/006_relations_indexes.sql b/migrations/postgres/006_relations_indexes.sql new file mode 100644 index 0000000..fc70ad7 --- /dev/null +++ b/migrations/postgres/006_relations_indexes.sql @@ -0,0 +1,9 @@ +-- +migrate Up + +CREATE INDEX idx_rel_created_at ON relations (created_at); +CREATE INDEX idx_rel_last_seen ON assets (last_seen); + +-- +migrate Down + +DROP INDEX idx_rel_created_at; +DROP INDEX idx_rel_last_seen; \ No newline at end of file diff --git a/migrations/sqlite3/004_assets_indexes.sql b/migrations/sqlite3/004_assets_indexes.sql new file mode 100644 index 0000000..15bee3b --- /dev/null +++ b/migrations/sqlite3/004_assets_indexes.sql @@ -0,0 +1,23 @@ +-- +migrate Up + +-- Index the `name` field of the `content` jsonb when type is `FQDN` +-- Assumes the pg_trgm extension is created in the database +CREATE INDEX fqdn_name ON assets (content->>'name' COLLATE NOCASE) WHERE type = 'FQDN'; + +-- Index assets.type +CREATE INDEX idx_assets_type ON assets (type); + +-- Index created_at +CREATE INDEX idx_as_created_at ON assets (created_at); + +-- Index last_seen +CREATE INDEX idx_as_last_seen ON assets (last_seen); + + +-- +migrate Down + +-- drop all the indexes we just created +DROP INDEX idx_fqdn_content_name; +DROP INDEX idx_assets_type_hash; +DROP INDEX idx_as_created_at; +DROP INDEX idx_as_last_seen; \ No newline at end of file diff --git a/migrations/sqlite3/005_relations_indexes.sql b/migrations/sqlite3/005_relations_indexes.sql new file mode 100644 index 0000000..480e69a --- /dev/null +++ b/migrations/sqlite3/005_relations_indexes.sql @@ -0,0 +1,9 @@ +-- +migrate Up + +CREATE INDEX idx_rel_created_at ON relations (created_at); +CREATE INDEX idx_rel_last_seen ON relations (last_seen); + +-- +migrate Down + +DROP INDEX idx_rel_created_at; +DROP INDEX idx_rel_last_seen; \ No newline at end of file From 92e9e6b557cca1278ac3ba32c4c030dd559e71c8 Mon Sep 17 00:00:00 2001 From: Ryan Morton Date: Thu, 3 Aug 2023 16:32:08 -0400 Subject: [PATCH 2/3] chore: move README/CONTRIBUTING to docs/ folder --- CONTRIBUTING.md => docs/CONTRIBUTING.md | 0 README.md => docs/README.md | 0 2 files changed, 0 insertions(+), 0 deletions(-) rename CONTRIBUTING.md => docs/CONTRIBUTING.md (100%) rename README.md => docs/README.md (100%) diff --git a/CONTRIBUTING.md b/docs/CONTRIBUTING.md similarity index 100% rename from CONTRIBUTING.md rename to docs/CONTRIBUTING.md diff --git a/README.md b/docs/README.md similarity index 100% rename from README.md rename to docs/README.md From 286cac338f5d3b6da94e6ed92f3cf052021c7d09 Mon Sep 17 00:00:00 2001 From: Ryan Morton Date: Thu, 3 Aug 2023 16:32:32 -0400 Subject: [PATCH 3/3] docs: add user guide includes important details related to postgres --- docs/README.md | 4 ++++ docs/USER_GUIDE.md | 49 ++++++++++++++++++++++++++++++++++++++++++++++ 2 files changed, 53 insertions(+) create mode 100644 docs/USER_GUIDE.md diff --git a/docs/README.md b/docs/README.md index 39331c1..76ace6d 100644 --- a/docs/README.md +++ b/docs/README.md @@ -12,3 +12,7 @@ This repository offers services and repositories to interact with an asset datab ## Contributing If you have interest in contributing, please refer to the [contributing doc](CONTRIBUTING.md) + +## User Guide + +For important information on how to get started with this project, please refer to the [user guide](USER_GUIDE.md). \ No newline at end of file diff --git a/docs/USER_GUIDE.md b/docs/USER_GUIDE.md new file mode 100644 index 0000000..e2b5d9b --- /dev/null +++ b/docs/USER_GUIDE.md @@ -0,0 +1,49 @@ +# User Guide + +## Postgres + +This project relies upon several Postgres features that require elevated privileges. +If you plan to use a _superuser_ when running migrations and working with the database, +you can skip this section. + +It is best practice to _not_ use a superuser in most enterprise environments. +For this reason, if you are configuring this in an environment +where you do not possess these privileges, +please work with your DBA to configure a new database in the following way: + +```sql +-- Create a new database to store assets and relations. +CREATE DATABASE IF NOT EXISTS assetdb; + +-- set the timezone to UTC +ALTER DATABASE assetdb SET timezone TO 'UTC'; +``` + +Reconnect to the `assetdb` database with the privileged user and run the following: + +```sql + +-- pg_trgm is required for to improve the performance of queries that use the LIKE operator. +-- If you already have pg_trgm installed (extensions are global), you can skip this step +-- If you don't know, you can run the following query to check: +-- SELECT * FROM pg_extension where extname = 'pg_trgm'; + +-- Install the pg_trgm extension on assetdb +CREATE EXTENSION IF NOT EXISTS pg_trgm SCHEMA public; + +-- Create a user +CREATE USER your_username WITH PASSWORD 'your_password'; + +-- on Postgres 15, the public schema is not available except to superusers. +GRANT USAGE ON schema public to your_username; + +-- Grant create permissions to your user on the public schema. +GRANT CREATE ON schema public to your_username; + +-- Grant table modification permissions to your user on the public schema. +GRANT ALL ON ALL TABLES IN SCHEMA public to your_username; + +``` + +If you would like to keep the schema modifications separate from the collection user, +you can create a separate user for this purpose.