Skip to content

Commit

Permalink
Fix #691: Tracking code generation does not follow rules
Browse files Browse the repository at this point in the history
  • Loading branch information
kumy committed Nov 27, 2021
1 parent 6912a12 commit c0c935e
Show file tree
Hide file tree
Showing 3 changed files with 237 additions and 3 deletions.
175 changes: 175 additions & 0 deletions website/db/migrations/20211125204119_tracking_code_validate.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,175 @@
<?php

declare(strict_types=1);

use Phinx\Migration\AbstractMigration;

final class TrackingCodeValidate extends AbstractMigration {
public function up(): void {
$sql = <<<'EOL'
CREATE OR REPLACE FUNCTION geokrety.invalid_starting_tracking_code()
RETURNS character varying[]
LANGUAGE 'sql'
VOLATILE
PARALLEL UNSAFE
COST 100
AS $BODY$
SELECT '{"GK", "GC", "OP", "OK", "GE", "OZ", "OU", "ON", "OL", "OJ", "OS", "GD", "GA", "VI", "MS", "TR", "EX", "GR", "RH", "OX", "OB", "OR", "LT", "LV"}'::character varying[]
$BODY$;
EOL;
$this->execute($sql);

$sql = <<<'EOL'
CREATE OR REPLACE FUNCTION geokrety.is_tracking_code_valid(IN tracking_code character varying)
RETURNS boolean
LANGUAGE 'plpgsql'
VOLATILE
PARALLEL UNSAFE
COST 100
AS $BODY$
BEGIN
IF LENGTH(tracking_code) < 6 THEN
RETURN FALSE;
ELSIF UPPER(SUBSTRING(tracking_code, 1, 2)) = ANY (invalid_starting_tracking_code()) THEN
RETURN FALSE;
END IF;
RETURN TRUE;
END;
$BODY$;
EOL;
$this->execute($sql);

$sql = <<<'EOL'
CREATE OR REPLACE FUNCTION geokrety.generate_tracking_code(IN size integer DEFAULT 6)
RETURNS character varying
LANGUAGE 'plpgsql'
VOLATILE
PARALLEL UNSAFE
COST 100
AS $BODY$
DECLARE
tracking_code character varying := '';
BEGIN
WHILE NOT(is_tracking_code_valid(tracking_code)) LOOP
SELECT array_to_string(array(select substr('ABCDEFGHJKMNPQRSTUVWXYZ23456789',((random()*(31-1)+1)::integer),1) from generate_series(1,size)),'')
INTO tracking_code;
END LOOP;
RETURN tracking_code;
END;
$BODY$;
EOL;
$this->execute($sql);

// ## This is not possible to apply because of actual values in DB
// $sql = <<<'EOL'
//ALTER TABLE IF EXISTS geokrety.gk_geokrety
// ADD CONSTRAINT tracking_code CHECK (is_tracking_code_valid(tracking_code))
// NOT VALID;
//EOL;
// $this->execute($sql);

$sql = <<<'EOL'
CREATE OR REPLACE FUNCTION geokrety.geokret_tracking_code()
RETURNS trigger
LANGUAGE 'plpgsql'
VOLATILE
COST 100
AS $BODY$
BEGIN
IF NEW.tracking_code IS NOT NULL THEN
NEW.tracking_code = UPPER(NEW.tracking_code);
IF is_tracking_code_valid(NEW.tracking_code) THEN
RETURN NEW;
END IF;
RAISE 'Tracking code is invalid';
END IF;
NEW.tracking_code = generate_tracking_code();
RETURN NEW;
END;
$BODY$;
EOL;
$this->execute($sql);
}

public function down(): void {
// ## This is not possible to apply because of actual values in DB
// $sql = <<<'EOL'
//ALTER TABLE IF EXISTS geokrety.gk_geokrety
// DROP CONSTRAINT tracking_code;
//EOL;
// $this->execute($sql);

$sql = <<<'EOL'
CREATE OR REPLACE FUNCTION geokrety.generate_tracking_code(IN size integer DEFAULT 6)
RETURNS character varying
LANGUAGE 'plpgsql'
VOLATILE
PARALLEL UNSAFE
COST 100
AS $BODY$
<<mylabel>>
DECLARE
tracking_code character varying := '';
BEGIN
WHILE NOT(is_tracking_code_valid(tracking_code)) OR (SELECT COUNT(*) > 0 FROM gk_geokrety AS gkg WHERE gkg.tracking_code = mylabel.tracking_code) LOOP
SELECT array_to_string(array(select substr('ABCDEFGHJKMNPQRSTUVWXYZ23456789',((random()*(31-1)+1)::integer),1) from generate_series(1,size)),'')
INTO tracking_code;
END LOOP;
RETURN tracking_code;
END;
$BODY$;
EOL;
$this->execute($sql);

$sql = <<<'EOL'
DROP FUNCTION is_tracking_code_valid;
EOL;
$this->execute($sql);

$sql = <<<'EOL'
DROP FUNCTION invalid_starting_tracking_code;
EOL;
$this->execute($sql);

$sql = <<<'EOL'
CREATE OR REPLACE FUNCTION geokrety.geokret_tracking_code()
RETURNS trigger
LANGUAGE 'plpgsql'
VOLATILE
COST 100
AS $BODY$
DECLARE
found_tc bool;
BEGIN
IF (NEW.tracking_code IS NOT NULL AND LENGTH(NEW.tracking_code) >= 6) THEN
NEW.tracking_code = UPPER(NEW.tracking_code);
RETURN NEW;
END IF;
LOOP
NEW.tracking_code = generate_tracking_code();
SELECT COUNT(*) = 0 FROM gk_geokrety WHERE tracking_code = NEW.tracking_code INTO found_tc;
EXIT WHEN found_tc;
END LOOP;
RETURN NEW;
END;
$BODY$;
EOL;
$this->execute($sql);
}
}
34 changes: 33 additions & 1 deletion website/db/tests/test-20-functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,7 +2,7 @@
BEGIN;

-- SELECT * FROM no_plan();
SELECT plan(55);
SELECT plan(86);

-- Run the tests.
SELECT is(valid_move_types(), '{0,1,2,3,4,5}'::smallint[], 'Check valid_move_types()');
Expand Down Expand Up @@ -69,6 +69,38 @@ SELECT is(coords2position(43.68579, 6.87647), '0101000020E610000053B3075A81811B4
SELECT is(position2coords('0101000020E610000053B3075A81811B4040F67AF7C7D74540'), ROW(43.68579::double precision, 6.87647::double precision), 'Check conversion position to coordinates');

SELECT ok(LENGTH(generate_tracking_code()) = 6, 'Secret id size');
SELECT ok(LENGTH(generate_tracking_code(10)) = 10, 'Secret id size');

SELECT is(is_tracking_code_valid('123456'), TRUE);
SELECT is(is_tracking_code_valid('ABCDEF'), TRUE);
SELECT is(is_tracking_code_valid('ABC123'), TRUE);
SELECT is(is_tracking_code_valid(''), FALSE);
SELECT is(is_tracking_code_valid('1'), FALSE);
SELECT is(is_tracking_code_valid('12345'), FALSE);
SELECT is(is_tracking_code_valid('GK'), FALSE);
SELECT is(is_tracking_code_valid('GC'), FALSE);
SELECT is(is_tracking_code_valid('OP'), FALSE);
SELECT is(is_tracking_code_valid('OK'), FALSE);
SELECT is(is_tracking_code_valid('GE'), FALSE);
SELECT is(is_tracking_code_valid('OZ'), FALSE);
SELECT is(is_tracking_code_valid('OU'), FALSE);
SELECT is(is_tracking_code_valid('ON'), FALSE);
SELECT is(is_tracking_code_valid('OL'), FALSE);
SELECT is(is_tracking_code_valid('OJ'), FALSE);
SELECT is(is_tracking_code_valid('OS'), FALSE);
SELECT is(is_tracking_code_valid('GD'), FALSE);
SELECT is(is_tracking_code_valid('GA'), FALSE);
SELECT is(is_tracking_code_valid('VI'), FALSE);
SELECT is(is_tracking_code_valid('MS'), FALSE);
SELECT is(is_tracking_code_valid('TR'), FALSE);
SELECT is(is_tracking_code_valid('EX'), FALSE);
SELECT is(is_tracking_code_valid('GR'), FALSE);
SELECT is(is_tracking_code_valid('RH'), FALSE);
SELECT is(is_tracking_code_valid('OX'), FALSE);
SELECT is(is_tracking_code_valid('OB'), FALSE);
SELECT is(is_tracking_code_valid('OR'), FALSE);
SELECT is(is_tracking_code_valid('LT'), FALSE);
SELECT is(is_tracking_code_valid('LV'), FALSE);

SELECT ok(fresher_than('2020-04-07 00:00:00+00'::timestamp with time zone, 100, 'YEAR') = TRUE, 'Older than 100 years');

Expand Down
31 changes: 29 additions & 2 deletions website/db/tests/test-50-geokret-tracking-code.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,8 +9,8 @@ INSERT INTO "gk_geokrety" ("id", "gkid", "name", "type") VALUES (1, 1, 'test 1',
SELECT is(LENGTH(tracking_code), 6, 'Automatic add tracking_code') FROM gk_geokrety WHERE id = 1::bigint;

-- Manual
INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (2, 2, 'GEOKRETY', 'test 2', 0);
SELECT is(tracking_code, 'GEOKRETY', 'Code can be manually inserted') FROM gk_geokrety WHERE id = 2::bigint;
INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (2, 2, 'AGEOKRETY', 'test 2', 0);
SELECT is(tracking_code, 'AGEOKRETY', 'Code can be manually inserted') FROM gk_geokrety WHERE id = 2::bigint;

UPDATE "gk_geokrety" SET tracking_code='KRETYGEO' WHERE id=2;
SELECT is(tracking_code, 'KRETYGEO', 'Code can be manually updated') FROM gk_geokrety WHERE id = 2::bigint;
Expand All @@ -34,6 +34,33 @@ SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "na
INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (7, 7, 'jioklj', 'test 7', 0);
SELECT is(tracking_code, 'JIOKLJ', 'Tracking code will be saved uppercase') from gk_geokrety WHERE id = 7::bigint;

-- cannot start by GK or other networks prefixes
-- GK, GC, OP, OK, GE, OZ, OU, ON, OL, OJ, OS, GD, GA, VI, MS, TR, EX, GR, RH, OX, OB, OR, LT, LV
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (8, 8, 'GK1234', 'test GK', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (9, 9, 'GC', 'test GC', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (10, 10, 'OP', 'test OP', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (11, 11, 'OK', 'test OK', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (12, 12, 'GE', 'test GE', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (13, 13, 'OZ', 'test OZ', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (14, 14, 'OU', 'test OU', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (15, 15, 'ON', 'test ON', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (16, 16, 'OL', 'test OL', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (17, 17, 'OJ', 'test OJ', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (18, 18, 'OS', 'test OS', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (19, 19, 'GD', 'test GD', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (20, 20, 'GA', 'test GA', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (21, 21, 'VI', 'test VI', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (22, 22, 'MS', 'test MS', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (23, 23, 'TR', 'test TR', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (24, 24, 'EX', 'test EX', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (25, 25, 'GR', 'test GR', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (26, 26, 'RH', 'test RH', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (27, 27, 'OX', 'test OX', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (28, 28, 'OB', 'test OB', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (29, 29, 'OR', 'test OR', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (30, 30, 'LT', 'test LT', 0)$$);
SELECT throws_ok($$INSERT INTO "gk_geokrety" ("id", "gkid", "tracking_code", "name", "type") VALUES (31, 31, 'LV', 'test LV', 0)$$);

-- Finish the tests and clean up.
SELECT * FROM finish();
ROLLBACK;

0 comments on commit c0c935e

Please sign in to comment.