-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #3 from ZeroGachis/develop
Merge develop
- Loading branch information
Showing
11 changed files
with
498 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,62 @@ | ||
# .github/workflows/pgtest.yml | ||
name: Postgres tests | ||
|
||
on: push | ||
|
||
jobs: | ||
pgtap: | ||
runs-on: ubuntu-latest | ||
strategy: | ||
matrix: | ||
version: [ '16', '17' ] | ||
|
||
container: pgxn/pgxn-tools | ||
env: | ||
PGUSER: postgres | ||
|
||
steps: | ||
- run: pg-start ${{ matrix.version }} | ||
- uses: actions/checkout@main | ||
|
||
# Basic regression test. | ||
- run: pg-build-test | ||
|
||
# Basic regression test. | ||
- name: install dependency | ||
run: pgxn install ddl_historization | ||
|
||
- name: build application | ||
run: make all | ||
|
||
- name: install extension | ||
run: make install | ||
|
||
- name: create extension | ||
run: >- | ||
psql --host localhost --username postgres --dbname postgres \ | ||
-c 'CREATE EXTENSION schedoc CASCADE' | ||
env: | ||
PGPASSWORD: postgres | ||
|
||
- name: Checkout pgtap | ||
uses: actions/checkout@v4 | ||
with: | ||
repository: theory/pgtap | ||
path: pgtap | ||
ref: v1.3.3 | ||
|
||
- name: install pgtap | ||
working-directory: pgtap | ||
run: make && psql --host localhost --username postgres --dbname postgres --file sql/pgtap.sql | ||
env: | ||
PGPASSWORD: postgres | ||
|
||
- name: run unit tests | ||
run: pg_prove --host localhost --dbname postgres --username postgres test/sql/*.sql | ||
env: | ||
PGPASSWORD: postgres | ||
|
||
- name: run integration tests | ||
run: pg_prove --host localhost --dbname postgres --username postgres test/*.sql | ||
env: | ||
PGPASSWORD: postgres |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
*~ |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,47 @@ | ||
{ | ||
"name": "schedoc", | ||
"abstract": "Schema documentation for PostgreSQL based on ddl_historization extension", | ||
"description": "Schema documentation system based on COMMENT with json data and ddl_historization.", | ||
"version": "0.0.1", | ||
"maintainer": [ | ||
"Rodolphe Quiédeville <[email protected]>" | ||
], | ||
"license": { | ||
"PostgreSQL": "https://www.postgresql.org/about/licence" | ||
}, | ||
"prereqs": { | ||
"runtime": { | ||
"requires": { | ||
"plpgsql": 0, | ||
"PostgreSQL": "12.0.0", | ||
"ddl_historization": "0.0.5" | ||
} | ||
} | ||
}, | ||
"provides": { | ||
"schedoc": { | ||
"abstract": "Schema documentation for PostgreSQL", | ||
"file": "dist/schedoc", | ||
"version": "0.0.1" | ||
} | ||
}, | ||
"resources": { | ||
"bugtracker": { | ||
"web": "https://github.com/ZeroGachis/pg_schedoc/issues" | ||
}, | ||
"repository": { | ||
"url": "https://github.com/ZeroGachis/pg_schedoc.git", | ||
"web": "https://github.com/ZeroGachis/pg_schedoc", | ||
"type": "git" | ||
} | ||
}, | ||
"generated_by": "Rodolphe Quiédeville", | ||
"meta-spec": { | ||
"version": "1.0.0", | ||
"url": "https://pgxn.org/meta/spec.txt" | ||
}, | ||
"tags": [ | ||
"documentation", | ||
"schema" | ||
] | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,42 @@ | ||
.PHONY : all dist pgtle clean install test | ||
|
||
FILES = $(wildcard sql/*.sql) | ||
|
||
EXTENSION = schedoc | ||
|
||
EXTVERSION = $(shell grep -m 1 '[[:space:]]\{3\}"version":' META.json | \ | ||
sed -e 's/[[:space:]]*"version":[[:space:]]*"\([^"]*\)",\{0,1\}/\1/') | ||
|
||
DATA = dist/schedoc--$(EXTVERSION).sql | ||
|
||
DIST = dist/$(EXTENSION)--$(EXTVERSION).sql | ||
|
||
PGTLEOUT = dist/pgtle.$(EXTENSION)-$(EXTVERSION).sql | ||
|
||
PG_CONFIG = pg_config | ||
PGXS := $(shell $(PG_CONFIG) --pgxs) | ||
|
||
# edit this value if you want to deploy by hand | ||
SCHEMA = @extschema@ | ||
|
||
include $(PGXS) | ||
|
||
all: $(DIST) $(PGTLEOUT) | ||
|
||
clean: | ||
rm -f $(PGTLEOUT) $(DIST) | ||
|
||
$(DIST): $(FILES) | ||
cat sql/table.sql > $@ | ||
cat $@ > dist/$(EXTENSION).sql | ||
|
||
test: | ||
pg_prove -f test/sql/*.sql | ||
|
||
$(PGTLEOUT): dist/$(EXTENSION)--$(EXTVERSION).sql pgtle_header.in pgtle_footer.in | ||
sed -e 's/_EXTVERSION_/$(EXTVERSION)/' pgtle_header.in > $(PGTLEOUT) | ||
cat dist/$(EXTENSION)--$(EXTVERSION).sql >> $(PGTLEOUT) | ||
cat pgtle_footer.in >> $(PGTLEOUT) | ||
|
||
dist: $(PGTLEOUT) | ||
git archive --format zip --prefix=$(EXTENSION)-$(EXTVERSION)/ -o $(EXTENSION)-$(EXTVERSION).zip HEAD |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,110 @@ | ||
SELECT pgtle.install_extension | ||
( | ||
'schedoc', | ||
'0.0.1', | ||
'Schema documentation based on COMMENT', | ||
$_pg_tle_$ | ||
-- | ||
-- | ||
-- | ||
|
||
CREATE TYPE data_status AS ENUM ('public', 'private', 'legacy', 'wip'); | ||
|
||
CREATE TABLE schedoc_column_raw ( | ||
objoid oid, | ||
objsubid oid, | ||
comment jsonb, | ||
status data_status, | ||
PRIMARY KEY (objoid, objsubid) | ||
); | ||
|
||
CREATE VIEW schedoc_column_comments AS | ||
|
||
SELECT current_database() as databasename, c.relname as tablename, a.attname as columnname, status | ||
FROM schedoc_column_raw ccr | ||
JOIN pg_class c ON c.oid = ccr.objoid | ||
JOIN pg_attribute a ON (a.attnum = ccr.objsubid AND a.attrelid = ccr.objoid); | ||
|
||
-- | ||
-- | ||
-- | ||
CREATE OR REPLACE FUNCTION schedoc_start() | ||
RETURNS void | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
schemaname TEXT; | ||
BEGIN | ||
SELECT n.nspname FROM pg_extension e JOIN pg_namespace n ON n.oid=e.extnamespace WHERE e.extname='ddl_historization' INTO schemaname; | ||
|
||
-- | ||
-- Function to manage INSERT statements | ||
-- | ||
|
||
EXECUTE format('CREATE OR REPLACE FUNCTION %s.schedoc_trg() | ||
RETURNS trigger LANGUAGE plpgsql AS $$ | ||
BEGIN | ||
INSERT INTO %s.schedoc_column_raw (objoid, objsubid, comment, status) | ||
VALUES ( | ||
NEW.objoid, | ||
NEW.objsubid, | ||
%s.schedoc_get_column_description(NEW.objoid, NEW.objsubid)::jsonb, | ||
%s.schedoc_get_column_status(NEW.objoid, NEW.objsubid)::public.data_status | ||
) ON CONFLICT (objoid, objsubid) | ||
DO UPDATE SET | ||
comment = %s.schedoc_get_column_description(EXCLUDED.objoid, EXCLUDED.objsubid)::jsonb, | ||
status = %s.schedoc_get_column_status(EXCLUDED.objoid, EXCLUDED.objsubid)::public.data_status; | ||
RETURN NEW; | ||
END; | ||
$$', schemaname, schemaname, schemaname, schemaname, schemaname, schemaname); | ||
|
||
-- | ||
-- Create two triggers, one for UPDATE and one for INSERT | ||
-- | ||
|
||
EXECUTE format(' | ||
CREATE TRIGGER schedoc_trg | ||
BEFORE INSERT ON %s.ddl_history | ||
FOR EACH ROW | ||
WHEN (NEW.ddl_tag = ''COMMENT'') | ||
EXECUTE PROCEDURE %s.schedoc_trg()', | ||
schemaname,schemaname); | ||
|
||
END; | ||
$EOF$; | ||
|
||
|
||
CREATE OR REPLACE FUNCTION schedoc_get_column_description(bjoid oid, bjsubid oid) | ||
RETURNS text | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
description TEXT; | ||
BEGIN | ||
SELECT pg_description.description FROM pg_description | ||
WHERE pg_description.objoid=bjoid AND pg_description.objsubid=bjsubid INTO description; | ||
|
||
RETURN description; | ||
END; | ||
$EOF$; | ||
|
||
CREATE OR REPLACE FUNCTION schedoc_get_column_status(bjoid oid, bjsubid oid) | ||
RETURNS text | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
status TEXT; | ||
BEGIN | ||
SELECT pg_description.description::jsonb->>'status' FROM pg_description | ||
WHERE pg_description.objoid=bjoid AND pg_description.objsubid=bjsubid INTO status; | ||
|
||
RETURN status; | ||
END; | ||
$EOF$; | ||
|
||
-- CREATE TRIGGER schedoc_trg | ||
-- BEFORE INSERT ON ddl_history | ||
-- FOR EACH ROW | ||
-- EXECUTE PROCEDURE schedoc_trg(); | ||
$_pg_tle_$ | ||
); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,2 @@ | ||
$_pg_tle_$ | ||
); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,6 @@ | ||
SELECT pgtle.install_extension | ||
( | ||
'schedoc', | ||
'_EXTVERSION_', | ||
'Schema documentation based on COMMENT', | ||
$_pg_tle_$ |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,5 @@ | ||
comment = 'Schema automatic documentation based on ddl_historization and COMMENT' | ||
default_version = '0.0.1' | ||
relocatable = false | ||
module_pathname = '$libdir/pg_schedoc' | ||
requires = 'ddl_historization' |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,102 @@ | ||
-- | ||
-- | ||
-- | ||
|
||
CREATE TYPE data_status AS ENUM ('public', 'private', 'legacy', 'wip'); | ||
|
||
CREATE TABLE schedoc_column_raw ( | ||
objoid oid, | ||
objsubid oid, | ||
comment jsonb, | ||
status data_status, | ||
PRIMARY KEY (objoid, objsubid) | ||
); | ||
|
||
CREATE VIEW schedoc_column_comments AS | ||
|
||
SELECT current_database() as databasename, c.relname as tablename, a.attname as columnname, status | ||
FROM schedoc_column_raw ccr | ||
JOIN pg_class c ON c.oid = ccr.objoid | ||
JOIN pg_attribute a ON (a.attnum = ccr.objsubid AND a.attrelid = ccr.objoid); | ||
|
||
-- | ||
-- | ||
-- | ||
CREATE OR REPLACE FUNCTION schedoc_start() | ||
RETURNS void | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
schemaname TEXT; | ||
BEGIN | ||
SELECT n.nspname FROM pg_extension e JOIN pg_namespace n ON n.oid=e.extnamespace WHERE e.extname='ddl_historization' INTO schemaname; | ||
|
||
-- | ||
-- Function to manage INSERT statements | ||
-- | ||
|
||
EXECUTE format('CREATE OR REPLACE FUNCTION %s.schedoc_trg() | ||
RETURNS trigger LANGUAGE plpgsql AS $$ | ||
BEGIN | ||
INSERT INTO %s.schedoc_column_raw (objoid, objsubid, comment, status) | ||
VALUES ( | ||
NEW.objoid, | ||
NEW.objsubid, | ||
%s.schedoc_get_column_description(NEW.objoid, NEW.objsubid)::jsonb, | ||
%s.schedoc_get_column_status(NEW.objoid, NEW.objsubid)::public.data_status | ||
) ON CONFLICT (objoid, objsubid) | ||
DO UPDATE SET | ||
comment = %s.schedoc_get_column_description(EXCLUDED.objoid, EXCLUDED.objsubid)::jsonb, | ||
status = %s.schedoc_get_column_status(EXCLUDED.objoid, EXCLUDED.objsubid)::public.data_status; | ||
RETURN NEW; | ||
END; | ||
$$', schemaname, schemaname, schemaname, schemaname, schemaname, schemaname); | ||
|
||
-- | ||
-- Create two triggers, one for UPDATE and one for INSERT | ||
-- | ||
|
||
EXECUTE format(' | ||
CREATE TRIGGER schedoc_trg | ||
BEFORE INSERT ON %s.ddl_history | ||
FOR EACH ROW | ||
WHEN (NEW.ddl_tag = ''COMMENT'') | ||
EXECUTE PROCEDURE %s.schedoc_trg()', | ||
schemaname,schemaname); | ||
|
||
END; | ||
$EOF$; | ||
|
||
|
||
CREATE OR REPLACE FUNCTION schedoc_get_column_description(bjoid oid, bjsubid oid) | ||
RETURNS text | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
description TEXT; | ||
BEGIN | ||
SELECT pg_description.description FROM pg_description | ||
WHERE pg_description.objoid=bjoid AND pg_description.objsubid=bjsubid INTO description; | ||
|
||
RETURN description; | ||
END; | ||
$EOF$; | ||
|
||
CREATE OR REPLACE FUNCTION schedoc_get_column_status(bjoid oid, bjsubid oid) | ||
RETURNS text | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
status TEXT; | ||
BEGIN | ||
SELECT pg_description.description::jsonb->>'status' FROM pg_description | ||
WHERE pg_description.objoid=bjoid AND pg_description.objsubid=bjsubid INTO status; | ||
|
||
RETURN status; | ||
END; | ||
$EOF$; | ||
|
||
-- CREATE TRIGGER schedoc_trg | ||
-- BEFORE INSERT ON ddl_history | ||
-- FOR EACH ROW | ||
-- EXECUTE PROCEDURE schedoc_trg(); |
Oops, something went wrong.