├── .postgres-ci.yaml ├── LICENSE ├── Makefile ├── README.md ├── make.sh ├── postgres_ci--0.2--0.3.sql ├── postgres_ci--0.2.sql ├── postgres_ci--0.3.sql ├── postgres_ci.control ├── src ├── functions │ ├── auth │ │ ├── gc.sql │ │ ├── get_user.sql │ │ ├── login.sql │ │ └── logout.sql │ ├── build │ │ ├── accept.sql │ │ ├── add_part.sql │ │ ├── fetch.sql │ │ ├── gc.sql │ │ ├── list.sql │ │ ├── new.sql │ │ ├── notify.sql │ │ ├── start.sql │ │ ├── stop.sql │ │ └── view.sql │ ├── hook │ │ ├── commit.sql │ │ ├── github_push.sql │ │ └── push.sql │ ├── notification │ │ ├── bind_with_telegram.sql │ │ ├── fetch.sql │ │ ├── find_user_by_telegram_username.sql │ │ ├── get_method.sql │ │ └── update_method.sql │ ├── password │ │ ├── change.sql │ │ ├── check.sql │ │ └── reset.sql │ ├── project │ │ ├── add.sql │ │ ├── add_commit.sql │ │ ├── delete.sql │ │ ├── get.sql │ │ ├── get_branch_id.sql │ │ ├── get_github_secret.sql │ │ ├── get_possible_owners.sql │ │ ├── github_name.sql │ │ ├── list.sql │ │ └── update.sql │ └── users │ │ ├── add.sql │ │ ├── delete.sql │ │ ├── get.sql │ │ ├── list.sql │ │ └── update.sql ├── packages.sql ├── pg_extension_config_dump.sql └── schema.sql ├── test_setup.sh └── tests ├── auth ├── test_gc.sql ├── test_get_user.sql ├── test_login.sql └── test_logout.sql ├── build ├── test_accept.sql ├── test_add_part.sql ├── test_fetch.sql ├── test_new.sql ├── test_start.sql └── test_stop.sql ├── coverage.sql ├── grants.sql ├── hook ├── test_commit.sql ├── test_github_push.sql └── test_push.sql ├── manual_test_runner.sql ├── notification ├── test_bind_with_telegram.sql ├── test_find_user_by_telegram_username.sql ├── test_get_method.sql └── test_update_method.sql ├── password ├── test_change.sql ├── test_check.sql └── test_reset.sql ├── postgres_ci └── test_sha1.sql ├── project ├── test_add.sql ├── test_add_commit.sql ├── test_delete.sql ├── test_get.sql ├── test_get_branch_id.sql ├── test_get_github_secret.sql ├── test_get_possible_owners.sql ├── test_github_name.sql ├── test_list.sql └── test_update.sql ├── tests.sql └── users ├── test_add.sql ├── test_delete.sql ├── test_get.sql ├── test_list.sql └── test_update.sql /.postgres-ci.yaml: -------------------------------------------------------------------------------- 1 | images: 2 | - postgres:9.5 3 | - postgres:9.6 4 | 5 | commands: 6 | - "echo 'Dogfooding :)'" 7 | - "bash test_setup.sh" 8 | 9 | postgres: 10 | database: postgres_ci 11 | username: tester 12 | password: Slonik -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2016 Postgres-CI 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 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = postgres_ci 2 | DATA = postgres_ci--0.2.sql \ 3 | postgres_ci--0.2--0.3.sql \ 4 | postgres_ci--0.3.sql 5 | 6 | PG_CONFIG = pg_config 7 | PGXS := $(shell $(PG_CONFIG) --pgxs) 8 | include $(PGXS) -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # core -------------------------------------------------------------------------------- /make.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | VERSION="0.4" 4 | 5 | echo " 6 | \echo Use \"CREATE EXTENSION postgres_ci\" to load this file. \quit 7 | 8 | set statement_timeout = 0; 9 | set client_encoding = 'UTF8'; 10 | set client_min_messages = warning; 11 | set escape_string_warning = off; 12 | set standard_conforming_strings = on; 13 | 14 | " > "postgres_ci--$VERSION.sql" 15 | 16 | 17 | FILES="src/schema.sql 18 | src/packages.sql 19 | src/pg_extension_config_dump.sql 20 | src/functions/auth/*.sql 21 | src/functions/build/*.sql 22 | src/functions/project/*.sql 23 | src/functions/hook/*.sql 24 | src/functions/password/*.sql 25 | src/functions/notification/*.sql 26 | src/functions/users/*.sql" 27 | 28 | for file in $FILES 29 | do 30 | 31 | echo " 32 | 33 | /* source file: $file */ 34 | " >> "postgres_ci--$VERSION.sql" 35 | 36 | cat $file >> "postgres_ci--$VERSION.sql" 37 | done 38 | 39 | -------------------------------------------------------------------------------- /postgres_ci--0.2--0.3.sql: -------------------------------------------------------------------------------- 1 | create schema notification; 2 | grant usage on schema notification to public; 3 | grant execute on all functions in schema notification to public; 4 | drop index postgres_ci.find_user; 5 | 6 | create unlogged table postgres_ci.notification( 7 | build_id int not null references postgres_ci.builds(build_id) primary key, 8 | created_at timestamptz not null default current_timestamp 9 | ); 10 | 11 | create type postgres_ci.notification_method as enum ( 12 | 'none', 13 | 'email', 14 | 'telegram' 15 | ); 16 | 17 | create table postgres_ci.user_notification_method( 18 | user_id int not null references postgres_ci.users(user_id) primary key, 19 | method postgres_ci.notification_method not null default 'none', 20 | text_id text not null, 21 | int_id bigint not null default 0 22 | ); 23 | 24 | select pg_catalog.pg_extension_config_dump('postgres_ci.user_notification_method', ''); 25 | 26 | create unique index unique_user_notification_method 27 | on postgres_ci.user_notification_method (method, lower(text_id)) 28 | where method <> 'none' and text_id <> ''; 29 | 30 | insert into postgres_ci.user_notification_method (user_id, method, text_id) 31 | select user_id, 'email', user_email from postgres_ci.users; 32 | 33 | 34 | create or replace function notification.fetch() returns table ( 35 | build_id int, 36 | build_status postgres_ci.status, 37 | project_id int, 38 | project_name text, 39 | branch text, 40 | build_error text, 41 | build_created_at timestamptz, 42 | build_started_at timestamptz, 43 | build_finished_at timestamptz, 44 | commit_sha text, 45 | commit_message text, 46 | committed_at timestamptz, 47 | committer_name text, 48 | committer_email text, 49 | commit_author_name text, 50 | commit_author_email text, 51 | send_to jsonb 52 | ) as $$ 53 | declare 54 | _build_id int; 55 | begin 56 | 57 | SELECT 58 | N.build_id INTO _build_id 59 | FROM postgres_ci.notification AS N 60 | ORDER BY N.build_id 61 | LIMIT 1 62 | FOR UPDATE SKIP LOCKED; 63 | 64 | IF NOT FOUND THEN 65 | return; 66 | END IF; 67 | 68 | return query 69 | SELECT 70 | B.build_id, 71 | B.status, 72 | P.project_id, 73 | P.project_name, 74 | BR.branch, 75 | B.error, 76 | B.created_at, 77 | B.started_at, 78 | B.finished_at, 79 | C.commit_sha, 80 | C.commit_message, 81 | C.committed_at, 82 | C.committer_name, 83 | C.committer_email, 84 | C.author_name, 85 | C.author_email, 86 | ( 87 | SELECT 88 | COALESCE(array_to_json(array_agg(P.*)), '[]') 89 | FROM ( 90 | SELECT 91 | U.user_name, 92 | M.method AS notify_method, 93 | M.text_id AS notify_text_id, 94 | M.int_id AS notify_int_id 95 | FROM postgres_ci.users AS U 96 | JOIN postgres_ci.user_notification_method AS M ON U.user_id = M.user_id 97 | WHERE U.user_id IN ( 98 | SELECT 99 | P.project_owner_id 100 | UNION ALL 101 | SELECT 102 | U.user_id 103 | FROM postgres_ci.users AS U 104 | WHERE U.user_email IN (lower(C.author_email), lower(C.committer_email)) 105 | ) AND M.method <> 'none' 106 | ) AS P 107 | )::jsonb 108 | FROM postgres_ci.builds AS B 109 | JOIN postgres_ci.projects AS P ON P.project_id = B.project_id 110 | JOIN postgres_ci.commits AS C ON C.commit_id = B.commit_id 111 | JOIN postgres_ci.branches AS BR ON BR.branch_id = B.branch_id 112 | WHERE B.build_id = _build_id; 113 | 114 | DELETE FROM postgres_ci.notification AS N WHERE N.build_id = _build_id; 115 | end; 116 | $$ language plpgsql security definer rows 1; 117 | 118 | 119 | 120 | create or replace function users.add( 121 | _user_login text, 122 | _password text, 123 | _user_name text, 124 | _user_email text, 125 | _is_superuser boolean, 126 | out user_id int 127 | ) returns int as $$ 128 | declare 129 | _salt text; 130 | _message text; 131 | _column_name text; 132 | _constraint_name text; 133 | _datatype_name text; 134 | _table_name text; 135 | _schema_name text; 136 | begin 137 | 138 | _salt = postgres_ci.sha1(gen_salt('md5') || current_timestamp); 139 | 140 | BEGIN 141 | 142 | INSERT INTO postgres_ci.users ( 143 | user_login, 144 | user_name, 145 | user_email, 146 | is_superuser, 147 | hash, 148 | salt 149 | ) VALUES ( 150 | _user_login, 151 | _user_name, 152 | _user_email, 153 | _is_superuser, 154 | encode(digest(_salt || _password, 'sha1'), 'hex'), 155 | _salt 156 | ) RETURNING users.user_id INTO user_id; 157 | 158 | INSERT INTO postgres_ci.user_notification_method (user_id, method, text_id) VALUES (add.user_id, 'email', _user_email); 159 | 160 | EXCEPTION WHEN OTHERS THEN 161 | 162 | GET STACKED DIAGNOSTICS 163 | _column_name = column_name, 164 | _constraint_name = constraint_name, 165 | _datatype_name = pg_datatype_name, 166 | _table_name = table_name, 167 | _schema_name = schema_name; 168 | 169 | CASE 170 | WHEN _constraint_name = 'unique_user_login' THEN 171 | _message = 'LOGIN_ALREADY_EXISTS'; 172 | WHEN _constraint_name = 'unique_user_email' THEN 173 | _message = 'EMAIL_ALREADY_EXISTS'; 174 | WHEN _constraint_name = 'check_user_email' THEN 175 | _message = 'INVALID_EMAIL'; 176 | ELSE 177 | _message = SQLERRM; 178 | END CASE; 179 | 180 | RAISE EXCEPTION USING 181 | MESSAGE = _message, 182 | ERRCODE = SQLSTATE, 183 | COLUMN = _column_name, 184 | CONSTRAINT = _constraint_name, 185 | DATATYPE = _datatype_name, 186 | TABLE = _table_name, 187 | SCHEMA = _schema_name; 188 | END; 189 | 190 | end; 191 | $$ language plpgsql security definer; 192 | 193 | 194 | create or replace function notification.update_method( 195 | _user_id int, 196 | _method postgres_ci.notification_method, 197 | _text_id text 198 | ) returns void as $$ 199 | begin 200 | 201 | CASE 202 | WHEN _method = 'none' THEN 203 | UPDATE postgres_ci.user_notification_method 204 | SET 205 | method = _method, 206 | text_id = '', 207 | int_id = 0 208 | WHERE user_id = _user_id; 209 | ELSE 210 | UPDATE postgres_ci.user_notification_method 211 | SET 212 | method = _method, 213 | text_id = _text_id, 214 | int_id = 0 215 | WHERE user_id = _user_id AND NOT ( 216 | text_id = _text_id AND method = _method 217 | ); 218 | END CASE; 219 | 220 | end; 221 | $$ language plpgsql security definer; 222 | 223 | create or replace function notification.bind_with_telegram( 224 | _user_id int, 225 | _telegram_username text, 226 | _telegram_id bigint 227 | ) returns void as $$ 228 | begin 229 | 230 | UPDATE postgres_ci.user_notification_method 231 | SET 232 | int_id = _telegram_id 233 | WHERE user_id = _user_id 234 | AND method = 'telegram' 235 | AND text_id = _telegram_username; 236 | 237 | IF NOT FOUND THEN 238 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 239 | END IF; 240 | end; 241 | $$ language plpgsql security definer; 242 | 243 | create or replace function notification.find_user_by_telegram_username(_telegram_username text) returns table ( 244 | user_id int, 245 | telegram_id bigint 246 | ) as $$ 247 | begin 248 | 249 | return query 250 | SELECT 251 | N.user_id, 252 | N.int_id 253 | FROM postgres_ci.user_notification_method AS N 254 | WHERE N.method = 'telegram' 255 | AND N.text_id = _telegram_username; 256 | 257 | end; 258 | $$ language plpgsql security definer rows 1; 259 | 260 | 261 | create or replace function build.stop(_build_id int, _config text, _error text) returns void as $$ 262 | begin 263 | 264 | UPDATE postgres_ci.builds 265 | SET 266 | config = _config, 267 | error = _error, 268 | status = ( 269 | CASE 270 | WHEN _error = '' THEN 'success' 271 | ELSE 'failed' 272 | END 273 | )::postgres_ci.status, 274 | finished_at = current_timestamp 275 | WHERE build_id = _build_id 276 | AND status = 'running'; 277 | 278 | IF NOT FOUND THEN 279 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 280 | END IF; 281 | 282 | PERFORM build.notify(_build_id); 283 | 284 | IF EXISTS( 285 | SELECT 286 | FROM postgres_ci.parts 287 | WHERE build_id = _build_id 288 | AND success IS False 289 | LIMIT 1 290 | ) THEN 291 | UPDATE postgres_ci.builds SET status = 'failed'::postgres_ci.status WHERE build_id = _build_id; 292 | END IF; 293 | 294 | end; 295 | $$ language plpgsql security definer; 296 | 297 | 298 | 299 | create or replace function build.gc() returns void as $$ 300 | declare 301 | _build_id int; 302 | begin 303 | 304 | FOR _build_id IN 305 | SELECT 306 | build_id 307 | FROM postgres_ci.builds 308 | WHERE status IN ('accepted', 'running') 309 | AND created_at < (current_timestamp - '1 hour'::interval) 310 | ORDER BY build_id 311 | LOOP 312 | UPDATE postgres_ci.builds AS B 313 | SET 314 | status = 'failed', 315 | error = 'Execution timeout', 316 | finished_at = current_timestamp 317 | WHERE B.build_id = _build_id; 318 | 319 | PERFORM 320 | pg_notify('postgres-ci::stop_container', ( 321 | SELECT to_json(T.*) FROM ( 322 | SELECT 323 | P.container_id, 324 | current_timestamp AS created_at 325 | ) T 326 | )::text 327 | ) 328 | FROM postgres_ci.parts AS P 329 | WHERE P.build_id = _build_id; 330 | 331 | PERFORM build.notify(_build_id); 332 | END LOOP; 333 | end; 334 | $$ language plpgsql security definer; 335 | 336 | create or replace function build.notify(_build_id int) returns boolean as $$ 337 | begin 338 | 339 | INSERT INTO postgres_ci.notification (build_id) VALUES (_build_id); 340 | 341 | PERFORM pg_notify('postgres-ci::notification', ( 342 | SELECT to_json(T.*) FROM ( 343 | SELECT 344 | _build_id AS build_id, 345 | CURRENT_TIMESTAMP AS created_at 346 | ) T 347 | )::text 348 | ); 349 | 350 | return true; 351 | 352 | end; 353 | $$ language plpgsql security definer; 354 | 355 | create or replace function notification.get_method( 356 | _user_id int, 357 | out method text, 358 | out text_id text, 359 | out int_id bigint 360 | ) returns record as $$ 361 | begin 362 | 363 | SELECT 364 | M.method, 365 | M.text_id, 366 | M.int_id 367 | INTO 368 | method, 369 | text_id, 370 | int_id 371 | FROM postgres_ci.user_notification_method AS M 372 | WHERE M.user_id = _user_id; 373 | 374 | IF NOT FOUND THEN 375 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 376 | END IF; 377 | end; 378 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /postgres_ci--0.2.sql: -------------------------------------------------------------------------------- 1 | 2 | \echo Use "CREATE EXTENSION postgres_ci" to load this file. \quit 3 | 4 | set statement_timeout = 0; 5 | set client_encoding = 'UTF8'; 6 | set client_min_messages = warning; 7 | set escape_string_warning = off; 8 | set standard_conforming_strings = on; 9 | 10 | 11 | 12 | 13 | /* source file: src/schema.sql */ 14 | 15 | --create schema postgres_ci; 16 | 17 | create or replace function postgres_ci.sha1(_value text) returns text as $$ 18 | begin 19 | return encode(digest(_value, 'sha1'), 'hex'); 20 | end; 21 | $$ language plpgsql; 22 | 23 | create sequence postgres_ci.users_seq; 24 | create table postgres_ci.users ( 25 | user_id int not null default nextval('postgres_ci.users_seq') primary key, 26 | user_name text not null, 27 | user_login text not null, 28 | user_email text not null, 29 | hash text not null, 30 | salt text not null, 31 | is_superuser boolean not null default false, 32 | is_deleted boolean not null default false, 33 | created_at timestamptz not null default current_timestamp, 34 | updated_at timestamptz not null default current_timestamp, 35 | constraint check_user_hash check(length(hash) = 40), 36 | constraint check_user_salt check(length(salt) = 40), 37 | constraint check_user_email check(strpos(user_email, '@') > 0) 38 | ); 39 | 40 | create unique index unique_user_login on postgres_ci.users (lower(user_login)); 41 | create unique index unique_user_email on postgres_ci.users (lower(user_email)); 42 | create index find_user on postgres_ci.users using gin(lower(user_name || user_login || user_email) gin_trgm_ops); 43 | 44 | create unlogged table postgres_ci.sessions( 45 | session_id text not null default postgres_ci.sha1(gen_salt('md5') || gen_salt('md5')) primary key, 46 | user_id int not null references postgres_ci.users(user_id), 47 | expires_at timestamptz not null default current_timestamp 48 | ); 49 | 50 | create index idx_sessions_expires_at on postgres_ci.sessions(expires_at); 51 | 52 | create type postgres_ci.status as enum( 53 | 'pending', 54 | 'accepted', 55 | 'running', 56 | 'failed', 57 | 'success' 58 | ); 59 | 60 | create sequence postgres_ci.projects_seq; 61 | 62 | create table postgres_ci.projects( 63 | project_id int not null default nextval('postgres_ci.projects_seq') primary key, 64 | project_name text not null, 65 | project_token uuid not null default gen_random_uuid(), 66 | project_owner_id int not null, 67 | repository_url text not null, 68 | github_name text not null, 69 | github_secret text not null, 70 | last_build_id int, 71 | is_deleted boolean not null default false, 72 | created_at timestamptz not null default current_timestamp, 73 | updated_at timestamptz not null default current_timestamp, 74 | unique(project_token) 75 | ); 76 | 77 | create unique index udx_is_github_repo on postgres_ci.projects (github_name) where github_name <> ''; 78 | alter table postgres_ci.projects add constraint fk_project_owner_id foreign key (project_owner_id) references postgres_ci.users(user_id); 79 | 80 | create sequence postgres_ci.branches_seq; 81 | 82 | create table postgres_ci.branches( 83 | branch_id int not null default nextval('postgres_ci.branches_seq'), 84 | branch text not null, 85 | project_id int not null references postgres_ci.projects(project_id), 86 | created_at timestamptz not null default current_timestamp, 87 | primary key (project_id, branch_id) 88 | ); 89 | 90 | create index idx_branch on postgres_ci.branches (branch_id); 91 | 92 | create sequence postgres_ci.commits_seq; 93 | 94 | create table postgres_ci.commits( 95 | commit_id int not null default nextval('postgres_ci.commits_seq') primary key, 96 | project_id int not null, 97 | branch_id int not null, 98 | commit_sha text not null, 99 | commit_message text not null, 100 | committed_at timestamptz not null, 101 | committer_name text not null, 102 | committer_email text not null, 103 | author_name text not null, 104 | author_email text not null, 105 | created_at timestamptz not null default current_timestamp, 106 | constraint check_commit_sha check(length(commit_sha) = 40), 107 | constraint uniq_commit unique(branch_id, commit_sha), 108 | foreign key (project_id, branch_id) references postgres_ci.branches(project_id, branch_id) match full 109 | ); 110 | 111 | create sequence postgres_ci.builds_seq; 112 | 113 | create table postgres_ci.builds( 114 | build_id int not null default nextval('postgres_ci.builds_seq') primary key, 115 | project_id int not null, 116 | branch_id int not null, 117 | commit_id int not null references postgres_ci.commits(commit_id), 118 | config text not null, 119 | status postgres_ci.status not null, 120 | error text not null default '', 121 | created_at timestamptz not null default current_timestamp, 122 | started_at timestamptz, 123 | finished_at timestamptz, 124 | foreign key (project_id, branch_id) references postgres_ci.branches(project_id, branch_id) match full 125 | ); 126 | 127 | create index idx_new_build on postgres_ci.builds(status) where status in ('pending', 'accepted', 'running'); 128 | create index idx_p_b_build on postgres_ci.builds(project_id, branch_id); 129 | 130 | alter table postgres_ci.projects add foreign key (last_build_id) references postgres_ci.builds(build_id); 131 | 132 | create table postgres_ci.builds_counters( 133 | project_id int not null, 134 | branch_id int not null, 135 | counter bigint not null, 136 | constraint unique_builds_counters unique(project_id, branch_id), 137 | foreign key (project_id, branch_id) references postgres_ci.branches(project_id, branch_id) match full 138 | ); 139 | 140 | create sequence postgres_ci.parts_seq; 141 | 142 | create table postgres_ci.parts( 143 | part_id int not null default nextval('postgres_ci.parts_seq') primary key, 144 | build_id int not null references postgres_ci.builds(build_id), 145 | image text not null, 146 | container_id text not null, 147 | version text not null, 148 | output text not null, 149 | success boolean not null, 150 | started_at timestamptz not null, 151 | finished_at timestamptz not null 152 | ); 153 | 154 | create index idx_parts_build on postgres_ci.parts(build_id); 155 | 156 | create table postgres_ci.tests( 157 | part_id int not null references postgres_ci.parts(part_id), 158 | function text not null, 159 | errors jsonb not null default '[]', 160 | duration real not null 161 | ); 162 | 163 | create index idx_part_tests on postgres_ci.tests(part_id); 164 | 165 | 166 | /* 167 | 168 | select * from users.add('user', 'password', 'User', 'email@email.com', true); 169 | 170 | */ 171 | 172 | 173 | 174 | /* source file: src/packages.sql */ 175 | 176 | create schema auth; 177 | create schema hook; 178 | create schema users; 179 | create schema build; 180 | create schema project; 181 | create schema password; 182 | 183 | grant usage on schema auth to public; 184 | grant usage on schema hook to public; 185 | grant usage on schema users to public; 186 | grant usage on schema build to public; 187 | grant usage on schema project to public; 188 | grant usage on schema password to public; 189 | grant usage on schema postgres_ci to public; 190 | grant execute on all functions in schema auth to public; 191 | grant execute on all functions in schema hook to public; 192 | grant execute on all functions in schema users to public; 193 | grant execute on all functions in schema build to public; 194 | grant execute on all functions in schema project to public; 195 | grant execute on all functions in schema password to public; 196 | grant execute on all functions in schema postgres_ci to public; 197 | 198 | /* source file: src/pg_extension_config_dump.sql */ 199 | 200 | select pg_catalog.pg_extension_config_dump('postgres_ci.users', ''); 201 | select pg_catalog.pg_extension_config_dump('postgres_ci.users_seq', ''); 202 | select pg_catalog.pg_extension_config_dump('postgres_ci.projects', ''); 203 | select pg_catalog.pg_extension_config_dump('postgres_ci.projects_seq', ''); 204 | select pg_catalog.pg_extension_config_dump('postgres_ci.branches', ''); 205 | select pg_catalog.pg_extension_config_dump('postgres_ci.branches_seq', ''); 206 | select pg_catalog.pg_extension_config_dump('postgres_ci.commits', ''); 207 | select pg_catalog.pg_extension_config_dump('postgres_ci.commits_seq', ''); 208 | select pg_catalog.pg_extension_config_dump('postgres_ci.builds', ''); 209 | select pg_catalog.pg_extension_config_dump('postgres_ci.builds_seq', ''); 210 | select pg_catalog.pg_extension_config_dump('postgres_ci.parts', ''); 211 | select pg_catalog.pg_extension_config_dump('postgres_ci.parts_seq', ''); 212 | 213 | 214 | /* source file: src/functions/auth/gc.sql */ 215 | 216 | create or replace function auth.gc() returns void as $$ 217 | begin 218 | DELETE FROM postgres_ci.sessions WHERE expires_at < CURRENT_TIMESTAMP; 219 | end; 220 | $$ language plpgsql security definer; 221 | 222 | /* source file: src/functions/auth/get_user.sql */ 223 | 224 | create or replace function auth.get_user( 225 | _session_id text 226 | ) returns table( 227 | user_id int, 228 | user_name text, 229 | user_login text, 230 | user_email text, 231 | is_superuser boolean, 232 | created_at timestamptz 233 | ) as $$ 234 | begin 235 | 236 | return query 237 | SELECT 238 | U.user_id, 239 | U.user_name, 240 | U.user_login, 241 | U.user_email, 242 | U.is_superuser, 243 | U.created_at 244 | FROM postgres_ci.users AS U 245 | JOIN postgres_ci.sessions AS S USING(user_id) 246 | WHERE U.is_deleted = false 247 | AND S.session_id = _session_id 248 | AND S.expires_at > CURRENT_TIMESTAMP; 249 | 250 | IF FOUND THEN 251 | UPDATE postgres_ci.sessions 252 | SET 253 | expires_at = CURRENT_TIMESTAMP + '1 hour'::interval 254 | WHERE session_id = _session_id; 255 | END IF; 256 | end; 257 | $$ language plpgsql security definer rows 1; 258 | 259 | /* source file: src/functions/auth/login.sql */ 260 | 261 | create or replace function auth.login( 262 | _login text, 263 | _password text, 264 | out session_id text 265 | ) returns text as $$ 266 | declare 267 | _user_id int; 268 | _invalid_password boolean; 269 | begin 270 | 271 | SELECT 272 | U.user_id, 273 | encode(digest(U.salt || _password, 'sha1'), 'hex') != U.hash 274 | INTO 275 | _user_id, 276 | _invalid_password 277 | FROM postgres_ci.users AS U 278 | WHERE lower(U.user_login) = lower(_login) 279 | AND is_deleted = false; 280 | 281 | CASE 282 | WHEN NOT FOUND THEN 283 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 284 | WHEN _invalid_password THEN 285 | RAISE EXCEPTION 'INVALID_PASSWORD' USING ERRCODE = 'invalid_password'; 286 | ELSE 287 | INSERT INTO postgres_ci.sessions ( 288 | user_id, 289 | expires_at 290 | ) VALUES ( 291 | _user_id, 292 | CURRENT_TIMESTAMP + '1 hour'::interval 293 | ) RETURNING sessions.session_id INTO session_id; 294 | END CASE; 295 | end; 296 | $$ language plpgsql security definer; 297 | 298 | /* source file: src/functions/auth/logout.sql */ 299 | 300 | create or replace function auth.logout(_session_id text) returns void as $$ 301 | begin 302 | DELETE FROM postgres_ci.sessions WHERE session_id = _session_id; 303 | end; 304 | $$ language plpgsql security definer; 305 | 306 | /* source file: src/functions/build/accept.sql */ 307 | 308 | create or replace function build.accept( 309 | _build_id int, 310 | out accept boolean 311 | ) returns boolean as $$ 312 | begin 313 | 314 | UPDATE postgres_ci.builds 315 | SET status = 'accepted' 316 | WHERE status = 'pending' 317 | AND build_id = _build_id; 318 | 319 | IF NOT FOUND THEN 320 | accept = false; 321 | return; 322 | END IF; 323 | 324 | accept = true; 325 | end; 326 | $$ language plpgsql security definer; 327 | 328 | /* source file: src/functions/build/add_part.sql */ 329 | 330 | create or replace function build.add_part( 331 | _build_id int, 332 | _version text, 333 | _image text, 334 | _container_id text, 335 | _output text, 336 | _started_at timestamptz, 337 | _tests jsonb, 338 | out part_id int 339 | ) returns int as $$ 340 | declare 341 | _test postgres_ci.tests; 342 | begin 343 | 344 | INSERT INTO postgres_ci.parts ( 345 | build_id, 346 | version, 347 | image, 348 | container_id, 349 | output, 350 | success, 351 | started_at, 352 | finished_at 353 | ) VALUES ( 354 | _build_id, 355 | _version, 356 | _image, 357 | _container_id, 358 | _output, 359 | true, 360 | _started_at, 361 | CURRENT_TIMESTAMP 362 | ) RETURNING parts.part_id INTO add_part.part_id; 363 | 364 | INSERT INTO postgres_ci.tests ( 365 | part_id, 366 | function, 367 | errors, 368 | duration 369 | ) 370 | SELECT 371 | add_part.part_id, 372 | E.function, 373 | E.errors, 374 | E.duration 375 | FROM jsonb_populate_recordset(null::postgres_ci.tests, _tests) AS E; 376 | 377 | IF EXISTS( 378 | SELECT 379 | FROM postgres_ci.tests 380 | WHERE tests.part_id = add_part.part_id 381 | AND jsonb_array_length(errors) > 0 382 | LIMIT 1 383 | ) THEN 384 | UPDATE postgres_ci.parts SET success = false WHERE parts.part_id = add_part.part_id; 385 | END IF; 386 | 387 | end; 388 | $$ language plpgsql security definer; 389 | 390 | 391 | /* source file: src/functions/build/fetch.sql */ 392 | 393 | create or replace function build.fetch() returns table ( 394 | build_id int, 395 | created_at timestamptz 396 | ) as $$ 397 | declare 398 | _build_id int; 399 | _created_at timestamptz; 400 | begin 401 | 402 | SELECT 403 | B.build_id, 404 | B.created_at 405 | INTO 406 | _build_id, 407 | _created_at 408 | FROM postgres_ci.builds AS B 409 | WHERE B.status = 'pending' 410 | ORDER BY B.build_id 411 | LIMIT 1 412 | FOR UPDATE SKIP LOCKED; 413 | 414 | IF NOT FOUND THEN 415 | return; 416 | END IF; 417 | 418 | UPDATE postgres_ci.builds AS B SET status = 'accepted' WHERE B.build_id = _build_id; 419 | 420 | return query 421 | SELECT _build_id, _created_at; 422 | end; 423 | $$ language plpgsql security definer rows 1; 424 | 425 | /* source file: src/functions/build/gc.sql */ 426 | 427 | create or replace function build.gc() returns void as $$ 428 | declare 429 | _build_id int; 430 | begin 431 | 432 | FOR _build_id IN 433 | SELECT 434 | build_id 435 | FROM postgres_ci.builds 436 | WHERE status IN ('accepted', 'running') 437 | AND created_at < (current_timestamp - '1 hour'::interval) 438 | ORDER BY build_id 439 | LOOP 440 | UPDATE postgres_ci.builds AS B 441 | SET 442 | status = 'failed', 443 | error = 'Execution timeout', 444 | finished_at = current_timestamp 445 | WHERE B.build_id = _build_id; 446 | 447 | PERFORM 448 | pg_notify('postgres-ci::stop_container', ( 449 | SELECT to_json(T.*) FROM ( 450 | SELECT 451 | P.container_id, 452 | current_timestamp AS created_at 453 | ) T 454 | )::text 455 | ) 456 | FROM postgres_ci.parts AS P 457 | WHERE P.build_id = _build_id; 458 | END LOOP; 459 | end; 460 | $$ language plpgsql security definer; 461 | 462 | 463 | /* source file: src/functions/build/list.sql */ 464 | 465 | create or replace function build.list( 466 | _project_id int, 467 | _branch_id int, 468 | _limit int, 469 | _offset int, 470 | out project_id int, 471 | out project_name text, 472 | out total bigint, 473 | out branches jsonb, 474 | out items jsonb 475 | ) returns record as $$ 476 | begin 477 | 478 | SELECT 479 | P.project_id, 480 | P.project_name, 481 | ( 482 | SELECT 483 | COALESCE(SUM(C.counter), 0) 484 | FROM postgres_ci.builds_counters AS C 485 | WHERE C.project_id = _project_id 486 | AND ( 487 | CASE WHEN _branch_id <> 0 488 | THEN branch_id = _branch_id 489 | ELSE true 490 | END 491 | ) 492 | ), 493 | ( 494 | SELECT 495 | COALESCE(array_to_json(array_agg(R.*)), '[]') 496 | FROM ( 497 | SELECT 498 | B.branch_id, 499 | B.branch 500 | FROM postgres_ci.branches AS B 501 | WHERE 502 | B.project_id = _project_id 503 | ORDER BY branch 504 | ) AS R 505 | ), 506 | ( 507 | SELECT 508 | COALESCE(array_to_json(array_agg(R.*)), '[]') 509 | FROM ( 510 | SELECT 511 | BD.build_id, 512 | BD.project_id, 513 | BD.status, 514 | BD.error, 515 | BD.created_at, 516 | BD.started_at, 517 | BD.finished_at, 518 | C.commit_sha, 519 | C.commit_message, 520 | B.branch, 521 | B.branch_id 522 | FROM postgres_ci.builds AS BD 523 | JOIN postgres_ci.commits AS C USING(commit_id) 524 | JOIN postgres_ci.branches AS B ON B.branch_id = C.branch_id 525 | WHERE 526 | BD.project_id = _project_id 527 | AND ( 528 | CASE WHEN _branch_id <> 0 529 | THEN BD.branch_id = _branch_id 530 | ELSE true 531 | END 532 | ) 533 | ORDER BY build_id DESC 534 | LIMIT _limit 535 | OFFSET _offset 536 | ) AS R 537 | ) 538 | FROM postgres_ci.projects AS P 539 | WHERE P.project_id = _project_id 540 | AND P.is_deleted = false 541 | INTO project_id, project_name, total, branches, items; 542 | 543 | end; 544 | $$ language plpgsql security definer; 545 | 546 | 547 | /* source file: src/functions/build/new.sql */ 548 | 549 | create or replace function build.new( 550 | _project_id int, 551 | _branch_id int, 552 | _commit_id int, 553 | out build_id int 554 | ) returns int as $$ 555 | begin 556 | 557 | INSERT INTO postgres_ci.builds ( 558 | project_id, 559 | branch_id, 560 | commit_id, 561 | config, 562 | status 563 | ) VALUES ( 564 | _project_id, 565 | _branch_id, 566 | _commit_id, 567 | '', 568 | 'pending' 569 | ) RETURNING builds.build_id INTO build_id; 570 | 571 | INSERT INTO postgres_ci.builds_counters AS C ( 572 | project_id, 573 | branch_id, 574 | counter 575 | ) VALUES ( 576 | _project_id, 577 | _branch_id, 578 | 1 579 | ) ON CONFLICT 580 | ON CONSTRAINT unique_builds_counters DO UPDATE 581 | SET counter = C.counter + 1; 582 | 583 | PERFORM pg_notify('postgres-ci::tasks', ( 584 | SELECT to_json(T.*) FROM ( 585 | SELECT 586 | new.build_id AS build_id, 587 | CURRENT_TIMESTAMP AS created_at 588 | ) T 589 | )::text 590 | ); 591 | 592 | end; 593 | $$ language plpgsql security definer; 594 | 595 | /* source file: src/functions/build/start.sql */ 596 | 597 | create or replace function build.start( 598 | _build_id int, 599 | out repository_url text, 600 | out branch text, 601 | out revision text 602 | ) returns record as $$ 603 | declare 604 | _commit_id int; 605 | _project_id int; 606 | begin 607 | 608 | UPDATE postgres_ci.builds AS B 609 | SET 610 | status = 'running', 611 | started_at = current_timestamp 612 | WHERE B.build_id = _build_id 613 | AND B.status = 'accepted' 614 | RETURNING B.commit_id INTO _commit_id; 615 | 616 | IF NOT FOUND THEN 617 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 618 | END IF; 619 | 620 | SELECT 621 | P.project_id, 622 | P.repository_url, 623 | B.branch, 624 | C.commit_sha 625 | INTO 626 | _project_id, 627 | repository_url, 628 | branch, 629 | revision 630 | FROM postgres_ci.projects AS P 631 | JOIN postgres_ci.branches AS B USING(project_id) 632 | JOIN postgres_ci.commits AS C ON C.branch_id = B.branch_id 633 | WHERE C.commit_id = _commit_id; 634 | 635 | UPDATE postgres_ci.projects SET last_build_id = _build_id WHERE project_id = _project_id; 636 | end; 637 | $$ language plpgsql security definer; 638 | 639 | /* source file: src/functions/build/stop.sql */ 640 | 641 | create or replace function build.stop(_build_id int, _config text, _error text) returns void as $$ 642 | begin 643 | 644 | UPDATE postgres_ci.builds 645 | SET 646 | config = _config, 647 | error = _error, 648 | status = ( 649 | CASE 650 | WHEN _error = '' THEN 'success' 651 | ELSE 'failed' 652 | END 653 | )::postgres_ci.status, 654 | finished_at = current_timestamp 655 | WHERE build_id = _build_id 656 | AND status = 'running'; 657 | 658 | IF NOT FOUND THEN 659 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 660 | END IF; 661 | 662 | IF EXISTS( 663 | SELECT 664 | FROM postgres_ci.parts 665 | WHERE build_id = _build_id 666 | AND success IS False 667 | LIMIT 1 668 | ) THEN 669 | UPDATE postgres_ci.builds SET status = 'failed'::postgres_ci.status WHERE build_id = _build_id; 670 | END IF; 671 | 672 | end; 673 | $$ language plpgsql security definer; 674 | 675 | 676 | /* source file: src/functions/build/view.sql */ 677 | 678 | create or replace function build.view( 679 | _build_id int, 680 | 681 | out project_id int, 682 | out project_name text, 683 | out branch_id int, 684 | out branch_name text, 685 | out config text, 686 | out error text, 687 | out status postgres_ci.status, 688 | out commit_sha text, 689 | out commit_message text, 690 | out committed_at timestamptz, 691 | out committer_name text, 692 | out committer_email text, 693 | out author_name text, 694 | out author_email text, 695 | out created_at timestamptz, 696 | out parts jsonb 697 | ) returns record as $$ 698 | begin 699 | 700 | SELECT 701 | B.project_id, 702 | P.project_name, 703 | B.branch_id, 704 | BR.branch, 705 | B.config, 706 | B.error, 707 | B.status, 708 | C.commit_sha, 709 | C.commit_message, 710 | C.committed_at, 711 | C.committer_name, 712 | C.committer_email, 713 | C.author_name, 714 | C.author_email, 715 | B.created_at, 716 | ( 717 | SELECT 718 | COALESCE(array_to_json(array_agg(P.*)), '[]') 719 | FROM ( 720 | SELECT 721 | part_id, 722 | image, 723 | version, 724 | output, 725 | success, 726 | started_at, 727 | finished_at, 728 | ( 729 | SELECT 730 | COALESCE(array_to_json(array_agg(T.*)), '[]') 731 | FROM ( 732 | SELECT 733 | function, 734 | errors, 735 | duration 736 | FROM postgres_ci.tests 737 | WHERE part_id = parts.part_id 738 | ORDER BY 739 | jsonb_array_length(errors) DESC, 740 | function 741 | ) AS T 742 | ) AS tests 743 | FROM postgres_ci.parts 744 | WHERE build_id = B.build_id 745 | ORDER BY part_id 746 | ) AS P 747 | ) 748 | INTO 749 | project_id, 750 | project_name, 751 | branch_id, 752 | branch_name, 753 | config, 754 | error, 755 | status, 756 | commit_sha, 757 | commit_message, 758 | committed_at, 759 | committer_name, 760 | committer_email, 761 | author_name, 762 | author_email, 763 | created_at, 764 | parts 765 | FROM postgres_ci.builds AS B 766 | JOIN postgres_ci.projects AS P USING(project_id) 767 | JOIN postgres_ci.branches AS BR ON BR.branch_id = B.branch_id 768 | JOIN postgres_ci.commits AS C ON C.commit_id = B.commit_id 769 | WHERE B.build_id = _build_id; 770 | 771 | IF NOT FOUND THEN 772 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 773 | END IF; 774 | end; 775 | $$ language plpgsql security definer; 776 | 777 | 778 | 779 | /* source file: src/functions/project/add_commit.sql */ 780 | 781 | create or replace function project.add_commit( 782 | _project_id int, 783 | _branch text, 784 | _commit_sha text, 785 | _commit_message text, 786 | _committed_at timestamptz, 787 | _committer_name text, 788 | _committer_email text, 789 | _author_name text, 790 | _author_email text, 791 | out commit_id int 792 | ) returns int as $$ 793 | declare 794 | _branch_id int; 795 | begin 796 | 797 | _branch_id = project.get_branch_id(_project_id, _branch); 798 | 799 | BEGIN 800 | 801 | INSERT INTO postgres_ci.commits ( 802 | project_id, 803 | branch_id, 804 | commit_sha, 805 | commit_message, 806 | committed_at, 807 | committer_name, 808 | committer_email, 809 | author_name, 810 | author_email 811 | ) VALUES ( 812 | _project_id, 813 | _branch_id, 814 | _commit_sha, 815 | _commit_message, 816 | _committed_at, 817 | _committer_name, 818 | _committer_email, 819 | _author_name, 820 | _author_email 821 | ) RETURNING commits.commit_id INTO commit_id; 822 | 823 | PERFORM build.new(_project_id, _branch_id, commit_id); 824 | 825 | EXCEPTION WHEN unique_violation THEN 826 | 827 | SELECT 828 | C.commit_id INTO commit_id 829 | FROM postgres_ci.commits C 830 | WHERE C.branch_id = _branch_id 831 | AND C.commit_sha = _commit_sha; 832 | END; 833 | 834 | end; 835 | $$ language plpgsql security definer; 836 | 837 | 838 | /* source file: src/functions/project/add.sql */ 839 | 840 | create or replace function project.add( 841 | _project_name text, 842 | _project_owner_id int, 843 | _repository_url text, 844 | _github_secret text, 845 | out project_id int 846 | ) returns int as $$ 847 | begin 848 | 849 | INSERT INTO postgres_ci.projects ( 850 | project_name, 851 | project_owner_id, 852 | repository_url, 853 | github_name, 854 | github_secret 855 | ) VALUES ( 856 | _project_name, 857 | _project_owner_id, 858 | _repository_url, 859 | project.github_name(_repository_url), 860 | _github_secret 861 | ) RETURNING projects.project_id INTO project_id; 862 | 863 | end; 864 | $$ language plpgsql security definer; 865 | 866 | 867 | /* source file: src/functions/project/delete.sql */ 868 | 869 | create or replace function project.delete(_project_id int) returns void as $$ 870 | begin 871 | UPDATE postgres_ci.projects 872 | SET 873 | is_deleted = true, 874 | updated_at = current_timestamp 875 | WHERE project_id = _project_id; 876 | end; 877 | $$ language plpgsql security definer; 878 | 879 | /* source file: src/functions/project/get_branch_id.sql */ 880 | 881 | create or replace function project.get_branch_id(_project_id int, _branch text, out branch_id int) returns int as $$ 882 | begin 883 | 884 | SELECT 885 | B.branch_id INTO branch_id 886 | FROM postgres_ci.branches AS B 887 | WHERE B.project_id = _project_id 888 | AND B.branch = _branch; 889 | 890 | IF NOT FOUND THEN 891 | 892 | INSERT INTO postgres_ci.branches ( 893 | project_id, 894 | branch 895 | ) VALUES ( 896 | _project_id, 897 | _branch 898 | ) RETURNING branches.branch_id INTO branch_id; 899 | 900 | END IF; 901 | end; 902 | $$ language plpgsql security definer; 903 | 904 | /* source file: src/functions/project/get_github_secret.sql */ 905 | 906 | create or replace function project.get_github_secret(_github_name text) returns table( 907 | secret text 908 | ) as $$ 909 | begin 910 | return query 911 | SELECT 912 | github_secret 913 | FROM postgres_ci.projects 914 | WHERE github_name = _github_name 915 | AND is_deleted = false; 916 | end 917 | $$ language plpgsql security definer rows 1; 918 | 919 | /* source file: src/functions/project/get_possible_owners.sql */ 920 | 921 | create or replace function project.get_possible_owners() returns table ( 922 | user_id int, 923 | user_name text 924 | ) as $$ 925 | begin 926 | 927 | return query 928 | SELECT 929 | U.user_id, 930 | U.user_name 931 | FROM postgres_ci.users AS U 932 | WHERE U.is_deleted = false 933 | ORDER BY U.user_id; 934 | 935 | end; 936 | $$ language plpgsql security definer; 937 | 938 | /* source file: src/functions/project/get.sql */ 939 | 940 | create or replace function project.get( 941 | _project_id int, 942 | out project_id int, 943 | out project_name text, 944 | out project_token text, 945 | out repository_url text, 946 | out project_owner_id int, 947 | out possible_owners jsonb, 948 | out github_secret text, 949 | out created_at timestamptz, 950 | out updated_at timestamptz 951 | ) returns record as $$ 952 | begin 953 | 954 | SELECT 955 | P.project_id, 956 | P.project_name, 957 | P.project_token, 958 | P.repository_url, 959 | P.project_owner_id, 960 | ( 961 | SELECT 962 | COALESCE(array_to_json(array_agg(U.*)), '[]') 963 | FROM ( 964 | SELECT 965 | user_id, 966 | user_name 967 | FROM postgres_ci.users 968 | WHERE is_deleted = false 969 | ORDER BY user_id 970 | ) U 971 | ), 972 | P.github_secret, 973 | P.created_at, 974 | P.updated_at 975 | 976 | INTO 977 | project_id, 978 | project_name, 979 | project_token, 980 | repository_url, 981 | project_owner_id, 982 | possible_owners, 983 | github_secret, 984 | created_at, 985 | updated_at 986 | FROM postgres_ci.projects AS P 987 | WHERE P.project_id = _project_id 988 | AND P.is_deleted = false; 989 | 990 | IF NOT FOUND THEN 991 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 992 | END IF; 993 | 994 | end; 995 | $$ language plpgsql security definer; 996 | 997 | /* source file: src/functions/project/github_name.sql */ 998 | 999 | create or replace function project.github_name(_repository_url text) returns text as $$ 1000 | begin 1001 | CASE 1002 | WHEN _repository_url LIKE 'https://github\.com%' THEN 1003 | return replace((string_to_array(_repository_url, 'github.com/'))[2], '.git', ''); 1004 | WHEN _repository_url LIKE '%@github\.com:%' THEN 1005 | return replace((string_to_array(_repository_url, 'github.com:'))[2], '.git', ''); 1006 | ELSE 1007 | return ''; 1008 | END CASE; 1009 | end; 1010 | $$ language plpgsql security definer; 1011 | 1012 | /* source file: src/functions/project/list.sql */ 1013 | 1014 | create or replace function project.list() returns table ( 1015 | project_id int, 1016 | project_name text, 1017 | project_token uuid, 1018 | project_owner_id int, 1019 | user_email text, 1020 | user_name text, 1021 | status postgres_ci.status, 1022 | commit_sha text, 1023 | last_build_id int, 1024 | started_at timestamptz, 1025 | finished_at timestamptz 1026 | ) as $$ 1027 | begin 1028 | return query 1029 | SELECT 1030 | P.project_id, 1031 | P.project_name, 1032 | P.project_token, 1033 | P.project_owner_id, 1034 | U.user_email, 1035 | U.user_name, 1036 | B.status, 1037 | C.commit_sha, 1038 | P.last_build_id, 1039 | B.started_at, 1040 | B.finished_at 1041 | FROM postgres_ci.projects AS P 1042 | JOIN postgres_ci.users AS U ON U.user_id = P.project_owner_id 1043 | LEFT JOIN postgres_ci.builds AS B ON B.build_id = P.last_build_id 1044 | LEFT JOIN postgres_ci.commits AS C ON C.commit_id = B.commit_id 1045 | WHERE P.is_deleted = false 1046 | ORDER BY P.project_name; 1047 | 1048 | end; 1049 | $$ language plpgsql security definer; 1050 | 1051 | /* source file: src/functions/project/update.sql */ 1052 | 1053 | create or replace function project.update( 1054 | _project_id int, 1055 | _project_name text, 1056 | _project_owner_id int, 1057 | _repository_url text, 1058 | _github_secret text 1059 | ) returns void as $$ 1060 | begin 1061 | 1062 | UPDATE postgres_ci.projects 1063 | SET 1064 | project_name = _project_name, 1065 | project_owner_id = _project_owner_id, 1066 | repository_url = _repository_url, 1067 | github_name = project.github_name(_repository_url), 1068 | github_secret = _github_secret 1069 | WHERE project_id = _project_id; 1070 | 1071 | IF NOT FOUND THEN 1072 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 1073 | END IF; 1074 | end; 1075 | $$ language plpgsql security definer; 1076 | 1077 | 1078 | /* source file: src/functions/hook/commit.sql */ 1079 | 1080 | create or replace function hook.commit( 1081 | _token uuid, 1082 | _branch text, 1083 | _commit_sha text, 1084 | _commit_message text, 1085 | _committed_at timestamptz, 1086 | _committer_name text, 1087 | _committer_email text, 1088 | _author_name text, 1089 | _author_email text, 1090 | out commit_id int 1091 | ) returns int as $$ 1092 | declare 1093 | _project_id int; 1094 | begin 1095 | 1096 | SELECT project_id INTO _project_id FROM postgres_ci.projects WHERE project_token = _token AND is_deleted = false; 1097 | 1098 | IF NOT FOUND THEN 1099 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 1100 | END IF; 1101 | 1102 | SELECT project.add_commit( 1103 | _project_id, 1104 | _branch, 1105 | _commit_sha, 1106 | _commit_message, 1107 | _committed_at, 1108 | _committer_name, 1109 | _committer_email, 1110 | _author_name, 1111 | _author_email 1112 | ) INTO commit_id; 1113 | 1114 | end; 1115 | $$ language plpgsql security definer; 1116 | 1117 | /* source file: src/functions/hook/github_push.sql */ 1118 | 1119 | create or replace function hook.github_push( 1120 | _github_name text, 1121 | _branch text, 1122 | _commits jsonb 1123 | ) returns table ( 1124 | commit_id int 1125 | ) as $$ 1126 | declare 1127 | _project_id int; 1128 | begin 1129 | 1130 | SELECT project_id INTO _project_id FROM postgres_ci.projects WHERE github_name = _github_name AND is_deleted = false; 1131 | 1132 | IF NOT FOUND THEN 1133 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 1134 | END IF; 1135 | 1136 | return query 1137 | 1138 | SELECT 1139 | project.add_commit( 1140 | _project_id, 1141 | _branch, 1142 | C.commit_sha, 1143 | C.commit_message, 1144 | C.committed_at, 1145 | C.committer_name, 1146 | C.committer_email, 1147 | C.author_name, 1148 | C.author_email 1149 | ) 1150 | FROM jsonb_populate_recordset(null::postgres_ci.commits, _commits) AS C; 1151 | end; 1152 | $$ language plpgsql security definer; 1153 | 1154 | /* source file: src/functions/hook/push.sql */ 1155 | 1156 | create or replace function hook.push( 1157 | _token uuid, 1158 | _branch text, 1159 | _commits jsonb 1160 | ) returns table ( 1161 | commit_id int 1162 | ) as $$ 1163 | declare 1164 | _project_id int; 1165 | begin 1166 | 1167 | SELECT project_id INTO _project_id FROM postgres_ci.projects WHERE project_token = _token AND is_deleted = false; 1168 | 1169 | IF NOT FOUND THEN 1170 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 1171 | END IF; 1172 | 1173 | return query 1174 | 1175 | SELECT 1176 | project.add_commit( 1177 | _project_id, 1178 | _branch, 1179 | C.commit_sha, 1180 | C.commit_message, 1181 | C.committed_at, 1182 | C.committer_name, 1183 | C.committer_email, 1184 | C.author_name, 1185 | C.author_email 1186 | ) 1187 | FROM jsonb_populate_recordset(null::postgres_ci.commits, _commits) AS C; 1188 | end; 1189 | $$ language plpgsql security definer; 1190 | 1191 | 1192 | /* source file: src/functions/password/change.sql */ 1193 | 1194 | create or replace function password.change( 1195 | _user_id int, 1196 | _current_password text, 1197 | _new_password text 1198 | ) returns boolean as $$ 1199 | declare 1200 | _salt text; 1201 | begin 1202 | 1203 | IF password.check(_user_id, _current_password) THEN 1204 | 1205 | _salt = postgres_ci.sha1(gen_salt('md5') || current_timestamp); 1206 | 1207 | UPDATE postgres_ci.users 1208 | SET 1209 | hash = encode(digest(_salt || _new_password, 'sha1'), 'hex'), 1210 | salt = _salt 1211 | WHERE user_id = _user_id; 1212 | 1213 | END IF; 1214 | 1215 | return true; 1216 | end; 1217 | $$ language plpgsql security definer; 1218 | 1219 | /* source file: src/functions/password/check.sql */ 1220 | 1221 | create or replace function password.check(_user_id int, _password text) returns boolean as $$ 1222 | declare 1223 | _invalid_password boolean; 1224 | begin 1225 | 1226 | SELECT 1227 | encode(digest(U.salt || _password, 'sha1'), 'hex') != U.hash 1228 | INTO 1229 | _invalid_password 1230 | FROM postgres_ci.users AS U 1231 | WHERE user_id = _user_id 1232 | AND is_deleted = false; 1233 | 1234 | CASE 1235 | WHEN NOT FOUND THEN 1236 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 1237 | WHEN _invalid_password THEN 1238 | RAISE EXCEPTION 'INVALID_PASSWORD' USING ERRCODE = 'invalid_password'; 1239 | ELSE 1240 | return true; 1241 | END CASE; 1242 | 1243 | end; 1244 | $$ language plpgsql security definer; 1245 | 1246 | /* source file: src/functions/password/reset.sql */ 1247 | 1248 | create or replace function password.reset(_user_id int, _password text) returns void as $$ 1249 | declare 1250 | _salt text; 1251 | begin 1252 | _salt = postgres_ci.sha1(gen_salt('md5') || current_timestamp); 1253 | UPDATE postgres_ci.users 1254 | SET 1255 | hash = encode(digest(_salt || _password, 'sha1'), 'hex'), 1256 | salt = _salt, 1257 | updated_at = current_timestamp 1258 | WHERE user_id = _user_id; 1259 | end; 1260 | $$ language plpgsql security definer; 1261 | 1262 | /* source file: src/functions/users/add.sql */ 1263 | 1264 | create or replace function users.add( 1265 | _user_login text, 1266 | _password text, 1267 | _user_name text, 1268 | _user_email text, 1269 | _is_superuser boolean, 1270 | out user_id int 1271 | ) returns int as $$ 1272 | declare 1273 | _salt text; 1274 | _message text; 1275 | _column_name text; 1276 | _constraint_name text; 1277 | _datatype_name text; 1278 | _table_name text; 1279 | _schema_name text; 1280 | begin 1281 | 1282 | _salt = postgres_ci.sha1(gen_salt('md5') || current_timestamp); 1283 | 1284 | BEGIN 1285 | 1286 | INSERT INTO postgres_ci.users ( 1287 | user_login, 1288 | user_name, 1289 | user_email, 1290 | is_superuser, 1291 | hash, 1292 | salt 1293 | ) VALUES ( 1294 | _user_login, 1295 | _user_name, 1296 | _user_email, 1297 | _is_superuser, 1298 | encode(digest(_salt || _password, 'sha1'), 'hex'), 1299 | _salt 1300 | ) RETURNING users.user_id INTO user_id; 1301 | 1302 | EXCEPTION WHEN OTHERS THEN 1303 | 1304 | GET STACKED DIAGNOSTICS 1305 | _column_name = column_name, 1306 | _constraint_name = constraint_name, 1307 | _datatype_name = pg_datatype_name, 1308 | _table_name = table_name, 1309 | _schema_name = schema_name; 1310 | 1311 | CASE 1312 | WHEN _constraint_name = 'unique_user_login' THEN 1313 | _message = 'LOGIN_ALREADY_EXISTS'; 1314 | WHEN _constraint_name = 'unique_user_email' THEN 1315 | _message = 'EMAIL_ALREADY_EXISTS'; 1316 | WHEN _constraint_name = 'check_user_email' THEN 1317 | _message = 'INVALID_EMAIL'; 1318 | ELSE 1319 | _message = SQLERRM; 1320 | END CASE; 1321 | 1322 | RAISE EXCEPTION USING 1323 | MESSAGE = _message, 1324 | ERRCODE = SQLSTATE, 1325 | COLUMN = _column_name, 1326 | CONSTRAINT = _constraint_name, 1327 | DATATYPE = _datatype_name, 1328 | TABLE = _table_name, 1329 | SCHEMA = _schema_name; 1330 | END; 1331 | 1332 | end; 1333 | $$ language plpgsql security definer; 1334 | 1335 | 1336 | 1337 | 1338 | /* source file: src/functions/users/delete.sql */ 1339 | 1340 | create or replace function users.delete(_user_id int) returns void as $$ 1341 | begin 1342 | 1343 | IF EXISTS( 1344 | SELECT 1345 | null 1346 | FROM postgres_ci.users 1347 | WHERE is_deleted = false 1348 | AND is_superuser = true 1349 | AND user_id = _user_id 1350 | ) THEN 1351 | RAISE EXCEPTION 'IS_SUPERUSER' USING ERRCODE = 'check_violation'; 1352 | END IF; 1353 | 1354 | UPDATE postgres_ci.users 1355 | SET 1356 | is_deleted = true, 1357 | updated_at = CURRENT_TIMESTAMP 1358 | WHERE user_id = _user_id 1359 | AND is_deleted = false; 1360 | 1361 | IF NOT FOUND THEN 1362 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 1363 | END IF; 1364 | end; 1365 | $$ language plpgsql security definer; 1366 | 1367 | /* source file: src/functions/users/get.sql */ 1368 | 1369 | create or replace function users.get( 1370 | _user_id int, 1371 | out user_id int, 1372 | out user_name text, 1373 | out user_login text, 1374 | out user_email text, 1375 | out is_superuser boolean, 1376 | out created_at timestamptz, 1377 | out updated_at timestamptz 1378 | ) returns record as $$ 1379 | begin 1380 | SELECT 1381 | U.user_id, 1382 | U.user_name, 1383 | U.user_login, 1384 | U.user_email, 1385 | U.is_superuser, 1386 | U.created_at, 1387 | U.updated_at 1388 | INTO 1389 | user_id, 1390 | user_name, 1391 | user_login, 1392 | user_email, 1393 | is_superuser, 1394 | created_at, 1395 | updated_at 1396 | FROM postgres_ci.users AS U 1397 | WHERE U.user_id = _user_id 1398 | AND U.is_deleted = false; 1399 | 1400 | IF NOT FOUND THEN 1401 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 1402 | END IF; 1403 | 1404 | end; 1405 | $$ language plpgsql security definer; 1406 | 1407 | /* source file: src/functions/users/list.sql */ 1408 | 1409 | create or replace function users.list( 1410 | _limit int, 1411 | _offset int, 1412 | _query text, 1413 | 1414 | out total bigint, 1415 | out users jsonb 1416 | ) returns record as $$ 1417 | declare 1418 | _pattern text; 1419 | begin 1420 | 1421 | IF _query <> '' THEN 1422 | _pattern = '%' || array_to_string(string_to_array(lower(_query), ' '), '%') || '%'; 1423 | END IF; 1424 | 1425 | SELECT 1426 | ( 1427 | SELECT 1428 | COUNT(*) 1429 | FROM postgres_ci.users 1430 | WHERE is_deleted = false 1431 | AND ( 1432 | CASE WHEN _pattern IS NOT NULL 1433 | THEN lower(user_name || user_login || user_email) LIKE _pattern 1434 | ELSE true 1435 | END 1436 | ) 1437 | ), 1438 | ( 1439 | SELECT 1440 | COALESCE(array_to_json(array_agg(U.*)), '[]') 1441 | FROM ( 1442 | SELECT 1443 | user_id, 1444 | user_name, 1445 | user_login, 1446 | user_email, 1447 | is_superuser, 1448 | created_at, 1449 | updated_at 1450 | FROM postgres_ci.users 1451 | WHERE is_deleted = false 1452 | AND ( 1453 | CASE WHEN _pattern IS NOT NULL 1454 | THEN lower(user_name || user_login || user_email) LIKE _pattern 1455 | ELSE true 1456 | END 1457 | ) 1458 | ORDER BY user_id 1459 | LIMIT _limit 1460 | OFFSET _offset 1461 | ) U 1462 | ) 1463 | INTO total, users; 1464 | end; 1465 | $$ language plpgsql security definer; 1466 | 1467 | /* source file: src/functions/users/update.sql */ 1468 | 1469 | create or replace function users.update( 1470 | _user_id int, 1471 | _user_name text, 1472 | _user_email text, 1473 | _is_superuser boolean 1474 | ) returns void as $$ 1475 | declare 1476 | _message text; 1477 | _column_name text; 1478 | _constraint_name text; 1479 | _datatype_name text; 1480 | _table_name text; 1481 | _schema_name text; 1482 | begin 1483 | 1484 | BEGIN 1485 | UPDATE postgres_ci.users 1486 | SET 1487 | user_name = _user_name, 1488 | user_email = _user_email, 1489 | is_superuser = _is_superuser, 1490 | updated_at = current_timestamp 1491 | WHERE user_id = _user_id; 1492 | 1493 | EXCEPTION WHEN OTHERS THEN 1494 | 1495 | GET STACKED DIAGNOSTICS 1496 | _column_name = column_name, 1497 | _constraint_name = constraint_name, 1498 | _datatype_name = pg_datatype_name, 1499 | _table_name = table_name, 1500 | _schema_name = schema_name; 1501 | 1502 | CASE 1503 | WHEN _constraint_name = 'unique_user_email' THEN 1504 | _message = 'EMAIL_ALREADY_EXISTS'; 1505 | WHEN _constraint_name = 'check_user_email' THEN 1506 | _message = 'INVALID_EMAIL'; 1507 | ELSE 1508 | _message = SQLERRM; 1509 | END CASE; 1510 | 1511 | RAISE EXCEPTION USING 1512 | MESSAGE = _message, 1513 | ERRCODE = SQLSTATE, 1514 | COLUMN = _column_name, 1515 | CONSTRAINT = _constraint_name, 1516 | DATATYPE = _datatype_name, 1517 | TABLE = _table_name, 1518 | SCHEMA = _schema_name; 1519 | END; 1520 | 1521 | end; 1522 | $$ language plpgsql security definer; 1523 | 1524 | 1525 | -------------------------------------------------------------------------------- /postgres_ci.control: -------------------------------------------------------------------------------- 1 | comment = 'Postgres-CI' 2 | default_version = '0.3' 3 | superuser = false 4 | relocatable = false 5 | requires = 'plpgsql, pgcrypto, pg_trgm' 6 | schema = 'postgres_ci' -------------------------------------------------------------------------------- /src/functions/auth/gc.sql: -------------------------------------------------------------------------------- 1 | create or replace function auth.gc() returns void as $$ 2 | begin 3 | DELETE FROM postgres_ci.sessions WHERE expires_at < CURRENT_TIMESTAMP; 4 | end; 5 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/auth/get_user.sql: -------------------------------------------------------------------------------- 1 | create or replace function auth.get_user( 2 | _session_id text 3 | ) returns table( 4 | user_id int, 5 | user_name text, 6 | user_login text, 7 | user_email text, 8 | is_superuser boolean, 9 | created_at timestamptz 10 | ) as $$ 11 | begin 12 | 13 | return query 14 | SELECT 15 | U.user_id, 16 | U.user_name, 17 | U.user_login, 18 | U.user_email, 19 | U.is_superuser, 20 | U.created_at 21 | FROM postgres_ci.users AS U 22 | JOIN postgres_ci.sessions AS S USING(user_id) 23 | WHERE U.is_deleted = false 24 | AND S.session_id = _session_id 25 | AND S.expires_at > CURRENT_TIMESTAMP; 26 | 27 | IF FOUND THEN 28 | UPDATE postgres_ci.sessions 29 | SET 30 | expires_at = CURRENT_TIMESTAMP + '1 hour'::interval 31 | WHERE session_id = _session_id; 32 | END IF; 33 | end; 34 | $$ language plpgsql security definer rows 1; -------------------------------------------------------------------------------- /src/functions/auth/login.sql: -------------------------------------------------------------------------------- 1 | create or replace function auth.login( 2 | _login text, 3 | _password text, 4 | out session_id text 5 | ) returns text as $$ 6 | declare 7 | _user_id int; 8 | _invalid_password boolean; 9 | begin 10 | 11 | SELECT 12 | U.user_id, 13 | encode(digest(U.salt || _password, 'sha1'), 'hex') != U.hash 14 | INTO 15 | _user_id, 16 | _invalid_password 17 | FROM postgres_ci.users AS U 18 | WHERE lower(U.user_login) = lower(_login) 19 | AND is_deleted = false; 20 | 21 | CASE 22 | WHEN NOT FOUND THEN 23 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 24 | WHEN _invalid_password THEN 25 | RAISE EXCEPTION 'INVALID_PASSWORD' USING ERRCODE = 'invalid_password'; 26 | ELSE 27 | INSERT INTO postgres_ci.sessions ( 28 | user_id, 29 | expires_at 30 | ) VALUES ( 31 | _user_id, 32 | CURRENT_TIMESTAMP + '1 hour'::interval 33 | ) RETURNING sessions.session_id INTO session_id; 34 | END CASE; 35 | end; 36 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/auth/logout.sql: -------------------------------------------------------------------------------- 1 | create or replace function auth.logout(_session_id text) returns void as $$ 2 | begin 3 | DELETE FROM postgres_ci.sessions WHERE session_id = _session_id; 4 | end; 5 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/build/accept.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.accept( 2 | _build_id int, 3 | out accept boolean 4 | ) returns boolean as $$ 5 | begin 6 | 7 | UPDATE postgres_ci.builds 8 | SET status = 'accepted' 9 | WHERE status = 'pending' 10 | AND build_id = _build_id; 11 | 12 | IF NOT FOUND THEN 13 | accept = false; 14 | return; 15 | END IF; 16 | 17 | accept = true; 18 | end; 19 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/build/add_part.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.add_part( 2 | _build_id int, 3 | _version text, 4 | _image text, 5 | _container_id text, 6 | _output text, 7 | _started_at timestamptz, 8 | _tests jsonb, 9 | out part_id int 10 | ) returns int as $$ 11 | declare 12 | _test postgres_ci.tests; 13 | begin 14 | 15 | INSERT INTO postgres_ci.parts ( 16 | build_id, 17 | version, 18 | image, 19 | container_id, 20 | output, 21 | success, 22 | started_at, 23 | finished_at 24 | ) VALUES ( 25 | _build_id, 26 | _version, 27 | _image, 28 | _container_id, 29 | _output, 30 | true, 31 | _started_at, 32 | CURRENT_TIMESTAMP 33 | ) RETURNING parts.part_id INTO add_part.part_id; 34 | 35 | INSERT INTO postgres_ci.tests ( 36 | part_id, 37 | function, 38 | errors, 39 | duration 40 | ) 41 | SELECT 42 | add_part.part_id, 43 | E.function, 44 | E.errors, 45 | E.duration 46 | FROM jsonb_populate_recordset(null::postgres_ci.tests, _tests) AS E; 47 | 48 | IF EXISTS( 49 | SELECT 50 | FROM postgres_ci.tests 51 | WHERE tests.part_id = add_part.part_id 52 | AND jsonb_array_length(errors) > 0 53 | LIMIT 1 54 | ) THEN 55 | UPDATE postgres_ci.parts SET success = false WHERE parts.part_id = add_part.part_id; 56 | END IF; 57 | 58 | end; 59 | $$ language plpgsql security definer; 60 | -------------------------------------------------------------------------------- /src/functions/build/fetch.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.fetch() returns table ( 2 | build_id int, 3 | created_at timestamptz 4 | ) as $$ 5 | declare 6 | _build_id int; 7 | _created_at timestamptz; 8 | begin 9 | 10 | SELECT 11 | B.build_id, 12 | B.created_at 13 | INTO 14 | _build_id, 15 | _created_at 16 | FROM postgres_ci.builds AS B 17 | WHERE B.status = 'pending' 18 | ORDER BY B.build_id 19 | LIMIT 1 20 | FOR UPDATE SKIP LOCKED; 21 | 22 | IF NOT FOUND THEN 23 | return; 24 | END IF; 25 | 26 | UPDATE postgres_ci.builds AS B SET status = 'accepted' WHERE B.build_id = _build_id; 27 | 28 | return query 29 | SELECT _build_id, _created_at; 30 | end; 31 | $$ language plpgsql security definer rows 1; -------------------------------------------------------------------------------- /src/functions/build/gc.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.gc() returns void as $$ 2 | declare 3 | _build_id int; 4 | begin 5 | 6 | FOR _build_id IN 7 | SELECT 8 | build_id 9 | FROM postgres_ci.builds 10 | WHERE status IN ('accepted', 'running') 11 | AND created_at < (current_timestamp - '1 hour'::interval) 12 | ORDER BY build_id 13 | LOOP 14 | UPDATE postgres_ci.builds AS B 15 | SET 16 | status = 'failed', 17 | error = 'Execution timeout', 18 | finished_at = current_timestamp 19 | WHERE B.build_id = _build_id; 20 | 21 | PERFORM 22 | pg_notify('postgres-ci::stop_container', ( 23 | SELECT to_json(T.*) FROM ( 24 | SELECT 25 | P.container_id, 26 | current_timestamp AS created_at 27 | ) T 28 | )::text 29 | ) 30 | FROM postgres_ci.parts AS P 31 | WHERE P.build_id = _build_id; 32 | 33 | PERFORM build.notify(_build_id); 34 | END LOOP; 35 | end; 36 | $$ language plpgsql security definer; 37 | -------------------------------------------------------------------------------- /src/functions/build/list.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.list( 2 | _project_id int, 3 | _branch_id int, 4 | _limit int, 5 | _offset int, 6 | out project_id int, 7 | out project_name text, 8 | out total bigint, 9 | out branches jsonb, 10 | out items jsonb 11 | ) returns record as $$ 12 | begin 13 | 14 | SELECT 15 | P.project_id, 16 | P.project_name, 17 | ( 18 | SELECT 19 | COALESCE(SUM(C.counter), 0) 20 | FROM postgres_ci.builds_counters AS C 21 | WHERE C.project_id = _project_id 22 | AND ( 23 | CASE WHEN _branch_id <> 0 24 | THEN branch_id = _branch_id 25 | ELSE true 26 | END 27 | ) 28 | ), 29 | ( 30 | SELECT 31 | COALESCE(array_to_json(array_agg(R.*)), '[]') 32 | FROM ( 33 | SELECT 34 | B.branch_id, 35 | B.branch 36 | FROM postgres_ci.branches AS B 37 | WHERE 38 | B.project_id = _project_id 39 | ORDER BY branch 40 | ) AS R 41 | ), 42 | ( 43 | SELECT 44 | COALESCE(array_to_json(array_agg(R.*)), '[]') 45 | FROM ( 46 | SELECT 47 | BD.build_id, 48 | BD.project_id, 49 | BD.status, 50 | BD.error, 51 | BD.created_at, 52 | BD.started_at, 53 | BD.finished_at, 54 | C.commit_sha, 55 | C.commit_message, 56 | B.branch, 57 | B.branch_id 58 | FROM postgres_ci.builds AS BD 59 | JOIN postgres_ci.commits AS C USING(commit_id) 60 | JOIN postgres_ci.branches AS B ON B.branch_id = C.branch_id 61 | WHERE 62 | BD.project_id = _project_id 63 | AND ( 64 | CASE WHEN _branch_id <> 0 65 | THEN BD.branch_id = _branch_id 66 | ELSE true 67 | END 68 | ) 69 | ORDER BY build_id DESC 70 | LIMIT _limit 71 | OFFSET _offset 72 | ) AS R 73 | ) 74 | FROM postgres_ci.projects AS P 75 | WHERE P.project_id = _project_id 76 | AND P.is_deleted = false 77 | INTO project_id, project_name, total, branches, items; 78 | 79 | end; 80 | $$ language plpgsql security definer; 81 | -------------------------------------------------------------------------------- /src/functions/build/new.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.new( 2 | _project_id int, 3 | _branch_id int, 4 | _commit_id int, 5 | out build_id int 6 | ) returns int as $$ 7 | begin 8 | 9 | INSERT INTO postgres_ci.builds ( 10 | project_id, 11 | branch_id, 12 | commit_id, 13 | config, 14 | status 15 | ) VALUES ( 16 | _project_id, 17 | _branch_id, 18 | _commit_id, 19 | '', 20 | 'pending' 21 | ) RETURNING builds.build_id INTO build_id; 22 | 23 | INSERT INTO postgres_ci.builds_counters AS C ( 24 | project_id, 25 | branch_id, 26 | counter 27 | ) VALUES ( 28 | _project_id, 29 | _branch_id, 30 | 1 31 | ) ON CONFLICT 32 | ON CONSTRAINT unique_builds_counters DO UPDATE 33 | SET counter = C.counter + 1; 34 | 35 | PERFORM pg_notify('postgres-ci::tasks', ( 36 | SELECT to_json(T.*) FROM ( 37 | SELECT 38 | new.build_id AS build_id, 39 | CURRENT_TIMESTAMP AS created_at 40 | ) T 41 | )::text 42 | ); 43 | 44 | end; 45 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/build/notify.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.notify(_build_id int) returns boolean as $$ 2 | begin 3 | 4 | INSERT INTO postgres_ci.notification (build_id) VALUES (_build_id); 5 | 6 | PERFORM pg_notify('postgres-ci::notification', ( 7 | SELECT to_json(T.*) FROM ( 8 | SELECT 9 | _build_id AS build_id, 10 | CURRENT_TIMESTAMP AS created_at 11 | ) T 12 | )::text 13 | ); 14 | 15 | return true; 16 | 17 | end; 18 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/build/start.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.start( 2 | _build_id int, 3 | out repository_url text, 4 | out branch text, 5 | out revision text 6 | ) returns record as $$ 7 | declare 8 | _commit_id int; 9 | _project_id int; 10 | begin 11 | 12 | UPDATE postgres_ci.builds AS B 13 | SET 14 | status = 'running', 15 | started_at = current_timestamp 16 | WHERE B.build_id = _build_id 17 | AND B.status = 'accepted' 18 | RETURNING B.commit_id INTO _commit_id; 19 | 20 | IF NOT FOUND THEN 21 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 22 | END IF; 23 | 24 | SELECT 25 | P.project_id, 26 | P.repository_url, 27 | B.branch, 28 | C.commit_sha 29 | INTO 30 | _project_id, 31 | repository_url, 32 | branch, 33 | revision 34 | FROM postgres_ci.projects AS P 35 | JOIN postgres_ci.branches AS B USING(project_id) 36 | JOIN postgres_ci.commits AS C ON C.branch_id = B.branch_id 37 | WHERE C.commit_id = _commit_id; 38 | 39 | UPDATE postgres_ci.projects SET last_build_id = _build_id WHERE project_id = _project_id; 40 | end; 41 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/build/stop.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.stop(_build_id int, _config text, _error text) returns void as $$ 2 | begin 3 | 4 | UPDATE postgres_ci.builds 5 | SET 6 | config = _config, 7 | error = _error, 8 | status = ( 9 | CASE 10 | WHEN _error = '' THEN 'success' 11 | ELSE 'failed' 12 | END 13 | )::postgres_ci.status, 14 | finished_at = current_timestamp 15 | WHERE build_id = _build_id 16 | AND status = 'running'; 17 | 18 | IF NOT FOUND THEN 19 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 20 | END IF; 21 | 22 | PERFORM build.notify(_build_id); 23 | 24 | IF EXISTS( 25 | SELECT 26 | FROM postgres_ci.parts 27 | WHERE build_id = _build_id 28 | AND success IS False 29 | LIMIT 1 30 | ) THEN 31 | UPDATE postgres_ci.builds SET status = 'failed'::postgres_ci.status WHERE build_id = _build_id; 32 | END IF; 33 | 34 | end; 35 | $$ language plpgsql security definer; 36 | -------------------------------------------------------------------------------- /src/functions/build/view.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.view( 2 | _build_id int, 3 | 4 | out project_id int, 5 | out project_name text, 6 | out branch_id int, 7 | out branch_name text, 8 | out config text, 9 | out error text, 10 | out status postgres_ci.status, 11 | out commit_sha text, 12 | out commit_message text, 13 | out committed_at timestamptz, 14 | out committer_name text, 15 | out committer_email text, 16 | out author_name text, 17 | out author_email text, 18 | out created_at timestamptz, 19 | out parts jsonb 20 | ) returns record as $$ 21 | begin 22 | 23 | SELECT 24 | B.project_id, 25 | P.project_name, 26 | B.branch_id, 27 | BR.branch, 28 | B.config, 29 | B.error, 30 | B.status, 31 | C.commit_sha, 32 | C.commit_message, 33 | C.committed_at, 34 | C.committer_name, 35 | C.committer_email, 36 | C.author_name, 37 | C.author_email, 38 | B.created_at, 39 | ( 40 | SELECT 41 | COALESCE(array_to_json(array_agg(P.*)), '[]') 42 | FROM ( 43 | SELECT 44 | part_id, 45 | image, 46 | version, 47 | output, 48 | success, 49 | started_at, 50 | finished_at, 51 | ( 52 | SELECT 53 | COALESCE(array_to_json(array_agg(T.*)), '[]') 54 | FROM ( 55 | SELECT 56 | function, 57 | errors, 58 | duration 59 | FROM postgres_ci.tests 60 | WHERE part_id = parts.part_id 61 | ORDER BY 62 | jsonb_array_length(errors) DESC, 63 | function 64 | ) AS T 65 | ) AS tests 66 | FROM postgres_ci.parts 67 | WHERE build_id = B.build_id 68 | ORDER BY part_id 69 | ) AS P 70 | ) 71 | INTO 72 | project_id, 73 | project_name, 74 | branch_id, 75 | branch_name, 76 | config, 77 | error, 78 | status, 79 | commit_sha, 80 | commit_message, 81 | committed_at, 82 | committer_name, 83 | committer_email, 84 | author_name, 85 | author_email, 86 | created_at, 87 | parts 88 | FROM postgres_ci.builds AS B 89 | JOIN postgres_ci.projects AS P USING(project_id) 90 | JOIN postgres_ci.branches AS BR ON BR.branch_id = B.branch_id 91 | JOIN postgres_ci.commits AS C ON C.commit_id = B.commit_id 92 | WHERE B.build_id = _build_id; 93 | 94 | IF NOT FOUND THEN 95 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 96 | END IF; 97 | end; 98 | $$ language plpgsql security definer; 99 | 100 | -------------------------------------------------------------------------------- /src/functions/hook/commit.sql: -------------------------------------------------------------------------------- 1 | create or replace function hook.commit( 2 | _token uuid, 3 | _branch text, 4 | _commit_sha text, 5 | _commit_message text, 6 | _committed_at timestamptz, 7 | _committer_name text, 8 | _committer_email text, 9 | _author_name text, 10 | _author_email text, 11 | out commit_id int 12 | ) returns int as $$ 13 | declare 14 | _project_id int; 15 | begin 16 | 17 | SELECT project_id INTO _project_id FROM postgres_ci.projects WHERE project_token = _token AND is_deleted = false; 18 | 19 | IF NOT FOUND THEN 20 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 21 | END IF; 22 | 23 | SELECT project.add_commit( 24 | _project_id, 25 | _branch, 26 | _commit_sha, 27 | _commit_message, 28 | _committed_at, 29 | _committer_name, 30 | _committer_email, 31 | _author_name, 32 | _author_email 33 | ) INTO commit_id; 34 | 35 | end; 36 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/hook/github_push.sql: -------------------------------------------------------------------------------- 1 | create or replace function hook.github_push( 2 | _github_name text, 3 | _branch text, 4 | _commits jsonb 5 | ) returns table ( 6 | commit_id int 7 | ) as $$ 8 | declare 9 | _project_id int; 10 | begin 11 | 12 | SELECT project_id INTO _project_id FROM postgres_ci.projects WHERE github_name = _github_name AND is_deleted = false; 13 | 14 | IF NOT FOUND THEN 15 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 16 | END IF; 17 | 18 | return query 19 | 20 | SELECT 21 | project.add_commit( 22 | _project_id, 23 | _branch, 24 | C.commit_sha, 25 | C.commit_message, 26 | C.committed_at, 27 | C.committer_name, 28 | C.committer_email, 29 | C.author_name, 30 | C.author_email 31 | ) 32 | FROM jsonb_populate_recordset(null::postgres_ci.commits, _commits) AS C; 33 | end; 34 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/hook/push.sql: -------------------------------------------------------------------------------- 1 | create or replace function hook.push( 2 | _token uuid, 3 | _branch text, 4 | _commits jsonb 5 | ) returns table ( 6 | commit_id int 7 | ) as $$ 8 | declare 9 | _project_id int; 10 | begin 11 | 12 | SELECT project_id INTO _project_id FROM postgres_ci.projects WHERE project_token = _token AND is_deleted = false; 13 | 14 | IF NOT FOUND THEN 15 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 16 | END IF; 17 | 18 | return query 19 | 20 | SELECT 21 | project.add_commit( 22 | _project_id, 23 | _branch, 24 | C.commit_sha, 25 | C.commit_message, 26 | C.committed_at, 27 | C.committer_name, 28 | C.committer_email, 29 | C.author_name, 30 | C.author_email 31 | ) 32 | FROM jsonb_populate_recordset(null::postgres_ci.commits, _commits) AS C; 33 | end; 34 | $$ language plpgsql security definer; 35 | -------------------------------------------------------------------------------- /src/functions/notification/bind_with_telegram.sql: -------------------------------------------------------------------------------- 1 | create or replace function notification.bind_with_telegram( 2 | _user_id int, 3 | _telegram_username text, 4 | _telegram_id bigint 5 | ) returns void as $$ 6 | begin 7 | 8 | UPDATE postgres_ci.user_notification_method 9 | SET 10 | int_id = _telegram_id 11 | WHERE user_id = _user_id 12 | AND method = 'telegram' 13 | AND text_id = _telegram_username; 14 | 15 | IF NOT FOUND THEN 16 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 17 | END IF; 18 | end; 19 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/notification/fetch.sql: -------------------------------------------------------------------------------- 1 | create or replace function notification.fetch() returns table ( 2 | build_id int, 3 | build_status postgres_ci.status, 4 | project_id int, 5 | project_name text, 6 | branch text, 7 | build_error text, 8 | build_created_at timestamptz, 9 | build_started_at timestamptz, 10 | build_finished_at timestamptz, 11 | commit_sha text, 12 | commit_message text, 13 | committed_at timestamptz, 14 | committer_name text, 15 | committer_email text, 16 | commit_author_name text, 17 | commit_author_email text, 18 | send_to jsonb 19 | ) as $$ 20 | declare 21 | _build_id int; 22 | begin 23 | 24 | SELECT 25 | N.build_id INTO _build_id 26 | FROM postgres_ci.notification AS N 27 | ORDER BY N.build_id 28 | LIMIT 1 29 | FOR UPDATE SKIP LOCKED; 30 | 31 | IF NOT FOUND THEN 32 | return; 33 | END IF; 34 | 35 | return query 36 | SELECT 37 | B.build_id, 38 | B.status, 39 | P.project_id, 40 | P.project_name, 41 | BR.branch, 42 | B.error, 43 | B.created_at, 44 | B.started_at, 45 | B.finished_at, 46 | C.commit_sha, 47 | C.commit_message, 48 | C.committed_at, 49 | C.committer_name, 50 | C.committer_email, 51 | C.author_name, 52 | C.author_email, 53 | ( 54 | SELECT 55 | COALESCE(array_to_json(array_agg(P.*)), '[]') 56 | FROM ( 57 | SELECT 58 | U.user_name, 59 | M.method AS notify_method, 60 | M.text_id AS notify_text_id, 61 | M.int_id AS notify_int_id 62 | FROM postgres_ci.users AS U 63 | JOIN postgres_ci.user_notification_method AS M ON U.user_id = M.user_id 64 | WHERE U.user_id IN ( 65 | SELECT 66 | P.project_owner_id 67 | UNION ALL 68 | SELECT 69 | U.user_id 70 | FROM postgres_ci.users AS U 71 | WHERE U.user_email IN (lower(C.author_email), lower(C.committer_email)) 72 | ) AND M.method <> 'none' 73 | ) AS P 74 | )::jsonb 75 | FROM postgres_ci.builds AS B 76 | JOIN postgres_ci.projects AS P ON P.project_id = B.project_id 77 | JOIN postgres_ci.commits AS C ON C.commit_id = B.commit_id 78 | JOIN postgres_ci.branches AS BR ON BR.branch_id = B.branch_id 79 | WHERE B.build_id = _build_id; 80 | 81 | DELETE FROM postgres_ci.notification AS N WHERE N.build_id = _build_id; 82 | end; 83 | $$ language plpgsql security definer rows 1; 84 | -------------------------------------------------------------------------------- /src/functions/notification/find_user_by_telegram_username.sql: -------------------------------------------------------------------------------- 1 | create or replace function notification.find_user_by_telegram_username(_telegram_username text) returns table ( 2 | user_id int, 3 | telegram_id bigint 4 | ) as $$ 5 | begin 6 | 7 | return query 8 | SELECT 9 | N.user_id, 10 | N.int_id 11 | FROM postgres_ci.user_notification_method AS N 12 | WHERE N.method = 'telegram' 13 | AND N.text_id = _telegram_username; 14 | 15 | end; 16 | $$ language plpgsql security definer rows 1; -------------------------------------------------------------------------------- /src/functions/notification/get_method.sql: -------------------------------------------------------------------------------- 1 | create or replace function notification.get_method( 2 | _user_id int, 3 | out method text, 4 | out text_id text, 5 | out int_id bigint 6 | ) returns record as $$ 7 | begin 8 | 9 | SELECT 10 | M.method, 11 | M.text_id, 12 | M.int_id 13 | INTO 14 | method, 15 | text_id, 16 | int_id 17 | FROM postgres_ci.user_notification_method AS M 18 | WHERE M.user_id = _user_id; 19 | 20 | IF NOT FOUND THEN 21 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 22 | END IF; 23 | end; 24 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/notification/update_method.sql: -------------------------------------------------------------------------------- 1 | create or replace function notification.update_method( 2 | _user_id int, 3 | _method postgres_ci.notification_method, 4 | _text_id text 5 | ) returns void as $$ 6 | begin 7 | 8 | CASE 9 | WHEN _method = 'none' THEN 10 | UPDATE postgres_ci.user_notification_method 11 | SET 12 | method = _method, 13 | text_id = '', 14 | int_id = 0 15 | WHERE user_id = _user_id; 16 | ELSE 17 | UPDATE postgres_ci.user_notification_method 18 | SET 19 | method = _method, 20 | text_id = _text_id, 21 | int_id = 0 22 | WHERE user_id = _user_id AND NOT ( 23 | text_id = _text_id AND method = _method 24 | ); 25 | END CASE; 26 | 27 | end; 28 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/password/change.sql: -------------------------------------------------------------------------------- 1 | create or replace function password.change( 2 | _user_id int, 3 | _current_password text, 4 | _new_password text 5 | ) returns boolean as $$ 6 | declare 7 | _salt text; 8 | begin 9 | 10 | IF password.check(_user_id, _current_password) THEN 11 | 12 | _salt = postgres_ci.sha1(gen_salt('md5') || current_timestamp); 13 | 14 | UPDATE postgres_ci.users 15 | SET 16 | hash = encode(digest(_salt || _new_password, 'sha1'), 'hex'), 17 | salt = _salt 18 | WHERE user_id = _user_id; 19 | 20 | END IF; 21 | 22 | return true; 23 | end; 24 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/password/check.sql: -------------------------------------------------------------------------------- 1 | create or replace function password.check(_user_id int, _password text) returns boolean as $$ 2 | declare 3 | _invalid_password boolean; 4 | begin 5 | 6 | SELECT 7 | encode(digest(U.salt || _password, 'sha1'), 'hex') != U.hash 8 | INTO 9 | _invalid_password 10 | FROM postgres_ci.users AS U 11 | WHERE user_id = _user_id 12 | AND is_deleted = false; 13 | 14 | CASE 15 | WHEN NOT FOUND THEN 16 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 17 | WHEN _invalid_password THEN 18 | RAISE EXCEPTION 'INVALID_PASSWORD' USING ERRCODE = 'invalid_password'; 19 | ELSE 20 | return true; 21 | END CASE; 22 | 23 | end; 24 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/password/reset.sql: -------------------------------------------------------------------------------- 1 | create or replace function password.reset(_user_id int, _password text) returns void as $$ 2 | declare 3 | _salt text; 4 | begin 5 | _salt = postgres_ci.sha1(gen_salt('md5') || current_timestamp); 6 | UPDATE postgres_ci.users 7 | SET 8 | hash = encode(digest(_salt || _password, 'sha1'), 'hex'), 9 | salt = _salt, 10 | updated_at = current_timestamp 11 | WHERE user_id = _user_id; 12 | end; 13 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/project/add.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.add( 2 | _project_name text, 3 | _project_owner_id int, 4 | _repository_url text, 5 | _github_secret text, 6 | out project_id int 7 | ) returns int as $$ 8 | begin 9 | 10 | INSERT INTO postgres_ci.projects ( 11 | project_name, 12 | project_owner_id, 13 | repository_url, 14 | github_name, 15 | github_secret 16 | ) VALUES ( 17 | _project_name, 18 | _project_owner_id, 19 | _repository_url, 20 | project.github_name(_repository_url), 21 | _github_secret 22 | ) RETURNING projects.project_id INTO project_id; 23 | 24 | end; 25 | $$ language plpgsql security definer; 26 | -------------------------------------------------------------------------------- /src/functions/project/add_commit.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.add_commit( 2 | _project_id int, 3 | _branch text, 4 | _commit_sha text, 5 | _commit_message text, 6 | _committed_at timestamptz, 7 | _committer_name text, 8 | _committer_email text, 9 | _author_name text, 10 | _author_email text, 11 | out commit_id int 12 | ) returns int as $$ 13 | declare 14 | _branch_id int; 15 | begin 16 | 17 | _branch_id = project.get_branch_id(_project_id, _branch); 18 | 19 | BEGIN 20 | 21 | INSERT INTO postgres_ci.commits ( 22 | project_id, 23 | branch_id, 24 | commit_sha, 25 | commit_message, 26 | committed_at, 27 | committer_name, 28 | committer_email, 29 | author_name, 30 | author_email 31 | ) VALUES ( 32 | _project_id, 33 | _branch_id, 34 | _commit_sha, 35 | _commit_message, 36 | _committed_at, 37 | _committer_name, 38 | _committer_email, 39 | _author_name, 40 | _author_email 41 | ) RETURNING commits.commit_id INTO commit_id; 42 | 43 | PERFORM build.new(_project_id, _branch_id, commit_id); 44 | 45 | EXCEPTION WHEN unique_violation THEN 46 | 47 | SELECT 48 | C.commit_id INTO commit_id 49 | FROM postgres_ci.commits C 50 | WHERE C.branch_id = _branch_id 51 | AND C.commit_sha = _commit_sha; 52 | END; 53 | 54 | end; 55 | $$ language plpgsql security definer; 56 | -------------------------------------------------------------------------------- /src/functions/project/delete.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.delete(_project_id int) returns void as $$ 2 | begin 3 | UPDATE postgres_ci.projects 4 | SET 5 | is_deleted = true, 6 | updated_at = current_timestamp 7 | WHERE project_id = _project_id; 8 | end; 9 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/project/get.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.get( 2 | _project_id int, 3 | out project_id int, 4 | out project_name text, 5 | out project_token text, 6 | out repository_url text, 7 | out project_owner_id int, 8 | out possible_owners jsonb, 9 | out github_secret text, 10 | out created_at timestamptz, 11 | out updated_at timestamptz 12 | ) returns record as $$ 13 | begin 14 | 15 | SELECT 16 | P.project_id, 17 | P.project_name, 18 | P.project_token, 19 | P.repository_url, 20 | P.project_owner_id, 21 | ( 22 | SELECT 23 | COALESCE(array_to_json(array_agg(U.*)), '[]') 24 | FROM ( 25 | SELECT 26 | user_id, 27 | user_name 28 | FROM postgres_ci.users 29 | WHERE is_deleted = false 30 | ORDER BY user_id 31 | ) U 32 | ), 33 | P.github_secret, 34 | P.created_at, 35 | P.updated_at 36 | 37 | INTO 38 | project_id, 39 | project_name, 40 | project_token, 41 | repository_url, 42 | project_owner_id, 43 | possible_owners, 44 | github_secret, 45 | created_at, 46 | updated_at 47 | FROM postgres_ci.projects AS P 48 | WHERE P.project_id = _project_id 49 | AND P.is_deleted = false; 50 | 51 | IF NOT FOUND THEN 52 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 53 | END IF; 54 | 55 | end; 56 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/project/get_branch_id.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.get_branch_id(_project_id int, _branch text, out branch_id int) returns int as $$ 2 | begin 3 | 4 | SELECT 5 | B.branch_id INTO branch_id 6 | FROM postgres_ci.branches AS B 7 | WHERE B.project_id = _project_id 8 | AND B.branch = _branch; 9 | 10 | IF NOT FOUND THEN 11 | 12 | INSERT INTO postgres_ci.branches ( 13 | project_id, 14 | branch 15 | ) VALUES ( 16 | _project_id, 17 | _branch 18 | ) RETURNING branches.branch_id INTO branch_id; 19 | 20 | END IF; 21 | end; 22 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/project/get_github_secret.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.get_github_secret(_github_name text) returns table( 2 | secret text 3 | ) as $$ 4 | begin 5 | return query 6 | SELECT 7 | github_secret 8 | FROM postgres_ci.projects 9 | WHERE github_name = _github_name 10 | AND is_deleted = false; 11 | end 12 | $$ language plpgsql security definer rows 1; -------------------------------------------------------------------------------- /src/functions/project/get_possible_owners.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.get_possible_owners() returns table ( 2 | user_id int, 3 | user_name text 4 | ) as $$ 5 | begin 6 | 7 | return query 8 | SELECT 9 | U.user_id, 10 | U.user_name 11 | FROM postgres_ci.users AS U 12 | WHERE U.is_deleted = false 13 | ORDER BY U.user_id; 14 | 15 | end; 16 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/project/github_name.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.github_name(_repository_url text) returns text as $$ 2 | begin 3 | CASE 4 | WHEN _repository_url LIKE 'https://github\.com%' THEN 5 | return replace((string_to_array(_repository_url, 'github.com/'))[2], '.git', ''); 6 | WHEN _repository_url LIKE '%@github\.com:%' THEN 7 | return replace((string_to_array(_repository_url, 'github.com:'))[2], '.git', ''); 8 | ELSE 9 | return ''; 10 | END CASE; 11 | end; 12 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/project/list.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.list() returns table ( 2 | project_id int, 3 | project_name text, 4 | project_token uuid, 5 | project_owner_id int, 6 | user_email text, 7 | user_name text, 8 | status postgres_ci.status, 9 | commit_sha text, 10 | last_build_id int, 11 | started_at timestamptz, 12 | finished_at timestamptz 13 | ) as $$ 14 | begin 15 | return query 16 | SELECT 17 | P.project_id, 18 | P.project_name, 19 | P.project_token, 20 | P.project_owner_id, 21 | U.user_email, 22 | U.user_name, 23 | B.status, 24 | C.commit_sha, 25 | P.last_build_id, 26 | B.started_at, 27 | B.finished_at 28 | FROM postgres_ci.projects AS P 29 | JOIN postgres_ci.users AS U ON U.user_id = P.project_owner_id 30 | LEFT JOIN postgres_ci.builds AS B ON B.build_id = P.last_build_id 31 | LEFT JOIN postgres_ci.commits AS C ON C.commit_id = B.commit_id 32 | WHERE P.is_deleted = false 33 | ORDER BY P.project_name; 34 | 35 | end; 36 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/project/update.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.update( 2 | _project_id int, 3 | _project_name text, 4 | _project_owner_id int, 5 | _repository_url text, 6 | _github_secret text 7 | ) returns void as $$ 8 | begin 9 | 10 | UPDATE postgres_ci.projects 11 | SET 12 | project_name = _project_name, 13 | project_owner_id = _project_owner_id, 14 | repository_url = _repository_url, 15 | github_name = project.github_name(_repository_url), 16 | github_secret = _github_secret 17 | WHERE project_id = _project_id; 18 | 19 | IF NOT FOUND THEN 20 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 21 | END IF; 22 | end; 23 | $$ language plpgsql security definer; 24 | -------------------------------------------------------------------------------- /src/functions/users/add.sql: -------------------------------------------------------------------------------- 1 | create or replace function users.add( 2 | _user_login text, 3 | _password text, 4 | _user_name text, 5 | _user_email text, 6 | _is_superuser boolean, 7 | out user_id int 8 | ) returns int as $$ 9 | declare 10 | _salt text; 11 | _message text; 12 | _column_name text; 13 | _constraint_name text; 14 | _datatype_name text; 15 | _table_name text; 16 | _schema_name text; 17 | begin 18 | 19 | _salt = postgres_ci.sha1(gen_salt('md5') || current_timestamp); 20 | 21 | BEGIN 22 | 23 | INSERT INTO postgres_ci.users ( 24 | user_login, 25 | user_name, 26 | user_email, 27 | is_superuser, 28 | hash, 29 | salt 30 | ) VALUES ( 31 | _user_login, 32 | _user_name, 33 | _user_email, 34 | _is_superuser, 35 | encode(digest(_salt || _password, 'sha1'), 'hex'), 36 | _salt 37 | ) RETURNING users.user_id INTO user_id; 38 | 39 | INSERT INTO postgres_ci.user_notification_method (user_id, method, text_id) VALUES (add.user_id, 'email', _user_email); 40 | 41 | EXCEPTION WHEN OTHERS THEN 42 | 43 | GET STACKED DIAGNOSTICS 44 | _column_name = column_name, 45 | _constraint_name = constraint_name, 46 | _datatype_name = pg_datatype_name, 47 | _table_name = table_name, 48 | _schema_name = schema_name; 49 | 50 | CASE 51 | WHEN _constraint_name = 'unique_user_login' THEN 52 | _message = 'LOGIN_ALREADY_EXISTS'; 53 | WHEN _constraint_name = 'unique_user_email' THEN 54 | _message = 'EMAIL_ALREADY_EXISTS'; 55 | WHEN _constraint_name = 'check_user_email' THEN 56 | _message = 'INVALID_EMAIL'; 57 | ELSE 58 | _message = SQLERRM; 59 | END CASE; 60 | 61 | RAISE EXCEPTION USING 62 | MESSAGE = _message, 63 | ERRCODE = SQLSTATE, 64 | COLUMN = _column_name, 65 | CONSTRAINT = _constraint_name, 66 | DATATYPE = _datatype_name, 67 | TABLE = _table_name, 68 | SCHEMA = _schema_name; 69 | END; 70 | 71 | end; 72 | $$ language plpgsql security definer; 73 | 74 | 75 | -------------------------------------------------------------------------------- /src/functions/users/delete.sql: -------------------------------------------------------------------------------- 1 | create or replace function users.delete(_user_id int) returns void as $$ 2 | begin 3 | 4 | IF EXISTS( 5 | SELECT 6 | null 7 | FROM postgres_ci.users 8 | WHERE is_deleted = false 9 | AND is_superuser = true 10 | AND user_id = _user_id 11 | ) THEN 12 | RAISE EXCEPTION 'IS_SUPERUSER' USING ERRCODE = 'check_violation'; 13 | END IF; 14 | 15 | UPDATE postgres_ci.users 16 | SET 17 | is_deleted = true, 18 | updated_at = CURRENT_TIMESTAMP 19 | WHERE user_id = _user_id 20 | AND is_deleted = false; 21 | 22 | IF NOT FOUND THEN 23 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 24 | END IF; 25 | end; 26 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/users/get.sql: -------------------------------------------------------------------------------- 1 | create or replace function users.get( 2 | _user_id int, 3 | out user_id int, 4 | out user_name text, 5 | out user_login text, 6 | out user_email text, 7 | out is_superuser boolean, 8 | out created_at timestamptz, 9 | out updated_at timestamptz 10 | ) returns record as $$ 11 | begin 12 | SELECT 13 | U.user_id, 14 | U.user_name, 15 | U.user_login, 16 | U.user_email, 17 | U.is_superuser, 18 | U.created_at, 19 | U.updated_at 20 | INTO 21 | user_id, 22 | user_name, 23 | user_login, 24 | user_email, 25 | is_superuser, 26 | created_at, 27 | updated_at 28 | FROM postgres_ci.users AS U 29 | WHERE U.user_id = _user_id 30 | AND U.is_deleted = false; 31 | 32 | IF NOT FOUND THEN 33 | RAISE EXCEPTION 'NOT_FOUND' USING ERRCODE = 'no_data_found'; 34 | END IF; 35 | 36 | end; 37 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/users/list.sql: -------------------------------------------------------------------------------- 1 | create or replace function users.list( 2 | _limit int, 3 | _offset int, 4 | _query text, 5 | 6 | out total bigint, 7 | out users jsonb 8 | ) returns record as $$ 9 | declare 10 | _pattern text; 11 | begin 12 | 13 | IF _query <> '' THEN 14 | _pattern = '%' || array_to_string(string_to_array(lower(_query), ' '), '%') || '%'; 15 | END IF; 16 | 17 | SELECT 18 | ( 19 | SELECT 20 | COUNT(*) 21 | FROM postgres_ci.users 22 | WHERE is_deleted = false 23 | AND ( 24 | CASE WHEN _pattern IS NOT NULL 25 | THEN lower(user_name || user_login || user_email) LIKE _pattern 26 | ELSE true 27 | END 28 | ) 29 | ), 30 | ( 31 | SELECT 32 | COALESCE(array_to_json(array_agg(U.*)), '[]') 33 | FROM ( 34 | SELECT 35 | user_id, 36 | user_name, 37 | user_login, 38 | user_email, 39 | is_superuser, 40 | created_at, 41 | updated_at 42 | FROM postgres_ci.users 43 | WHERE is_deleted = false 44 | AND ( 45 | CASE WHEN _pattern IS NOT NULL 46 | THEN lower(user_name || user_login || user_email) LIKE _pattern 47 | ELSE true 48 | END 49 | ) 50 | ORDER BY user_id 51 | LIMIT _limit 52 | OFFSET _offset 53 | ) U 54 | ) 55 | INTO total, users; 56 | end; 57 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /src/functions/users/update.sql: -------------------------------------------------------------------------------- 1 | create or replace function users.update( 2 | _user_id int, 3 | _user_name text, 4 | _user_email text, 5 | _is_superuser boolean 6 | ) returns void as $$ 7 | declare 8 | _message text; 9 | _column_name text; 10 | _constraint_name text; 11 | _datatype_name text; 12 | _table_name text; 13 | _schema_name text; 14 | begin 15 | 16 | BEGIN 17 | UPDATE postgres_ci.users 18 | SET 19 | user_name = _user_name, 20 | user_email = _user_email, 21 | is_superuser = _is_superuser, 22 | updated_at = current_timestamp 23 | WHERE user_id = _user_id; 24 | 25 | EXCEPTION WHEN OTHERS THEN 26 | 27 | GET STACKED DIAGNOSTICS 28 | _column_name = column_name, 29 | _constraint_name = constraint_name, 30 | _datatype_name = pg_datatype_name, 31 | _table_name = table_name, 32 | _schema_name = schema_name; 33 | 34 | CASE 35 | WHEN _constraint_name = 'unique_user_email' THEN 36 | _message = 'EMAIL_ALREADY_EXISTS'; 37 | WHEN _constraint_name = 'check_user_email' THEN 38 | _message = 'INVALID_EMAIL'; 39 | ELSE 40 | _message = SQLERRM; 41 | END CASE; 42 | 43 | RAISE EXCEPTION USING 44 | MESSAGE = _message, 45 | ERRCODE = SQLSTATE, 46 | COLUMN = _column_name, 47 | CONSTRAINT = _constraint_name, 48 | DATATYPE = _datatype_name, 49 | TABLE = _table_name, 50 | SCHEMA = _schema_name; 51 | END; 52 | 53 | end; 54 | $$ language plpgsql security definer; 55 | 56 | 57 | -------------------------------------------------------------------------------- /src/packages.sql: -------------------------------------------------------------------------------- 1 | create schema auth; 2 | create schema hook; 3 | create schema users; 4 | create schema build; 5 | create schema project; 6 | create schema password; 7 | create schema notification; 8 | 9 | grant usage on schema auth to public; 10 | grant usage on schema hook to public; 11 | grant usage on schema users to public; 12 | grant usage on schema build to public; 13 | grant usage on schema project to public; 14 | grant usage on schema password to public; 15 | grant usage on schema postgres_ci to public; 16 | grant usage on schema notification to public; 17 | grant execute on all functions in schema auth to public; 18 | grant execute on all functions in schema hook to public; 19 | grant execute on all functions in schema users to public; 20 | grant execute on all functions in schema build to public; 21 | grant execute on all functions in schema project to public; 22 | grant execute on all functions in schema password to public; 23 | grant execute on all functions in schema postgres_ci to public; 24 | grant execute on all functions in schema notification to public; -------------------------------------------------------------------------------- /src/pg_extension_config_dump.sql: -------------------------------------------------------------------------------- 1 | select pg_catalog.pg_extension_config_dump('postgres_ci.users', ''); 2 | select pg_catalog.pg_extension_config_dump('postgres_ci.users_seq', ''); 3 | select pg_catalog.pg_extension_config_dump('postgres_ci.projects', ''); 4 | select pg_catalog.pg_extension_config_dump('postgres_ci.projects_seq', ''); 5 | select pg_catalog.pg_extension_config_dump('postgres_ci.branches', ''); 6 | select pg_catalog.pg_extension_config_dump('postgres_ci.branches_seq', ''); 7 | select pg_catalog.pg_extension_config_dump('postgres_ci.commits', ''); 8 | select pg_catalog.pg_extension_config_dump('postgres_ci.commits_seq', ''); 9 | select pg_catalog.pg_extension_config_dump('postgres_ci.builds', ''); 10 | select pg_catalog.pg_extension_config_dump('postgres_ci.builds_seq', ''); 11 | select pg_catalog.pg_extension_config_dump('postgres_ci.parts', ''); 12 | select pg_catalog.pg_extension_config_dump('postgres_ci.parts_seq', ''); 13 | select pg_catalog.pg_extension_config_dump('postgres_ci.user_notification_method', ''); -------------------------------------------------------------------------------- /src/schema.sql: -------------------------------------------------------------------------------- 1 | --create schema postgres_ci; 2 | 3 | create or replace function postgres_ci.sha1(_value text) returns text as $$ 4 | begin 5 | return encode(digest(_value, 'sha1'), 'hex'); 6 | end; 7 | $$ language plpgsql; 8 | 9 | create sequence postgres_ci.users_seq; 10 | create table postgres_ci.users ( 11 | user_id int not null default nextval('postgres_ci.users_seq') primary key, 12 | user_name text not null, 13 | user_login text not null, 14 | user_email text not null, 15 | hash text not null, 16 | salt text not null, 17 | is_superuser boolean not null default false, 18 | is_deleted boolean not null default false, 19 | created_at timestamptz not null default current_timestamp, 20 | updated_at timestamptz not null default current_timestamp, 21 | constraint check_user_hash check(length(hash) = 40), 22 | constraint check_user_salt check(length(salt) = 40), 23 | constraint check_user_email check(strpos(user_email, '@') > 0) 24 | ); 25 | 26 | create unique index unique_user_login on postgres_ci.users (lower(user_login)); 27 | create unique index unique_user_email on postgres_ci.users (lower(user_email)); 28 | 29 | create type postgres_ci.notification_method as enum ( 30 | 'none', 31 | 'email', 32 | 'telegram' 33 | ); 34 | 35 | create table postgres_ci.user_notification_method( 36 | user_id int not null references postgres_ci.users(user_id) primary key, 37 | method postgres_ci.notification_method not null default 'none', 38 | text_id text not null, 39 | int_id bigint not null default 0 40 | ); 41 | 42 | create unique index unique_user_notification_method 43 | on postgres_ci.user_notification_method (method, lower(text_id)) 44 | where method <> 'none' and text_id <> ''; 45 | 46 | create unlogged table postgres_ci.sessions( 47 | session_id text not null default postgres_ci.sha1(gen_salt('md5') || gen_salt('md5')) primary key, 48 | user_id int not null references postgres_ci.users(user_id), 49 | expires_at timestamptz not null default current_timestamp 50 | ); 51 | 52 | create index idx_sessions_expires_at on postgres_ci.sessions(expires_at); 53 | 54 | create type postgres_ci.status as enum( 55 | 'pending', 56 | 'accepted', 57 | 'running', 58 | 'failed', 59 | 'success' 60 | ); 61 | 62 | create sequence postgres_ci.projects_seq; 63 | 64 | create table postgres_ci.projects( 65 | project_id int not null default nextval('postgres_ci.projects_seq') primary key, 66 | project_name text not null, 67 | project_token uuid not null default gen_random_uuid(), 68 | project_owner_id int not null, 69 | repository_url text not null, 70 | github_name text not null, 71 | github_secret text not null, 72 | last_build_id int, 73 | is_deleted boolean not null default false, 74 | created_at timestamptz not null default current_timestamp, 75 | updated_at timestamptz not null default current_timestamp, 76 | unique(project_token) 77 | ); 78 | 79 | create unique index udx_is_github_repo on postgres_ci.projects (github_name) where github_name <> ''; 80 | alter table postgres_ci.projects add constraint fk_project_owner_id foreign key (project_owner_id) references postgres_ci.users(user_id); 81 | 82 | create sequence postgres_ci.branches_seq; 83 | 84 | create table postgres_ci.branches( 85 | branch_id int not null default nextval('postgres_ci.branches_seq'), 86 | branch text not null, 87 | project_id int not null references postgres_ci.projects(project_id), 88 | created_at timestamptz not null default current_timestamp, 89 | primary key (project_id, branch_id) 90 | ); 91 | 92 | create index idx_branch on postgres_ci.branches (branch_id); 93 | 94 | create sequence postgres_ci.commits_seq; 95 | 96 | create table postgres_ci.commits( 97 | commit_id int not null default nextval('postgres_ci.commits_seq') primary key, 98 | project_id int not null, 99 | branch_id int not null, 100 | commit_sha text not null, 101 | commit_message text not null, 102 | committed_at timestamptz not null, 103 | committer_name text not null, 104 | committer_email text not null, 105 | author_name text not null, 106 | author_email text not null, 107 | created_at timestamptz not null default current_timestamp, 108 | constraint check_commit_sha check(length(commit_sha) = 40), 109 | constraint uniq_commit unique(branch_id, commit_sha), 110 | foreign key (project_id, branch_id) references postgres_ci.branches(project_id, branch_id) match full 111 | ); 112 | 113 | create sequence postgres_ci.builds_seq; 114 | 115 | create table postgres_ci.builds( 116 | build_id int not null default nextval('postgres_ci.builds_seq') primary key, 117 | project_id int not null, 118 | branch_id int not null, 119 | commit_id int not null references postgres_ci.commits(commit_id), 120 | config text not null, 121 | status postgres_ci.status not null, 122 | error text not null default '', 123 | created_at timestamptz not null default current_timestamp, 124 | started_at timestamptz, 125 | finished_at timestamptz, 126 | foreign key (project_id, branch_id) references postgres_ci.branches(project_id, branch_id) match full 127 | ); 128 | 129 | create index idx_new_build on postgres_ci.builds(status) where status in ('pending', 'accepted', 'running'); 130 | create index idx_p_b_build on postgres_ci.builds(project_id, branch_id); 131 | 132 | alter table postgres_ci.projects add foreign key (last_build_id) references postgres_ci.builds(build_id); 133 | 134 | create table postgres_ci.builds_counters( 135 | project_id int not null, 136 | branch_id int not null, 137 | counter bigint not null, 138 | constraint unique_builds_counters unique(project_id, branch_id), 139 | foreign key (project_id, branch_id) references postgres_ci.branches(project_id, branch_id) match full 140 | ); 141 | 142 | create unlogged table postgres_ci.notification( 143 | build_id int not null references postgres_ci.builds(build_id) primary key, 144 | created_at timestamptz not null default current_timestamp 145 | ); 146 | 147 | create sequence postgres_ci.parts_seq; 148 | 149 | create table postgres_ci.parts( 150 | part_id int not null default nextval('postgres_ci.parts_seq') primary key, 151 | build_id int not null references postgres_ci.builds(build_id), 152 | image text not null, 153 | container_id text not null, 154 | version text not null, 155 | output text not null, 156 | success boolean not null, 157 | started_at timestamptz not null, 158 | finished_at timestamptz not null 159 | ); 160 | 161 | create index idx_parts_build on postgres_ci.parts(build_id); 162 | 163 | create table postgres_ci.tests( 164 | part_id int not null references postgres_ci.parts(part_id), 165 | function text not null, 166 | errors jsonb not null default '[]', 167 | duration real not null 168 | ); 169 | 170 | create index idx_part_tests on postgres_ci.tests(part_id); 171 | 172 | 173 | /* select * from users.add('user', 'password', 'User', 'email@email.com', true); */ 174 | 175 | -------------------------------------------------------------------------------- /test_setup.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | echo "Create database owner" 4 | 5 | env PGPASSWORD=$POSTGRES_PASSWORD psql -q -v ON_ERROR_STOP=1 -U $POSTGRES_USER -d $TEST_DATABASE <<-SQL 6 | CREATE USER ci_owner WITH PASSWORD 'password' LOGIN; 7 | GRANT ALL PRIVILEGES ON DATABASE "$TEST_DATABASE" TO ci_owner; 8 | SQL 9 | 10 | echo "Done!" 11 | echo "Create required extensions" 12 | env PGPASSWORD=$POSTGRES_PASSWORD psql -v ON_ERROR_STOP=1 -q -U $POSTGRES_USER -d $TEST_DATABASE <<-SQL 13 | CREATE EXTENSION pgcrypto; 14 | CREATE EXTENSION pg_trgm; 15 | SQL 16 | echo "Done!" 17 | 18 | env PGPASSWORD=password psql -q -v ON_ERROR_STOP=1 -U ci_owner -d $TEST_DATABASE <<-SQL 19 | CREATE SCHEMA postgres_ci; 20 | SQL 21 | 22 | cat postgres_ci--0.3.sql | sed '/CREATE EXTENSION postgres_ci/d' | sed '/pg_extension_config_dump/d' > dump.sql 23 | 24 | env PGPASSWORD=password psql -q -v ON_ERROR_STOP=1 -U ci_owner -d $TEST_DATABASE -f dump.sql 25 | 26 | #cat postgres_ci--0.3--0.4.sql | sed '/alter extension/d' | sed '/pg_extension_config_dump/d' > upgrade.sql 27 | 28 | #env PGPASSWORD=password psql -q -v ON_ERROR_STOP=1 -U ci_owner -d $TEST_DATABASE -f upgrade.sql 29 | 30 | echo "Grant privileges to Tester" 31 | 32 | env PGPASSWORD=password psql -q -v ON_ERROR_STOP=1 -U ci_owner -d $TEST_DATABASE -f tests/grants.sql 33 | 34 | echo "Create test functions" 35 | 36 | cd tests && env PGPASSWORD=$TEST_PASSWORD psql -v ON_ERROR_STOP=1 -q -U $TEST_USERNAME -d $TEST_DATABASE -f tests.sql -------------------------------------------------------------------------------- /tests/auth/test_gc.sql: -------------------------------------------------------------------------------- 1 | create or replace function auth.test_gc() returns void as $$ 2 | declare 3 | _session_id text; 4 | _expired_session_id text; 5 | begin 6 | 7 | IF assert.not_null(users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true)) THEN 8 | 9 | _session_id = auth.login('login', 'password'); 10 | _expired_session_id = auth.login('login', 'password'); 11 | 12 | IF assert.not_equal(_session_id, _expired_session_id) THEN 13 | 14 | PERFORM auth.gc(); 15 | 16 | IF assert.equal(2, (SELECT COUNT(*) FROM postgres_ci.sessions)::int) THEN 17 | 18 | UPDATE postgres_ci.sessions 19 | SET 20 | expires_at = current_timestamp - '1 second'::interval 21 | WHERE session_id = _expired_session_id; 22 | 23 | PERFORM auth.gc(); 24 | 25 | PERFORM assert.equal(1, (SELECT COUNT(*) FROM postgres_ci.sessions)::int); 26 | 27 | END IF; 28 | 29 | END IF; 30 | END IF; 31 | 32 | end; 33 | $$ language plpgsql; -------------------------------------------------------------------------------- /tests/auth/test_get_user.sql: -------------------------------------------------------------------------------- 1 | create or replace function auth.test_get_user() returns void as $$ 2 | declare 3 | _user record; 4 | _session_id text; 5 | begin 6 | 7 | IF assert.not_null(users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true)) THEN 8 | 9 | _session_id = auth.login('login', 'password'); 10 | 11 | IF assert.not_null(_session_id) THEN 12 | 13 | _user = auth.get_user(_session_id); 14 | 15 | IF assert.true(_user.is_superuser) THEN 16 | 17 | PERFORM assert.equal('Elephant Sam', _user.user_name); 18 | PERFORM assert.equal('samelephant82@gmail.com', _user.user_email); 19 | END IF; 20 | 21 | END IF; 22 | 23 | END IF; 24 | 25 | PERFORM assert.null((select user_id from auth.get_user('no_data_found'))); 26 | 27 | end; 28 | $$ language plpgsql; -------------------------------------------------------------------------------- /tests/auth/test_login.sql: -------------------------------------------------------------------------------- 1 | create or replace function auth.test_login() returns void as $$ 2 | begin 3 | 4 | IF assert.not_null(users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true)) THEN 5 | 6 | PERFORM assert.not_null(auth.login('login', 'password')); 7 | END IF; 8 | 9 | PERFORM assert.exception( 10 | $sql$ SELECT auth.login('login2', 'password') $sql$, 11 | exception_message := 'NOT_FOUND', 12 | exception_sqlstate := 'P0002' 13 | ); 14 | 15 | PERFORM assert.exception( 16 | $sql$ SELECT auth.login('login', 'password2') $sql$, 17 | exception_message := 'INVALID_PASSWORD', 18 | exception_sqlstate := '28P01' 19 | ); 20 | 21 | end; 22 | $$ language plpgsql; -------------------------------------------------------------------------------- /tests/auth/test_logout.sql: -------------------------------------------------------------------------------- 1 | create or replace function auth.test_logout() returns void as $$ 2 | declare 3 | _session_id text; 4 | begin 5 | 6 | IF assert.not_null(users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true)) THEN 7 | 8 | _session_id = auth.login('login', 'password'); 9 | 10 | IF assert.not_null(_session_id) THEN 11 | 12 | PERFORM assert.true(EXISTS( 13 | SELECT null FROM postgres_ci.sessions WHERE session_id = _session_id 14 | ) 15 | ); 16 | 17 | PERFORM auth.logout(_session_id); 18 | 19 | PERFORM assert.true(NOT EXISTS( 20 | SELECT null FROM postgres_ci.sessions WHERE session_id = _session_id 21 | ) 22 | ); 23 | 24 | END IF; 25 | 26 | END IF; 27 | 28 | end; 29 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/build/test_accept.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.test_accept() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _build_id int; 6 | _commit_id int; 7 | _commit_sha text; 8 | begin 9 | 10 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 11 | 12 | IF assert.not_null(_project_owner_id) THEN 13 | 14 | _project_id = project.add( 15 | 'project', 16 | _project_owner_id, 17 | 'https://github.com/postgres-ci/core.git', 18 | '' 19 | ); 20 | 21 | IF assert.not_null(_project_id) THEN 22 | 23 | _commit_sha = encode(digest('commit' || CURRENT_TIMESTAMP, 'sha1'), 'hex'); 24 | _commit_id = hook.commit( 25 | (SELECT project_token FROM postgres_ci.projects WHERE project_id = _project_id), 26 | 'master', 27 | _commit_sha, 28 | 'message', 29 | CURRENT_TIMESTAMP - '1 day'::interval, 30 | 'Elephant Sam', 31 | 'samelephant82@gmail.com', 32 | 'Elephant Sam', 33 | 'samelephant82@gmail.com' 34 | ); 35 | 36 | IF assert.not_null(_commit_id) THEN 37 | 38 | _build_id = (SELECT build_id FROM postgres_ci.builds WHERE commit_id = _commit_id LIMIT 1); 39 | 40 | IF assert.true(build.accept(_build_id)) THEN 41 | 42 | PERFORM assert.false(build.accept(_build_id)); 43 | 44 | END IF; 45 | END IF; 46 | 47 | END IF; 48 | 49 | END IF; 50 | end; 51 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/build/test_add_part.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.test_add_part() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _build_id int; 6 | _commit_id int; 7 | _part_id int; 8 | begin 9 | 10 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 11 | 12 | IF assert.not_null(_project_owner_id) THEN 13 | 14 | _project_id = project.add( 15 | 'project', 16 | _project_owner_id, 17 | 'https://github.com/postgres-ci/core.git', 18 | '' 19 | ); 20 | 21 | IF assert.not_null(_project_id) THEN 22 | 23 | _commit_id = hook.commit( 24 | (SELECT project_token FROM postgres_ci.projects WHERE project_id = _project_id), 25 | 'master', 26 | encode(digest('commit' || clock_timestamp(), 'sha1'), 'hex'), 27 | 'message', 28 | CURRENT_TIMESTAMP - '1 day'::interval, 29 | 'Elephant Sam', 30 | 'samelephant82@gmail.com', 31 | 'Elephant Sam', 32 | 'samelephant82@gmail.com' 33 | ); 34 | 35 | IF assert.not_null(_commit_id) THEN 36 | 37 | _build_id = (SELECT build_id FROM postgres_ci.builds WHERE commit_id = _commit_id LIMIT 1); 38 | 39 | 40 | IF assert.true(build.accept(_build_id)) THEN 41 | 42 | PERFORM build.start(_build_id); 43 | 44 | _part_id = build.add_part( 45 | _build_id, 46 | 'version:42', 47 | 'image', 48 | 'container_id', 49 | 'output', 50 | CURRENT_TIMESTAMP, 51 | '[]' 52 | ); 53 | 54 | IF assert.not_null(_part_id) THEN 55 | 56 | PERFORM 57 | assert.equal(_build_id, build_id), 58 | assert.equal('image', image), 59 | assert.equal('container_id', container_id), 60 | assert.equal('version:42', version), 61 | assert.equal('output', output), 62 | assert.true(success) 63 | FROM postgres_ci.parts 64 | WHERE part_id = _part_id; 65 | 66 | PERFORM assert.true(FOUND); 67 | 68 | PERFORM assert.equal(0, (SELECT COUNT(*) FROM postgres_ci.tests WHERE part_id = _part_id)::int); 69 | END IF; 70 | 71 | 72 | _part_id = build.add_part( 73 | _build_id, 74 | 'version:42', 75 | 'image', 76 | 'container_id', 77 | 'output', 78 | CURRENT_TIMESTAMP, 79 | '[{"function" : "fn", "duration" : 0.42, "errors" : []}, {"function" : "fn2", "duration" : 0.42, "errors" : [{"message" : ""}]}]' 80 | ); 81 | 82 | IF assert.not_null(_part_id) THEN 83 | 84 | PERFORM 85 | assert.equal(_build_id, build_id), 86 | assert.equal('image', image), 87 | assert.equal('container_id', container_id), 88 | assert.equal('version:42', version), 89 | assert.equal('output', output), 90 | assert.false(success) 91 | FROM postgres_ci.parts 92 | WHERE part_id = _part_id; 93 | 94 | PERFORM assert.true(FOUND); 95 | 96 | 97 | PERFORM 98 | assert.equal(2, COUNT(*)::int), 99 | assert.equal(1, (COUNT(*) FILTER (WHERE jsonb_array_length(errors) > 0))::int), 100 | assert.equal(1, (COUNT(*) FILTER (WHERE jsonb_array_length(errors) = 0))::int) 101 | FROM postgres_ci.tests WHERE part_id = _part_id; 102 | 103 | PERFORM assert.true(FOUND); 104 | 105 | PERFORM build.stop(_build_id, 'config', ''); 106 | 107 | PERFORM 108 | assert.equal('config', config), 109 | assert.equal('failed', status) 110 | FROM postgres_ci.builds 111 | WHERE build_id = _build_id; 112 | 113 | PERFORM assert.true(FOUND); 114 | END IF; 115 | 116 | END IF; 117 | END IF; 118 | 119 | END IF; 120 | 121 | END IF; 122 | end; 123 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/build/test_fetch.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.test_fetch() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _build_id int; 6 | _commit_id int; 7 | begin 8 | 9 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 10 | 11 | IF assert.not_null(_project_owner_id) THEN 12 | 13 | _project_id = project.add( 14 | 'project', 15 | _project_owner_id, 16 | 'https://github.com/postgres-ci/core.git', 17 | '' 18 | ); 19 | 20 | IF assert.not_null(_project_id) THEN 21 | 22 | _commit_id = hook.commit( 23 | (SELECT project_token FROM postgres_ci.projects WHERE project_id = _project_id), 24 | 'master', 25 | encode(digest('commit' || clock_timestamp(), 'sha1'), 'hex'), 26 | 'message', 27 | CURRENT_TIMESTAMP - '1 day'::interval, 28 | 'Elephant Sam', 29 | 'samelephant82@gmail.com', 30 | 'Elephant Sam', 31 | 'samelephant82@gmail.com' 32 | ); 33 | 34 | PERFORM hook.commit( 35 | (SELECT project_token FROM postgres_ci.projects WHERE project_id = _project_id), 36 | 'master', 37 | encode(digest('commit' || clock_timestamp(), 'sha1'), 'hex'), 38 | 'message', 39 | CURRENT_TIMESTAMP - '1 day'::interval, 40 | 'Elephant Sam', 41 | 'samelephant82@gmail.com', 42 | 'Elephant Sam', 43 | 'samelephant82@gmail.com' 44 | ); 45 | 46 | IF assert.not_null(_commit_id) THEN 47 | 48 | _build_id = (SELECT build_id FROM postgres_ci.builds WHERE commit_id = _commit_id LIMIT 1); 49 | 50 | IF assert.equal(_build_id, build_id) FROM build.fetch() THEN 51 | 52 | PERFORM assert.not_equal(_build_id, build_id) FROM build.fetch(); 53 | 54 | PERFORM build.fetch(); 55 | 56 | PERFORM assert.true(NOT FOUND); 57 | 58 | END IF; 59 | 60 | END IF; 61 | 62 | END IF; 63 | 64 | END IF; 65 | end; 66 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/build/test_new.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.test_new() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _commit_id int; 6 | begin 7 | 8 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 9 | 10 | IF assert.not_null(_project_owner_id) THEN 11 | 12 | _project_id = project.add( 13 | 'project', 14 | _project_owner_id, 15 | 'https://github.com/postgres-ci/core.git', 16 | '' 17 | ); 18 | 19 | IF assert.not_null(_project_id) THEN 20 | 21 | _commit_id = hook.commit( 22 | (SELECT project_token FROM postgres_ci.projects WHERE project_id = _project_id), 23 | 'master', 24 | encode(digest('commit' || clock_timestamp(), 'sha1'), 'hex'), 25 | 'message', 26 | CURRENT_TIMESTAMP - '1 day'::interval, 27 | 'Elephant Sam', 28 | 'samelephant82@gmail.com', 29 | 'Elephant Sam', 30 | 'samelephant82@gmail.com' 31 | ); 32 | 33 | IF assert.not_null(_commit_id) THEN 34 | 35 | PERFORM 36 | assert.equal(_project_id, project_id), 37 | assert.equal(project.get_branch_id(_project_id, 'master'), branch_id), 38 | assert.equal('pending', status) 39 | FROM postgres_ci.builds 40 | WHERE commit_id = _commit_id; 41 | 42 | PERFORM assert.true(FOUND); 43 | END IF; 44 | 45 | END IF; 46 | 47 | END IF; 48 | end; 49 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/build/test_start.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.test_start() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _build_id int; 6 | _commit_id int; 7 | _commit_sha text; 8 | begin 9 | 10 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 11 | 12 | IF assert.not_null(_project_owner_id) THEN 13 | 14 | _project_id = project.add( 15 | 'project', 16 | _project_owner_id, 17 | 'https://github.com/postgres-ci/core.git', 18 | '' 19 | ); 20 | 21 | IF assert.not_null(_project_id) THEN 22 | 23 | _commit_sha = encode(digest('commit' || CURRENT_TIMESTAMP, 'sha1'), 'hex'); 24 | _commit_id = hook.commit( 25 | (SELECT project_token FROM postgres_ci.projects WHERE project_id = _project_id), 26 | 'master', 27 | _commit_sha, 28 | 'message', 29 | CURRENT_TIMESTAMP - '1 day'::interval, 30 | 'Elephant Sam', 31 | 'samelephant82@gmail.com', 32 | 'Elephant Sam', 33 | 'samelephant82@gmail.com' 34 | ); 35 | 36 | IF assert.not_null(_commit_id) THEN 37 | 38 | _build_id = (SELECT build_id FROM postgres_ci.builds WHERE commit_id = _commit_id LIMIT 1); 39 | 40 | PERFORM assert.exception( 41 | $sql$ SELECT build.start($sql$ || _build_id || $sql$) $sql$, 42 | exception_message := 'NOT_FOUND', 43 | exception_sqlstate := 'P0002' 44 | ); 45 | 46 | IF build.accept(_build_id) THEN 47 | 48 | PERFORM 49 | assert.equal('master', branch), 50 | assert.equal(_commit_sha, revision), 51 | assert.equal((SELECT repository_url FROM postgres_ci.projects WHERE project_id = _project_id), repository_url) 52 | FROM build.start(_build_id); 53 | 54 | PERFORM assert.exception( 55 | $sql$ SELECT build.start($sql$ || _build_id || $sql$) $sql$, 56 | exception_message := 'NOT_FOUND', 57 | exception_sqlstate := 'P0002' 58 | ); 59 | 60 | END IF; 61 | END IF; 62 | 63 | END IF; 64 | 65 | END IF; 66 | end; 67 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/build/test_stop.sql: -------------------------------------------------------------------------------- 1 | create or replace function build.test_stop() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _build_id int; 6 | _commit_id int; 7 | begin 8 | 9 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 10 | 11 | IF assert.not_null(_project_owner_id) THEN 12 | 13 | _project_id = project.add( 14 | 'project', 15 | _project_owner_id, 16 | 'https://github.com/postgres-ci/core.git', 17 | '' 18 | ); 19 | 20 | IF assert.not_null(_project_id) THEN 21 | 22 | _commit_id = hook.commit( 23 | (SELECT project_token FROM postgres_ci.projects WHERE project_id = _project_id), 24 | 'master', 25 | encode(digest('commit' || clock_timestamp(), 'sha1'), 'hex'), 26 | 'message', 27 | CURRENT_TIMESTAMP - '1 day'::interval, 28 | 'Elephant Sam', 29 | 'samelephant82@gmail.com', 30 | 'Elephant Sam', 31 | 'samelephant82@gmail.com' 32 | ); 33 | 34 | IF assert.not_null(_commit_id) THEN 35 | 36 | _build_id = (SELECT build_id FROM postgres_ci.builds WHERE commit_id = _commit_id LIMIT 1); 37 | 38 | PERFORM assert.exception( 39 | $sql$ SELECT build.stop($sql$ || _build_id || $sql$, '', '') $sql$, 40 | exception_message := 'NOT_FOUND', 41 | exception_sqlstate := 'P0002' 42 | ); 43 | 44 | IF assert.true(build.accept(_build_id)) THEN 45 | 46 | PERFORM build.start(_build_id); 47 | 48 | PERFORM build.stop(_build_id, 'config', ''); 49 | 50 | PERFORM assert.exception( 51 | $sql$ SELECT build.stop($sql$ || _build_id || $sql$, '', '') $sql$, 52 | exception_message := 'NOT_FOUND', 53 | exception_sqlstate := 'P0002' 54 | ); 55 | 56 | PERFORM 57 | assert.equal('config', config), 58 | assert.equal('success', status) 59 | FROM postgres_ci.builds 60 | WHERE build_id = _build_id; 61 | 62 | PERFORM assert.true(FOUND); 63 | 64 | END IF; 65 | END IF; 66 | 67 | -- errors 68 | 69 | _commit_id = hook.commit( 70 | (SELECT project_token FROM postgres_ci.projects WHERE project_id = _project_id), 71 | 'master', 72 | encode(digest('commit' || clock_timestamp(), 'sha1'), 'hex'), 73 | 'message', 74 | CURRENT_TIMESTAMP - '1 day'::interval, 75 | 'Elephant Sam', 76 | 'samelephant82@gmail.com', 77 | 'Elephant Sam', 78 | 'samelephant82@gmail.com' 79 | ); 80 | 81 | IF assert.not_null(_commit_id) THEN 82 | 83 | _build_id = (SELECT build_id FROM postgres_ci.builds WHERE commit_id = _commit_id LIMIT 1); 84 | 85 | PERFORM assert.exception( 86 | $sql$ SELECT build.stop($sql$ || _build_id || $sql$, '', '') $sql$, 87 | exception_message := 'NOT_FOUND', 88 | exception_sqlstate := 'P0002' 89 | ); 90 | 91 | IF assert.true(build.accept(_build_id)) THEN 92 | 93 | PERFORM build.start(_build_id); 94 | 95 | PERFORM build.stop(_build_id, 'config', 'Error'); 96 | 97 | PERFORM assert.exception( 98 | $sql$ SELECT build.stop($sql$ || _build_id || $sql$, '', '') $sql$, 99 | exception_message := 'NOT_FOUND', 100 | exception_sqlstate := 'P0002' 101 | ); 102 | 103 | PERFORM 104 | assert.equal('config', config), 105 | assert.equal('Error', error), 106 | assert.equal('failed', status) 107 | FROM postgres_ci.builds 108 | WHERE build_id = _build_id; 109 | 110 | PERFORM assert.true(FOUND); 111 | 112 | END IF; 113 | END IF; 114 | 115 | END IF; 116 | 117 | END IF; 118 | end; 119 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/coverage.sql: -------------------------------------------------------------------------------- 1 | WITH coverage AS ( 2 | SELECT 3 | namespace.nspname || '.' || func.proname AS func, 4 | CASE WHEN tests.proname IS NOT NULL 5 | THEN '+' 6 | ELSE '-' 7 | END AS covered 8 | FROM pg_proc func 9 | JOIN pg_namespace namespace ON func.pronamespace = namespace.oid 10 | LEFT JOIN pg_proc tests ON func.pronamespace = tests.pronamespace 11 | AND func.proname = RIGHT(tests.proname, -5) 12 | WHERE namespace.nspname NOT LIKE 'pg_%' 13 | AND namespace.nspname NOT IN ('assert', 'information_schema') 14 | AND func.proname NOT LIKE 'test_%' 15 | AND func.prolang NOT IN (12, 13) -- @see pg_language 16 | ORDER BY covered DESC, func 17 | ) 18 | SELECT func, covered FROM coverage 19 | UNION ALL ( 20 | SELECT 'Coverage: ', ( 21 | SELECT 22 | ( 23 | ( 24 | (COUNT(*) FILTER (WHERE covered = '+'))::numeric / COUNT(*)::numeric 25 | ) * 100 26 | )::int 27 | FROM coverage 28 | )::text || '% of functions' 29 | ); -------------------------------------------------------------------------------- /tests/grants.sql: -------------------------------------------------------------------------------- 1 | grant create on schema auth to tester; 2 | grant create on schema hook to tester; 3 | grant create on schema users to tester; 4 | grant create on schema build to tester; 5 | grant create on schema project to tester; 6 | grant create on schema password to tester; 7 | grant create on schema postgres_ci to tester; 8 | grant create on schema notification to tester; 9 | 10 | grant select on all tables in schema postgres_ci to tester; 11 | grant update on table postgres_ci.sessions to tester; 12 | 13 | 14 | -- create user tester with password 'password' login; -------------------------------------------------------------------------------- /tests/hook/test_commit.sql: -------------------------------------------------------------------------------- 1 | create or replace function hook.test_commit() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _commit_id int; 6 | _commit_sha text; 7 | begin 8 | 9 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 10 | 11 | IF assert.not_null(_project_owner_id) THEN 12 | 13 | _project_id = project.add( 14 | 'project', 15 | _project_owner_id, 16 | 'https://github.com/postgres-ci/core.git', 17 | '' 18 | ); 19 | 20 | IF assert.not_null(_project_id) THEN 21 | 22 | _commit_sha = encode(digest('commit' || CURRENT_TIMESTAMP, 'sha1'), 'hex'); 23 | _commit_id = hook.commit( 24 | (SELECT project_token FROM postgres_ci.projects WHERE project_id = _project_id), 25 | 'master', 26 | _commit_sha, 27 | 'message', 28 | CURRENT_TIMESTAMP - '1 day'::interval, 29 | 'Elephant Sam', 30 | 'samelephant82@gmail.com', 31 | 'Elephant Sam', 32 | 'samelephant82@gmail.com' 33 | ); 34 | 35 | IF assert.not_null(_commit_id) THEN 36 | 37 | PERFORM 38 | assert.equal(project.get_branch_id(_project_id, 'master'), branch_id), 39 | assert.equal(_commit_sha, commit_sha), 40 | assert.equal(CURRENT_TIMESTAMP - '1 day'::interval, committed_at), 41 | assert.equal('Elephant Sam', committer_name), 42 | assert.equal('samelephant82@gmail.com', committer_email) 43 | FROM postgres_ci.commits 44 | WHERE commit_id = _commit_id; 45 | 46 | END IF; 47 | 48 | END IF; 49 | 50 | END IF; 51 | end; 52 | $$ language plpgsql security definer; 53 | -------------------------------------------------------------------------------- /tests/hook/test_github_push.sql: -------------------------------------------------------------------------------- 1 | create or replace function hook.test_github_push() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _github_name text; 6 | _push jsonb; 7 | begin 8 | 9 | _push = ' 10 | [ 11 | { 12 | "commit_sha":"fa7e3d5fc6b69309e2e8eb9e2af82da3cd96f383", 13 | "commit_message":"Test", 14 | "committed_at":"2016-05-05T17:40:59.431696+03:00", 15 | "committer_name":"kshvakov", 16 | "committer_email":"shvakov@gmail.com", 17 | "author_name":"kshvakov", 18 | "author_email":"shvakov@gmail.com", 19 | "created_at":"2016-05-05T17:40:59.431696+03:00" 20 | }, 21 | { 22 | "commit_sha":"654fe21cd1874d3028bfbc84e1ff4b6245cfac9b", 23 | "commit_message":"add list builds fn\n", 24 | "committed_at":"2016-05-05T17:53:55+03:00", 25 | "committer_name":"kshvakov", 26 | "committer_email":"shvakov@gmail.com", 27 | "author_name":"kshvakov", 28 | "author_email":"shvakov@gmail.com", 29 | "created_at":"2016-05-05T17:53:55.860997+03:00" 30 | }, 31 | { 32 | "commit_sha":"ac4c4a78e4f0321d273c0502165c98f8b71d2eb0", 33 | "commit_message":"misc\n", 34 | "committed_at":"2016-05-06T11:45:03+03:00", 35 | "committer_name":"kshvakov", 36 | "committer_email":"shvakov@gmail.com", 37 | "author_name":"kshvakov", 38 | "author_email":"shvakov@gmail.com", 39 | "created_at":"2016-05-06T11:45:03.421098+03:00" 40 | } 41 | ] 42 | '; 43 | 44 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 45 | 46 | IF assert.not_null(_project_owner_id) THEN 47 | 48 | _project_id = project.add( 49 | 'project', 50 | _project_owner_id, 51 | 'https://github.com/postgres-ci/core.git', 52 | '' 53 | ); 54 | 55 | IF assert.not_null(_project_id) THEN 56 | 57 | _github_name = (SELECT github_name FROM postgres_ci.projects WHERE project_id = _project_id); 58 | 59 | IF assert.equal(3, (SELECT COUNT(*) FROM (SELECT commit_id FROM hook.github_push(_github_name, 'master', _push)) _ )::int) THEN 60 | 61 | PERFORM assert.equal(3, (SELECT COUNT(*) FROM postgres_ci.commits WHERE project_id = _project_id)::int); 62 | 63 | END IF; 64 | 65 | END IF; 66 | 67 | END IF; 68 | end; 69 | $$ language plpgsql security definer; 70 | -------------------------------------------------------------------------------- /tests/hook/test_push.sql: -------------------------------------------------------------------------------- 1 | create or replace function hook.test_push() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _token uuid; 6 | _push jsonb; 7 | begin 8 | 9 | _push = ' 10 | [ 11 | { 12 | "commit_sha":"fa7e3d5fc6b69309e2e8eb9e2af82da3cd96f383", 13 | "commit_message":"Test", 14 | "committed_at":"2016-05-05T17:40:59.431696+03:00", 15 | "committer_name":"kshvakov", 16 | "committer_email":"shvakov@gmail.com", 17 | "author_name":"kshvakov", 18 | "author_email":"shvakov@gmail.com", 19 | "created_at":"2016-05-05T17:40:59.431696+03:00" 20 | }, 21 | { 22 | "commit_sha":"654fe21cd1874d3028bfbc84e1ff4b6245cfac9b", 23 | "commit_message":"add list builds fn\n", 24 | "committed_at":"2016-05-05T17:53:55+03:00", 25 | "committer_name":"kshvakov", 26 | "committer_email":"shvakov@gmail.com", 27 | "author_name":"kshvakov", 28 | "author_email":"shvakov@gmail.com", 29 | "created_at":"2016-05-05T17:53:55.860997+03:00" 30 | }, 31 | { 32 | "commit_sha":"ac4c4a78e4f0321d273c0502165c98f8b71d2eb0", 33 | "commit_message":"misc\n", 34 | "committed_at":"2016-05-06T11:45:03+03:00", 35 | "committer_name":"kshvakov", 36 | "committer_email":"shvakov@gmail.com", 37 | "author_name":"kshvakov", 38 | "author_email":"shvakov@gmail.com", 39 | "created_at":"2016-05-06T11:45:03.421098+03:00" 40 | } 41 | ] 42 | '; 43 | 44 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 45 | 46 | IF assert.not_null(_project_owner_id) THEN 47 | 48 | _project_id = project.add( 49 | 'project', 50 | _project_owner_id, 51 | 'https://github.com/postgres-ci/core.git', 52 | '' 53 | ); 54 | 55 | IF assert.not_null(_project_id) THEN 56 | 57 | _token = (SELECT project_token FROM postgres_ci.projects WHERE project_id = _project_id); 58 | 59 | IF assert.equal(3, (SELECT COUNT(*) FROM (SELECT commit_id FROM hook.push(_token, 'master', _push)) _ )::int) THEN 60 | 61 | PERFORM assert.equal(3, (SELECT COUNT(*) FROM postgres_ci.commits WHERE project_id = _project_id)::int); 62 | 63 | END IF; 64 | 65 | END IF; 66 | 67 | END IF; 68 | end; 69 | $$ language plpgsql security definer; 70 | -------------------------------------------------------------------------------- /tests/manual_test_runner.sql: -------------------------------------------------------------------------------- 1 | -- :~/tests$ psql -U tester -d postgres_ci < manual_test_runner.sql 2 | \i tests.sql 3 | 4 | select 5 | namespace || '.' || procedure as func, 6 | case 7 | when array_length(errors, 1) is null 8 | then 'PASS' 9 | else 'FAIL' 10 | end 11 | as result, 12 | to_json(errors) as errors, 13 | extract(epoch from finished_at - started_at) || 's' as duration 14 | from assert.test_runner(); 15 | 16 | \i coverage.sql; -------------------------------------------------------------------------------- /tests/notification/test_bind_with_telegram.sql: -------------------------------------------------------------------------------- 1 | create or replace function notification.test_bind_with_telegram() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 7 | 8 | IF assert.true(EXISTS(SELECT null FROM postgres_ci.user_notification_method WHERE user_id = _user_id), 'Notification method doesn''t exists') THEN 9 | 10 | IF ( 11 | SELECT 12 | assert.equal('email', method) AND 13 | assert.equal('samelephant82@gmail.com', text_id) AND 14 | assert.equal(0::bigint, int_id) 15 | FROM postgres_ci.user_notification_method WHERE user_id = _user_id 16 | ) THEN 17 | 18 | PERFORM notification.update_method(_user_id, 'telegram', 'telegram_username'); 19 | 20 | IF ( 21 | SELECT 22 | assert.equal('telegram', method) AND 23 | assert.equal('telegram_username', text_id) AND 24 | assert.equal(0::bigint, int_id) 25 | FROM postgres_ci.user_notification_method WHERE user_id = _user_id 26 | ) THEN 27 | 28 | PERFORM notification.bind_with_telegram(_user_id, 'telegram_username', 42); 29 | 30 | IF assert.equal(42::bigint, (SELECT int_id FROM postgres_ci.user_notification_method WHERE user_id = _user_id)) THEN 31 | 32 | PERFORM assert.exception( 33 | $sql$ SELECT notification.bind_with_telegram(-1, 'telegram_username', 42) $sql$, 34 | exception_message := 'NOT_FOUND', 35 | exception_sqlstate := 'P0002' 36 | ); 37 | 38 | PERFORM assert.exception( 39 | $sql$ SELECT notification.bind_with_telegram($sql$ || _user_id || $sql$, 'telegram_username2', 42) $sql$, 40 | exception_message := 'NOT_FOUND', 41 | exception_sqlstate := 'P0002' 42 | ); 43 | END IF; 44 | 45 | END IF; 46 | 47 | END IF; 48 | END IF; 49 | 50 | end; 51 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/notification/test_find_user_by_telegram_username.sql: -------------------------------------------------------------------------------- 1 | create or replace function notification.test_find_user_by_telegram_username() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 7 | 8 | IF assert.true(EXISTS(SELECT null FROM postgres_ci.user_notification_method WHERE user_id = _user_id), 'Notification method doesn''t exists') THEN 9 | 10 | IF ( 11 | SELECT 12 | assert.equal('email', method) AND 13 | assert.equal('samelephant82@gmail.com', text_id) AND 14 | assert.equal(0::bigint, int_id) 15 | FROM postgres_ci.user_notification_method WHERE user_id = _user_id 16 | ) THEN 17 | 18 | PERFORM notification.update_method(_user_id, 'telegram', 'telegram_username'); 19 | 20 | IF ( 21 | SELECT 22 | assert.equal('telegram', method) AND 23 | assert.equal('telegram_username', text_id) AND 24 | assert.equal(0::bigint, int_id) 25 | FROM postgres_ci.user_notification_method WHERE user_id = _user_id 26 | ) THEN 27 | 28 | PERFORM notification.bind_with_telegram(_user_id, 'telegram_username', 42); 29 | 30 | PERFORM 31 | assert.equal(_user_id, user_id), 32 | assert.equal(42::bigint, telegram_id) 33 | FROM notification.find_user_by_telegram_username('telegram_username'); 34 | 35 | END IF; 36 | 37 | END IF; 38 | END IF; 39 | 40 | end; 41 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/notification/test_get_method.sql: -------------------------------------------------------------------------------- 1 | create or replace function notification.test_get_method() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 7 | 8 | IF assert.true(EXISTS(SELECT null FROM postgres_ci.user_notification_method WHERE user_id = _user_id), 'Notification method doesn''t exists') THEN 9 | 10 | 11 | PERFORM 12 | assert.equal('email', method), 13 | assert.equal('samelephant82@gmail.com', text_id), 14 | assert.equal(0::bigint, int_id) 15 | FROM notification.get_method(_user_id); 16 | 17 | PERFORM assert.exception( 18 | $sql$ SELECT notification.get_method(-1) $sql$, 19 | exception_message := 'NOT_FOUND', 20 | exception_sqlstate := 'P0002' 21 | ); 22 | 23 | END IF; 24 | 25 | end; 26 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/notification/test_update_method.sql: -------------------------------------------------------------------------------- 1 | create or replace function notification.test_update_method() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 7 | 8 | IF assert.true(EXISTS(SELECT null FROM postgres_ci.user_notification_method WHERE user_id = _user_id), 'Notification method doesn''t exists') THEN 9 | 10 | IF ( 11 | SELECT 12 | assert.equal('email', method) AND 13 | assert.equal('samelephant82@gmail.com', text_id) AND 14 | assert.equal(0::bigint, int_id) 15 | FROM postgres_ci.user_notification_method WHERE user_id = _user_id 16 | ) THEN 17 | 18 | PERFORM notification.update_method(_user_id, 'telegram', 'telegram_username'); 19 | 20 | IF ( 21 | SELECT 22 | assert.equal('telegram', method) AND 23 | assert.equal('telegram_username', text_id) AND 24 | assert.equal(0::bigint, int_id) 25 | FROM postgres_ci.user_notification_method WHERE user_id = _user_id 26 | ) THEN 27 | 28 | PERFORM notification.bind_with_telegram(_user_id, 'telegram_username', 42); 29 | 30 | IF assert.equal(42::bigint, (SELECT int_id FROM postgres_ci.user_notification_method WHERE user_id = _user_id)) THEN 31 | PERFORM notification.update_method(_user_id, 'none', 'nonenone'); 32 | PERFORM 33 | assert.equal('none', method), 34 | assert.equal('', text_id), 35 | assert.equal(0::bigint, int_id) 36 | FROM postgres_ci.user_notification_method WHERE user_id = _user_id; 37 | END IF; 38 | 39 | END IF; 40 | 41 | END IF; 42 | END IF; 43 | 44 | end; 45 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/password/test_change.sql: -------------------------------------------------------------------------------- 1 | create or replace function password.test_change() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 7 | 8 | IF assert.not_null(_user_id) AND assert.true(password.check(_user_id, 'password')) THEN 9 | 10 | if assert.true(password.change(_user_id, 'password', 'password2')) THEN 11 | 12 | PERFORM assert.true(password.check(_user_id, 'password2')); 13 | END IF; 14 | 15 | PERFORM assert.exception( 16 | $sql$ SELECT password.check($sql$ || _user_id || $sql$, 'password') $sql$, 17 | exception_message := 'INVALID_PASSWORD', 18 | exception_sqlstate := '28P01' 19 | ); 20 | 21 | END IF; 22 | 23 | end; 24 | $$ language plpgsql; -------------------------------------------------------------------------------- /tests/password/test_check.sql: -------------------------------------------------------------------------------- 1 | create or replace function password.test_check() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 7 | 8 | IF assert.not_null(_user_id) THEN 9 | 10 | PERFORM assert.true(password.check(_user_id, 'password')); 11 | END IF; 12 | 13 | PERFORM assert.exception( 14 | $sql$ SELECT password.check(-1, 'password') $sql$, 15 | exception_message := 'NOT_FOUND', 16 | exception_sqlstate := 'P0002' 17 | ); 18 | 19 | PERFORM assert.exception( 20 | $sql$ SELECT password.check($sql$ || _user_id || $sql$, 'password2') $sql$, 21 | exception_message := 'INVALID_PASSWORD', 22 | exception_sqlstate := '28P01' 23 | ); 24 | 25 | end; 26 | $$ language plpgsql; -------------------------------------------------------------------------------- /tests/password/test_reset.sql: -------------------------------------------------------------------------------- 1 | create or replace function password.test_reset() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 7 | 8 | IF assert.not_null(_user_id) AND assert.true(password.check(_user_id, 'password')) THEN 9 | 10 | PERFORM password.reset(_user_id, 'password2'); 11 | 12 | IF assert.true(password.check(_user_id, 'password2')) THEN 13 | 14 | PERFORM assert.exception( 15 | $sql$ SELECT password.check($sql$ || _user_id || $sql$, 'password') $sql$, 16 | exception_message := 'INVALID_PASSWORD', 17 | exception_sqlstate := '28P01' 18 | ); 19 | END IF; 20 | 21 | END IF; 22 | 23 | end; 24 | $$ language plpgsql; -------------------------------------------------------------------------------- /tests/postgres_ci/test_sha1.sql: -------------------------------------------------------------------------------- 1 | create or replace function postgres_ci.test_sha1() returns void as $$ 2 | declare 3 | _value text; 4 | begin 5 | 6 | FOR _value IN SELECT 'value_' || v FROM generate_series(1, 100) v LOOP 7 | 8 | IF NOT assert.equal(encode(digest(_value, 'sha1'), 'hex'), postgres_ci.sha1(_value)) THEN 9 | return; 10 | END IF; 11 | 12 | END LOOP; 13 | end; 14 | $$ language plpgsql; -------------------------------------------------------------------------------- /tests/project/test_add.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.test_add() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_name text; 5 | _project_owner_id int; 6 | begin 7 | _project_name = 'New project ' || random(); 8 | 9 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 10 | 11 | IF assert.not_null(_project_owner_id) THEN 12 | 13 | _project_id = project.add( 14 | _project_name, 15 | _project_owner_id, 16 | 'https://github.com/postgres-ci/core.git', 17 | 'Ho-Ho-Ho' 18 | ); 19 | 20 | IF assert.not_null(_project_id) THEN 21 | 22 | PERFORM 23 | assert.equal(_project_name, project_name), 24 | assert.equal('postgres-ci/core', github_name), 25 | assert.equal('Ho-Ho-Ho', github_secret) 26 | FROM postgres_ci.projects 27 | WHERE project_id = _project_id; 28 | 29 | END IF; 30 | 31 | END IF; 32 | 33 | PERFORM assert.exception( 34 | $sql$ SELECT project.add('project', $sql$ || _project_owner_id || $sql$, 'https://github.com/postgres-ci/core.git', '') $sql$, 35 | exception_table := 'projects', 36 | exception_schema := 'postgres_ci', 37 | exception_constraint := 'udx_is_github_repo' 38 | ); 39 | 40 | PERFORM assert.exception( 41 | $sql$ SELECT project.add('project', -1, 'https://github.com/' || random(), '') $sql$, 42 | exception_schema := 'postgres_ci', 43 | exception_sqlstate := '23503', 44 | exception_constraint := 'fk_project_owner_id' 45 | ); 46 | end; 47 | $$ language plpgsql security definer; 48 | 49 | 50 | 51 | -------------------------------------------------------------------------------- /tests/project/test_add_commit.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.test_add_commit() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _commit_id int; 6 | _commit_sha text; 7 | begin 8 | 9 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 10 | 11 | IF assert.not_null(_project_owner_id) THEN 12 | 13 | _project_id = project.add( 14 | 'project', 15 | _project_owner_id, 16 | 'https://github.com/postgres-ci/core.git', 17 | '' 18 | ); 19 | 20 | IF assert.not_null(_project_id) THEN 21 | 22 | _commit_sha = encode(digest('commit' || CURRENT_TIMESTAMP, 'sha1'), 'hex'); 23 | _commit_id = project.add_commit( 24 | _project_id, 25 | 'master', 26 | _commit_sha, 27 | 'message', 28 | CURRENT_TIMESTAMP - '1 day'::interval, 29 | 'Elephant Sam', 30 | 'samelephant82@gmail.com', 31 | 'Elephant Sam', 32 | 'samelephant82@gmail.com' 33 | ); 34 | 35 | IF assert.not_null(_commit_id) THEN 36 | 37 | PERFORM 38 | assert.equal(project.get_branch_id(_project_id, 'master'), branch_id), 39 | assert.equal(_commit_sha, commit_sha), 40 | assert.equal(CURRENT_TIMESTAMP - '1 day'::interval, committed_at), 41 | assert.equal('Elephant Sam', committer_name), 42 | assert.equal('samelephant82@gmail.com', committer_email) 43 | FROM postgres_ci.commits 44 | WHERE commit_id = _commit_id; 45 | 46 | END IF; 47 | 48 | END IF; 49 | 50 | END IF; 51 | end; 52 | $$ language plpgsql security definer; 53 | 54 | -------------------------------------------------------------------------------- /tests/project/test_delete.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.test_delete() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_name text; 5 | _project_owner_id int; 6 | begin 7 | _project_name = 'New project ' || random(); 8 | 9 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 10 | 11 | IF assert.not_null(_project_owner_id) THEN 12 | 13 | _project_id = project.add( 14 | _project_name, 15 | _project_owner_id, 16 | 'https://github.com/postgres-ci/core.git', 17 | 'Ho-Ho-Ho' 18 | ); 19 | 20 | IF assert.not_null(_project_id) THEN 21 | 22 | PERFORM 23 | assert.equal(_project_name, project_name), 24 | assert.equal('postgres-ci/core', github_name), 25 | assert.equal('Ho-Ho-Ho', github_secret) 26 | FROM postgres_ci.projects 27 | WHERE project_id = _project_id; 28 | 29 | END IF; 30 | 31 | END IF; 32 | 33 | PERFORM assert.exception( 34 | $sql$ SELECT project.add('project', $sql$ || _project_owner_id || $sql$, 'https://github.com/postgres-ci/core.git', '') $sql$, 35 | exception_table := 'projects', 36 | exception_schema := 'postgres_ci', 37 | exception_constraint := 'udx_is_github_repo' 38 | ); 39 | 40 | PERFORM assert.exception( 41 | $sql$ SELECT project.add('project', -1, 'https://github.com/' || random(), '') $sql$, 42 | exception_schema := 'postgres_ci', 43 | exception_sqlstate := '23503', 44 | exception_constraint := 'fk_project_owner_id' 45 | ); 46 | end; 47 | $$ language plpgsql security definer; 48 | 49 | 50 | 51 | -------------------------------------------------------------------------------- /tests/project/test_get.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.test_get() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_name text; 5 | _project_owner_id int; 6 | begin 7 | _project_name = 'New project ' || random(); 8 | 9 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 10 | 11 | IF assert.not_null(_project_owner_id) THEN 12 | 13 | _project_id = project.add( 14 | _project_name, 15 | _project_owner_id, 16 | 'https://github.com/postgres-ci/core.git', 17 | 'Ho-Ho-Ho' 18 | ); 19 | 20 | IF assert.not_null(_project_id) THEN 21 | 22 | PERFORM users.add('possible', 'owner', '-', 'possible@owner.com', true); 23 | 24 | PERFORM 25 | assert.equal(_project_name, project_name), 26 | assert.equal('Ho-Ho-Ho', github_secret), 27 | assert.equal(_project_owner_id, project_owner_id), 28 | assert.equal(2, jsonb_array_length(possible_owners)) 29 | FROM project.get(_project_id); 30 | 31 | END IF; 32 | END IF; 33 | 34 | PERFORM assert.exception( 35 | $sql$ SELECT project.get(-1) $sql$, 36 | exception_message := 'NOT_FOUND', 37 | exception_sqlstate := 'P0002' 38 | ); 39 | 40 | end; 41 | $$ language plpgsql security definer; 42 | 43 | 44 | 45 | -------------------------------------------------------------------------------- /tests/project/test_get_branch_id.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.test_get_branch_id() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_owner_id int; 5 | _branch text; 6 | _branch_id int; 7 | begin 8 | 9 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 10 | 11 | IF assert.not_null(_project_owner_id) THEN 12 | 13 | _project_id = project.add( 14 | 'project', 15 | _project_owner_id, 16 | 'https://github.com/postgres-ci/core.git', 17 | '' 18 | ); 19 | 20 | IF assert.not_null(_project_id) THEN 21 | 22 | IF assert.true(NOT EXISTS( 23 | SELECT null FROM postgres_ci.branches WHERE project_id = _project_id AND branch = 'master' 24 | ) 25 | ) THEN 26 | 27 | _branch_id = project.get_branch_id(_project_id, 'master'); 28 | 29 | IF assert.not_null(_branch_id) THEN 30 | 31 | PERFORM assert.equal(_branch_id, project.get_branch_id(_project_id, 'master')); 32 | PERFORM assert.not_equal(_branch_id, project.get_branch_id(_project_id, 'master2')); 33 | 34 | END IF; 35 | 36 | END IF; 37 | 38 | END IF; 39 | 40 | END IF; 41 | end; 42 | $$ language plpgsql security definer; 43 | -------------------------------------------------------------------------------- /tests/project/test_get_github_secret.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.test_get_github_secret() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_name text; 5 | _project_owner_id int; 6 | begin 7 | _project_name = 'New project ' || random(); 8 | 9 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 10 | 11 | IF assert.not_null(_project_owner_id) THEN 12 | 13 | _project_id = project.add( 14 | _project_name, 15 | _project_owner_id, 16 | 'https://github.com/postgres-ci/core.git', 17 | 'GitHub Secret' 18 | ); 19 | 20 | IF assert.not_null(_project_id) THEN 21 | 22 | PERFORM 23 | assert.equal('GitHub Secret', secret) 24 | FROM project.get_github_secret('postgres-ci/core'); 25 | 26 | END IF; 27 | END IF; 28 | 29 | end; 30 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/project/test_get_possible_owners.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.test_get_possible_owners() returns void as $$ 2 | declare 3 | i int; 4 | begin 5 | FOR i IN 1..100 LOOP 6 | PERFORM assert.not_null(users.add('login' || i, 'password' || i, 'Elephant Sam', 'samelephant82@gmail.com' || i, false)); 7 | END LOOP; 8 | 9 | PERFORM users.delete(user_id) FROM postgres_ci.users ORDER BY user_id LIMIT 50; 10 | 11 | PERFORM assert.equal(50, ( 12 | SELECT COUNT(*) FROM (SELECT user_id FROM project.get_possible_owners()) _ 13 | )::int 14 | ); 15 | 16 | end; 17 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/project/test_github_name.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.test_github_name() returns void as $$ 2 | declare 3 | repo_url text; 4 | github_name text; 5 | begin 6 | 7 | FOR repo_url, github_name IN VALUES 8 | ('https://github.com/postgres/postgres.git', 'postgres/postgres'), 9 | ('git@github.com:postgres/postgres.git', 'postgres/postgres'), 10 | ('git@github.com:postgres-ci/assert.git', 'postgres-ci/assert'), 11 | ('https://github.com/postgres-ci/assert.git', 'postgres-ci/assert'), 12 | ('https://not_github.com/postgres-ci/assert.git', ''), 13 | ('https://github.net/postgres-ci/assert.git', '') 14 | LOOP 15 | 16 | IF NOT assert.equal(github_name, project.github_name(repo_url)) THEN 17 | return; 18 | END IF; 19 | 20 | END LOOP; 21 | 22 | end; 23 | $$ language plpgsql; 24 | 25 | -------------------------------------------------------------------------------- /tests/project/test_list.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.test_list() returns void as $$ 2 | declare 3 | i int; 4 | _project_owner_id int; 5 | begin 6 | 7 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 8 | 9 | IF assert.not_null(_project_owner_id) THEN 10 | 11 | FOR i IN 1..100 LOOP 12 | PERFORM assert.not_null(project.add('P' || i, _project_owner_id, 'repo' || i, '')); 13 | END LOOP; 14 | END IF; 15 | 16 | IF assert.equal(100, (SELECT COUNT(*) FROM (SELECT project_id FROM project.list()) _ )::int) THEN 17 | 18 | PERFORM project.delete(project_id) FROM postgres_ci.projects ORDER BY project_id LIMIT 50; 19 | 20 | PERFORM assert.equal(50, (SELECT COUNT(*) FROM (SELECT project_id FROM project.list()) _ )::int); 21 | END IF; 22 | 23 | end; 24 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/project/test_update.sql: -------------------------------------------------------------------------------- 1 | create or replace function project.test_update() returns void as $$ 2 | declare 3 | _project_id int; 4 | _project_name text; 5 | _project_owner_id int; 6 | begin 7 | _project_name = 'New project ' || random(); 8 | 9 | _project_owner_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 10 | 11 | IF assert.not_null(_project_owner_id) THEN 12 | 13 | _project_id = project.add( 14 | _project_name, 15 | _project_owner_id, 16 | 'https://github.com/postgres-ci/core.git', 17 | 'Ho-Ho-Ho' 18 | ); 19 | 20 | IF assert.not_null(_project_id) THEN 21 | 22 | PERFORM 23 | assert.equal(_project_name, project_name), 24 | assert.equal('postgres-ci/core', github_name), 25 | assert.equal('Ho-Ho-Ho', github_secret) 26 | FROM postgres_ci.projects 27 | WHERE project_id = _project_id; 28 | 29 | END IF; 30 | 31 | IF assert.exception( 32 | $sql$ SELECT project.update(-1, '', 0, '', '') $sql$, 33 | exception_message := 'NOT_FOUND', 34 | exception_sqlstate := 'P0002' 35 | ) THEN 36 | 37 | PERFORM project.update( 38 | _project_id, 39 | 'UPDATE_' || _project_name, 40 | _project_owner_id, 41 | 'https://github.com/postgres-ci/core.git', 42 | 'Ho-Ho-Ho2' 43 | ); 44 | 45 | PERFORM 46 | assert.equal('UPDATE_' || _project_name, project_name), 47 | assert.equal('postgres-ci/core', github_name), 48 | assert.equal('Ho-Ho-Ho2', github_secret) 49 | FROM postgres_ci.projects 50 | WHERE project_id = _project_id; 51 | END IF; 52 | 53 | END IF; 54 | 55 | end; 56 | $$ language plpgsql security definer; 57 | 58 | 59 | 60 | -------------------------------------------------------------------------------- /tests/tests.sql: -------------------------------------------------------------------------------- 1 | \i auth/test_login.sql 2 | \i auth/test_gc.sql 3 | \i auth/test_logout.sql 4 | \i auth/test_get_user.sql 5 | \i build/test_new.sql 6 | \i build/test_accept.sql 7 | \i build/test_fetch.sql 8 | \i build/test_start.sql 9 | \i build/test_add_part.sql 10 | \i build/test_stop.sql 11 | \i hook/test_commit.sql 12 | \i hook/test_push.sql 13 | \i hook/test_github_push.sql 14 | \i project/test_add.sql 15 | \i project/test_get.sql 16 | \i project/test_update.sql 17 | \i project/test_delete.sql 18 | \i project/test_list.sql 19 | \i project/test_add_commit.sql 20 | \i project/test_github_name.sql 21 | \i project/test_get_github_secret.sql 22 | \i project/test_get_branch_id.sql 23 | \i project/test_get_possible_owners.sql 24 | \i users/test_add.sql 25 | \i users/test_get.sql 26 | \i users/test_update.sql 27 | \i users/test_delete.sql 28 | \i users/test_list.sql 29 | \i notification/test_update_method.sql 30 | \i notification/test_get_method.sql 31 | \i notification/test_bind_with_telegram.sql 32 | \i notification/test_find_user_by_telegram_username.sql 33 | \i password/test_check.sql 34 | \i password/test_change.sql 35 | \i password/test_reset.sql 36 | \i postgres_ci/test_sha1.sql 37 | 38 | do $$ declare 39 | namespace text; 40 | procedure text; 41 | begin 42 | FOR namespace, procedure IN VALUES 43 | ('auth', 'test_login'), 44 | ('auth', 'test_logout'), 45 | ('auth', 'test_gc'), 46 | ('auth', 'test_get_user'), 47 | ('build', 'test_new'), 48 | ('build', 'test_accept'), 49 | ('build', 'test_fetch'), 50 | ('build', 'test_start'), 51 | ('build', 'test_add_part'), 52 | ('build', 'test_stop'), 53 | ('hook', 'test_commit'), 54 | ('hook', 'test_push'), 55 | ('hook', 'test_github_push'), 56 | ('project', 'test_add'), 57 | ('project', 'test_get'), 58 | ('project', 'test_update'), 59 | ('project', 'test_delete'), 60 | ('project', 'test_add_commit'), 61 | ('project', 'test_get_github_secret'), 62 | ('project', 'test_github_name'), 63 | ('project', 'test_get_branch_id'), 64 | ('project', 'test_get_possible_owners'), 65 | ('project', 'test_list'), 66 | ('users', 'test_add'), 67 | ('users', 'test_get'), 68 | ('users', 'test_update'), 69 | ('users', 'test_delete'), 70 | ('users', 'test_list'), 71 | ('notification','test_update_method'), 72 | ('notification', 'test_get_method'), 73 | ('notification','test_bind_with_telegram'), 74 | ('notification','test_find_user_by_telegram_username'), 75 | ('password', 'test_check'), 76 | ('password', 'test_change'), 77 | ('password', 'test_reset'), 78 | ('postgres_ci', 'test_sha1') 79 | LOOP 80 | PERFORM assert.add_test(namespace, procedure); 81 | END LOOP; 82 | end$$; -------------------------------------------------------------------------------- /tests/users/test_add.sql: -------------------------------------------------------------------------------- 1 | create or replace function users.test_add() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 7 | 8 | IF assert.not_null(_user_id) THEN 9 | 10 | IF assert.true((SELECT is_superuser FROM postgres_ci.users WHERE user_id = _user_id)) THEN 11 | 12 | PERFORM 13 | assert.equal('login', user_login), 14 | assert.equal('Elephant Sam', user_name), 15 | assert.equal('samelephant82@gmail.com', user_email) 16 | FROM postgres_ci.users WHERE user_id = _user_id; 17 | 18 | PERFORM 19 | assert.equal('email', method), 20 | assert.equal('samelephant82@gmail.com', text_id), 21 | assert.equal(0::bigint, int_id) 22 | FROM postgres_ci.user_notification_method WHERE user_id = _user_id; 23 | 24 | END IF; 25 | 26 | IF assert.not_null(auth.login('login', 'password')) THEN 27 | 28 | PERFORM assert.exception( 29 | $sql$ SELECT users.add('login', 'password', 'Elephant Sam', 'samelephant83@gmail.com', true) $sql$, 30 | exception_table := 'users', 31 | exception_schema := 'postgres_ci', 32 | exception_message := 'LOGIN_ALREADY_EXISTS', 33 | exception_constraint := 'unique_user_login' 34 | ); 35 | 36 | PERFORM assert.exception( 37 | $sql$ SELECT users.add('login2', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true) $sql$, 38 | exception_table := 'users', 39 | exception_schema := 'postgres_ci', 40 | exception_message := 'EMAIL_ALREADY_EXISTS', 41 | exception_constraint := 'unique_user_email' 42 | ); 43 | 44 | PERFORM assert.exception( 45 | $sql$ SELECT users.add('login2', 'password', 'Elephant Sam', 'samelephant82', true) $sql$, 46 | exception_table := 'users', 47 | exception_schema := 'postgres_ci', 48 | exception_message := 'INVALID_EMAIL', 49 | exception_constraint := 'check_user_email' 50 | ); 51 | 52 | END IF; 53 | 54 | END IF; 55 | end; 56 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/users/test_delete.sql: -------------------------------------------------------------------------------- 1 | create or replace function users.test_delete() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', false); 7 | 8 | IF assert.not_null(_user_id) THEN 9 | 10 | PERFORM users.delete(_user_id); 11 | 12 | IF assert.true((SELECT is_deleted FROM postgres_ci.users WHERE user_id = _user_id)) THEN 13 | 14 | PERFORM assert.exception( 15 | $sql$ SELECT auth.login('login', 'password') $sql$, 16 | exception_message := 'NOT_FOUND', 17 | exception_sqlstate := 'P0002' 18 | ); 19 | 20 | END IF; 21 | 22 | END IF; 23 | 24 | PERFORM assert.exception( 25 | $sql$ SELECT users.delete(-1) $sql$, 26 | exception_message := 'NOT_FOUND', 27 | exception_sqlstate := 'P0002' 28 | ); 29 | 30 | _user_id = users.add('login2', 'password2', 'Elephant Sam2', '2samelephant82@gmail.com', true); 31 | 32 | IF assert.not_null(_user_id) THEN 33 | 34 | PERFORM assert.exception( 35 | $sql$ SELECT users.delete($sql$ || _user_id || $sql$) $sql$, 36 | exception_message := 'IS_SUPERUSER', 37 | exception_sqlstate := '23514' 38 | ); 39 | 40 | END IF; 41 | 42 | end; 43 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/users/test_get.sql: -------------------------------------------------------------------------------- 1 | create or replace function users.test_get() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', false); 7 | 8 | IF assert.not_null(_user_id) THEN 9 | 10 | PERFORM 11 | assert.equal('login', user_login), 12 | assert.equal('Elephant Sam', user_name), 13 | assert.equal('samelephant82@gmail.com', user_email), 14 | assert.false(is_superuser) 15 | FROM users.get(_user_id); 16 | 17 | PERFORM users.delete(_user_id); 18 | 19 | PERFORM assert.exception( 20 | $sql$ SELECT users.get($sql$ || _user_id || $sql$) $sql$, 21 | exception_message := 'NOT_FOUND', 22 | exception_sqlstate := 'P0002' 23 | ); 24 | 25 | END IF; 26 | end; 27 | $$ language plpgsql security definer; -------------------------------------------------------------------------------- /tests/users/test_list.sql: -------------------------------------------------------------------------------- 1 | create or replace function users.test_list() returns void as $$ 2 | declare 3 | i int; 4 | q text; 5 | begin 6 | 7 | FOR i IN 1..99 LOOP 8 | PERFORM assert.not_null(users.add('login' || i, 'password' || i, 'Elephant Sam', 'samelephant82@gmail.com' || i, false)); 9 | END LOOP; 10 | 11 | PERFORM assert.not_null(users.add('UserForSearchTest', 'password', 'Search', 'test@gmail.com', false)); 12 | 13 | PERFORM 14 | assert.equal(100, total::int), 15 | assert.equal(15, jsonb_array_length(users)) 16 | FROM users.list(15, 0, ''); 17 | 18 | FOREACH q IN ARRAY ARRAY['Search', 'sear', 'test', 'search mail'] LOOP 19 | PERFORM 20 | assert.equal(1, total::int), 21 | assert.equal(1, jsonb_array_length(users)) 22 | FROM users.list(15, 0, q); 23 | END LOOP; 24 | end; 25 | $$ language plpgsql; -------------------------------------------------------------------------------- /tests/users/test_update.sql: -------------------------------------------------------------------------------- 1 | create or replace function users.test_update() returns void as $$ 2 | declare 3 | _user_id int; 4 | begin 5 | 6 | _user_id = users.add('login', 'password', 'Elephant Sam', 'samelephant82@gmail.com', true); 7 | 8 | IF assert.not_null(_user_id) THEN 9 | 10 | PERFORM users.update( 11 | _user_id, 12 | 'Up_Elephant Sam', 13 | 'Up_samelephant82@gmail.com', 14 | false 15 | ); 16 | 17 | IF assert.false((SELECT is_superuser FROM postgres_ci.users WHERE user_id = _user_id)) THEN 18 | 19 | PERFORM 20 | assert.equal('login', user_login), 21 | assert.equal('Up_Elephant Sam', user_name), 22 | assert.equal('Up_samelephant82@gmail.com', user_email) 23 | FROM postgres_ci.users WHERE user_id = _user_id; 24 | 25 | END IF; 26 | 27 | END IF; 28 | end; 29 | $$ language plpgsql security definer; --------------------------------------------------------------------------------