Merge pull request #137 from fpellet/postgresql

PL/pg SQL: Add unit test framework (PGUnit), with Docker
This commit is contained in:
Emily Bache 2020-01-15 09:03:22 +01:00 committed by GitHub
commit 9a9b4351f2
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
11 changed files with 434 additions and 0 deletions

20
plpgsql/pgunit/Dockerfile Normal file
View File

@ -0,0 +1,20 @@
FROM postgres:12.1
WORKDIR /app
ENV PGHOST=localhost
ENV PGDATABASE=kata
ENV PGPASSWORD=admin
ENV PGUSER=postgres
ENV POSTGRES_PASSWORD=admin
ENV PGDATA /var/lib/postgresql/data_local
RUN mkdir -p "$PGDATA" && chown -R postgres:postgres "$PGDATA" && chmod 777 "$PGDATA"
RUN apt-get update \
&& apt-get install -y --no-install-recommends ca-certificates wget \
&& rm -rf /var/lib/apt/lists/*
ADD ./*.sh /app/
ADD ./*.sql /app/
RUN chmod +x ./*.sh \
&& ./initializeDocker.sh

View File

@ -0,0 +1,59 @@
CREATE OR REPLACE FUNCTION test_assertEquals(message TEXT, expected ANYELEMENT, result ANYELEMENT) RETURNS VOID AS $$
BEGIN
IF expected = result THEN
null;
ELSE
raise exception '%: expect ''%'' instead of ''%''', message, expected, result using errcode = 'triggered_action_exception';
END IF;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_assertEquals(expected ANYELEMENT, result ANYELEMENT) RETURNS VOID AS $$
BEGIN
perform test_assertEquals('assertEquals failure', expected, result);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_assertEqualsArray(expected VARCHAR[], result VARCHAR[]) RETURNS VOID AS $$
DECLARE
line RECORD;
error_message text;
BEGIN
IF expected = result THEN
null;
ELSE
error_message := 'assertEqualsArray failure:';
FOR line IN SELECT expected_item, result_item FROM (SELECT unnest(expected) AS expected_item, unnest(result) AS result_item) x
LOOP
IF line.expected_item = line.result_item THEN
error_message := CONCAT(error_message, E'\n', '= ', line.expected_item);
ELSE
error_message := CONCAT(error_message, E'\n', '- ', line.expected_item);
error_message := CONCAT(error_message, E'\n', '+ ', line.result_item);
END IF;
END LOOP;
raise exception '%', error_message using errcode = 'triggered_action_exception';
END IF;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_assertEquals_golden_master(expected VARCHAR[], result VARCHAR[]) RETURNS VOID as $$
DECLARE
golden TEXT;
line VARCHAR;
BEGIN
perform test_assertEqualsArray(expected, result);
EXCEPTION
WHEN triggered_action_exception THEN
golden := CONCAT(SQLERRM, E'\n\n', E'For update, copy:\n');
golden := CONCAT(golden, E'expected := ARRAY[');
FOREACH line IN ARRAY result
LOOP
golden := CONCAT(golden, E'\n', '''', line, ''',');
END LOOP;
golden := CONCAT(golden, E'\n', '];');
raise exception '%', golden using errcode = 'triggered_action_exception';
END;
$$ LANGUAGE plpgsql;

View File

@ -0,0 +1,95 @@
CREATE OR REPLACE FUNCTION test_case_assertEquals_numeric_should_fail_if_not_equals() RETURNS VOID AS $$
DECLARE
expected_message VARCHAR;
error_message VARCHAR;
is_equals BOOLEAN;
BEGIN
BEGIN
perform test_assertEquals(7, 5);
EXCEPTION
WHEN triggered_action_exception THEN
expected_message := 'assertEquals failure: expect ''7'' instead of ''5''';
error_message := SQLERRM;
perform test_assertTrue(format('Expect message ''%s'' instead of ''%s'' ', expected_message, error_message), error_message = expected_message);
END;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_case_assertEquals_numeric_should_success_if_equals() RETURNS VOID AS $$
BEGIN
perform test_assertEquals(7, 7);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_case_assertEquals_text_should_fail_if_not_equals() RETURNS VOID AS $$
DECLARE
expected_message VARCHAR;
error_message VARCHAR;
is_equals BOOLEAN;
BEGIN
BEGIN
perform test_assertEquals('hello'::VARCHAR, 'olleh');
EXCEPTION
WHEN triggered_action_exception THEN
expected_message := 'assertEquals failure: expect ''hello'' instead of ''olleh''';
error_message := SQLERRM;
perform test_assertTrue(format('Expect message ''%s'' instead of ''%s'' ', expected_message, error_message), error_message = expected_message);
END;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_case_assertEquals_text_should_success_if_equals() RETURNS VOID AS $$
BEGIN
perform test_assertEquals('hello'::VARCHAR, 'hello');
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_case_assertEquals_should_display_custom_message_if_defined() RETURNS VOID AS $$
DECLARE
expected_message VARCHAR;
error_message VARCHAR;
is_equals BOOLEAN;
BEGIN
BEGIN
perform test_assertEquals('Test with custom message', 'hello'::VARCHAR, 'olleh');
EXCEPTION
WHEN triggered_action_exception THEN
expected_message := 'Test with custom message: expect ''hello'' instead of ''olleh''';
error_message := SQLERRM;
perform test_assertTrue(format('Expect message ''%s'' instead of ''%s'' ', expected_message, error_message), error_message = expected_message);
END;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_case_assertEqualsArray_should_success_if_equals() RETURNS VOID AS $$
BEGIN
perform test_assertEqualsArray(ARRAY['1','2'], ARRAY['1','2']);
perform test_assertEqualsArray(ARRAY['a','b'], ARRAY['a','b']);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_case_assertEqualsArray_should_display_diff_if_failed() RETURNS VOID AS $$
DECLARE
expected_message VARCHAR;
error_message VARCHAR;
is_equals BOOLEAN;
BEGIN
BEGIN
perform test_assertEqualsArray(ARRAY['1','2','3','4'], ARRAY['1','2','4','4']);
EXCEPTION
WHEN triggered_action_exception THEN
expected_message := CONCAT(
'assertEqualsArray failure:', E'\n',
'= 1', E'\n',
'= 2', E'\n',
'- 3', E'\n',
'+ 4', E'\n',
'= 4'
);
error_message := SQLERRM;
perform test_assertTrue(format('Expect message ''%s'' instead of ''%s'' ', expected_message, error_message), error_message = expected_message);
END;
END;
$$ LANGUAGE plpgsql;
SELECT * FROM test_run_all();

View File

@ -0,0 +1,16 @@
version: '3'
services:
database:
build: .
ports:
- "5432:5432"
volumes:
- .:/app/:z
admin:
image: adminer
links:
- database
ports:
- "8081:8080"

View File

@ -0,0 +1,21 @@
#!/usr/bin/env bash
set -ex
echo "Create database"
psql -d postgres -c 'DROP DATABASE IF EXISTS kata;'
psql -d postgres -c 'CREATE DATABASE kata;'
psql -d kata -c 'CREATE EXTENSION DBLINK;'
echo "Initialize test framework"
wget https://raw.githubusercontent.com/adrianandrei-ca/pgunit/bc69dfc526ec3db55ff72af5d78eab55661502af/PGUnit.sql \
&& psql -d kata -f PGUnit.sql \
&& rm PGUnit.sql
echo "Initialize custom asserts"
psql -d kata -f asserts.sql
echo "Add current code"
psql -d kata -f item.sql
psql -d kata -f new_item.sql
psql -d kata -f update_quality.sql

View File

@ -0,0 +1,26 @@
#!/usr/bin/env bash
wait_database()
{
while :
do
(echo > /dev/tcp/127.0.0.1/5432) >/dev/null 2>&1
result=$?
if [[ $result -eq 0 ]]; then
break
fi
sleep 1
done
return $result
}
nohup docker-entrypoint.sh postgres > /dev/null 2>&1 &
wait_database
set -ex
./initializeDatabase.sh
echo "Stop database"
disown %1

8
plpgsql/pgunit/item.sql Normal file
View File

@ -0,0 +1,8 @@
DROP TABLE IF EXISTS item;
CREATE TABLE item
(
name character varying(100) NOT NULL,
sell_in numeric(6) NOT NULL,
quality numeric(6) NOT NULL
);

View File

@ -0,0 +1,12 @@
DROP PROCEDURE IF EXISTS new_item;
CREATE PROCEDURE new_item(
name item.name%TYPE,
sell_in item.sell_in%TYPE,
quality item.quality%TYPE
)
LANGUAGE plpgsql
AS $$
BEGIN
INSERT INTO item (name, sell_in, quality) VALUES (name, sell_in, quality);
END;
$$;

10
plpgsql/pgunit/readme.md Normal file
View File

@ -0,0 +1,10 @@
## Requirement
Testing on postgres 12
Unit test framework used : pgunit (https://github.com/adrianandrei-ca/pgunit)
## Setup
Run `docker-compose up -d` to start, and `docker-compose exec database bash` to enter in container.
You can run `cat update_quality.sql run_tests.sql | psql -d kata -f -`
## Kata
`update_quality.sql` contains code to refactor, and `run_tests.sql` contains test examples.

View File

@ -0,0 +1,95 @@
CREATE OR REPLACE FUNCTION test_case_update_quality() RETURNS void AS $$
DECLARE
name_result item.name%TYPE;
BEGIN
TRUNCATE TABLE item;
CALL new_item('foo', 0, 0);
CALL update_quality();
SELECT name FROM item INTO name_result;
perform test_assertEquals('name did change', 'fixme', name_result);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION format_day(day INTEGER) RETURNS TEXT[] AS $$
DECLARE
result TEXT[];
item_result RECORD;
BEGIN
result := ARRAY[CONCAT('-------- day ', day, ' --------')];
result := result || 'name, sellIn, quality'::TEXT;
FOR item_result IN (SELECT name, sell_in, quality FROM item ORDER BY name ASC, sell_in ASC, quality ASC)
LOOP
result := result || format('%s, %s, %s', item_result.name, item_result.sell_in, item_result.quality);
END LOOP;
RETURN result;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION test_case_update_quality_golden_master() RETURNS VOID AS $$
DECLARE
sell_in_result item.sell_in%TYPE;
quality_result item.quality%TYPE;
days INTEGER;
result TEXT[];
expected TEXT[];
item_result RECORD;
BEGIN
-- given
TRUNCATE TABLE item;
CALL new_item('+5 Dexterity Vest', 10, 20);
CALL new_item('Aged Brie', 2, 0);
CALL new_item('Elixir of the Mongoose', 5, 7);
CALL new_item('Sulfuras, Hand of Ragnaros', 0, 80);
CALL new_item('Sulfuras, Hand of Ragnaros', -1, 80);
CALL new_item('Backstage passes to a TAFKAL80ETC concert', 15, 20);
CALL new_item('Backstage passes to a TAFKAL80ETC concert', 10, 49);
CALL new_item('Backstage passes to a TAFKAL80ETC concert', 5, 49);
-- this conjured item does not work properly yet ;
CALL new_item('Conjured Mana Cake', 3, 6);
days := 1;
-- when
result := format_day(0);
FOR current_day IN 1 .. days
LOOP
CALL update_quality();
result := result || format_day(current_day);
END LOOP;
-- then
expected := ARRAY[
'-------- day 0 --------',
'name, sellIn, quality',
'+5 Dexterity Vest, 10, 20',
'Aged Brie, 2, 0',
'Backstage passes to a TAFKAL80ETC concert, 5, 49',
'Backstage passes to a TAFKAL80ETC concert, 10, 49',
'Backstage passes to a TAFKAL80ETC concert, 15, 20',
'Conjured Mana Cake, 3, 6',
'Elixir of the Mongoose, 5, 7',
'Sulfuras, Hand of Ragnaros, -1, 80',
'Sulfuras, Hand of Ragnaros, 0, 80',
'-------- day 1 --------',
'name, sellIn, quality',
'+5 Dexterity Vest, 9, 19',
'Aged Brie, 1, 1',
'Backstage passes to a TAFKAL80ETC concert, 4, 50',
'Backstage passes to a TAFKAL80ETC concert, 9, 50',
'Backstage passes to a TAFKAL80ETC concert, 14, 21',
'Conjured Mana Cake, 2, 5',
'Elixir of the Mongoose, 4, 6',
'Sulfuras, Hand of Ragnaros, -1, 80',
'Sulfuras, Hand of Ragnaros, 0, 80'
];
perform test_assertEquals_golden_master(expected, result);
END;
$$ LANGUAGE plpgsql;
SELECT * FROM test_run_all();

View File

@ -0,0 +1,72 @@
CREATE OR REPLACE PROCEDURE update_quality()
LANGUAGE plpgsql
AS $$
DECLARE
c_items CURSOR FOR
SELECT name, sell_in, quality FROM item FOR UPDATE;
l_item RECORD;
l_name item.name%TYPE;
l_sell_in item.sell_in%TYPE;
l_quality item.quality%TYPE;
BEGIN
OPEN c_items;
LOOP
FETCH c_items INTO l_item;
EXIT WHEN NOT FOUND;
l_name := l_item.name;
l_sell_in := l_item.sell_in;
l_quality := l_item.quality;
IF l_name <> 'Aged Brie' AND l_name <> 'Backstage passes to a TAFKAL80ETC concert' THEN
IF l_quality > 0 THEN
IF l_name <> 'Sulfuras, Hand of Ragnaros' THEN
l_quality := l_quality - 1;
END IF;
END IF;
ELSE
IF (l_quality < 50) THEN
l_quality := l_quality + 1;
IF l_name = 'Backstage passes to a TAFKAL80ETC concert' THEN
IF l_sell_in < 11 THEN
IF l_quality < 50 THEN
l_quality := l_quality + 1;
END IF;
END IF;
IF l_sell_in < 6 THEN
IF l_quality < 50 THEN
l_quality := l_quality + 1;
END IF;
END IF;
END IF;
END IF;
END IF;
IF l_name <> 'Sulfuras, Hand of Ragnaros' THEN
l_sell_in := l_sell_in - 1;
END IF;
IF l_sell_in < 0 THEN
IF l_name <> 'Aged Brie' THEN
IF l_name <> 'Backstage passes to a TAFKAL80ETC concert' THEN
IF l_quality > 0 THEN
IF l_name <> 'Sulfuras, Hand of Ragnaros' THEN
l_quality := l_quality - 1;
END IF;
END IF;
ELSE
l_quality := l_quality - l_quality;
END IF;
ELSE
IF l_quality < 50 THEN
l_quality := l_quality + 1;
END IF;
END IF;
END IF;
UPDATE item
SET name = l_name, sell_in = l_sell_in, quality = l_quality WHERE CURRENT OF c_items;
END LOOP;
CLOSE c_items;
END;
$$;