Technology dependencies view
* Added SQL view that lists dependencies of technologies as comma-separated lists of identifiers
This commit is contained in:
parent
f4e38e4943
commit
e01eab9c09
3 changed files with 88 additions and 1 deletions
|
@ -311,4 +311,27 @@ CREATE TRIGGER tg_techdeps_ai
|
|||
|
||||
REVOKE EXECUTE
|
||||
ON FUNCTION defs.tgf_techdeps_ai( )
|
||||
FROM PUBLIC;
|
||||
FROM PUBLIC;
|
||||
|
||||
|
||||
/*
|
||||
* Technology dependencies view
|
||||
* -----------------------------
|
||||
*
|
||||
* This view generates a parseable list of dependencies per technology.
|
||||
*
|
||||
* Columns:
|
||||
* technology_name_id The technology's name
|
||||
* technology_dependencies A list of comma-separated technology name
|
||||
* identifiers
|
||||
*/
|
||||
DROP VIEW IF EXISTS defs.technology_dependencies_view CASCADE;
|
||||
CREATE VIEW defs.technology_dependencies_view
|
||||
AS SELECT technology_name_id ,
|
||||
array_to_string( array_agg( _name_str.name ) , ',' ) AS technology_dependencies
|
||||
FROM defs.technologies _tech
|
||||
LEFT OUTER JOIN defs.technology_dependencies
|
||||
USING ( technology_name_id )
|
||||
LEFT OUTER JOIN defs.strings _name_str
|
||||
ON _name_str.id = technology_name_id_depends
|
||||
GROUP BY technology_name_id;
|
||||
|
|
|
@ -0,0 +1,49 @@
|
|||
/*
|
||||
* Unit tests for defs.technology_dependencies_view
|
||||
*/
|
||||
BEGIN;
|
||||
\i utils/strings.sql
|
||||
-- Make the columns we don't use in the technology definition table NULL-able
|
||||
ALTER TABLE defs.technologies
|
||||
ALTER technology_category_id DROP NOT NULL ,
|
||||
ALTER technology_discovery_id DROP NOT NULL ,
|
||||
ALTER technology_description_id DROP NOT NULL ,
|
||||
ALTER technology_price DROP NOT NULL ,
|
||||
ALTER technology_points DROP NOT NULL;
|
||||
|
||||
-- Create strings to use as the technologies' names
|
||||
SELECT _create_test_strings( 4 , 'tech' );
|
||||
|
||||
-- Insert the technologies
|
||||
INSERT INTO defs.technologies ( technology_name_id )
|
||||
VALUES ( _get_string( 'tech1' ) ) ,
|
||||
( _get_string( 'tech2' ) ) ,
|
||||
( _get_string( 'tech3' ) ) ,
|
||||
( _get_string( 'tech4' ) );
|
||||
|
||||
-- Insert dependencies: tech3 -> {tech1,tech2} , tech4 -> {tech3}
|
||||
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
|
||||
VALUES ( _get_string( 'tech3' ) , _get_string( 'tech1' ) ) ,
|
||||
( _get_string( 'tech3' ) , _get_string( 'tech2' ) ) ,
|
||||
( _get_string( 'tech4' ) , _get_string( 'tech3' ) );
|
||||
|
||||
-- ***** TESTS BEGIN HERE *****
|
||||
SELECT plan( 3 );
|
||||
|
||||
SELECT diag_test_name( 'defs.technology_dependencies_view - Technologies with no dependencies' );
|
||||
SELECT is( technology_dependencies , '' )
|
||||
FROM defs.technology_dependencies_view
|
||||
WHERE technology_name_id = _get_string( 'tech1' );
|
||||
|
||||
SELECT diag_test_name( 'defs.technology_dependencies_view - Technologies with a single dependency' );
|
||||
SELECT is( technology_dependencies , 'tech3' )
|
||||
FROM defs.technology_dependencies_view
|
||||
WHERE technology_name_id = _get_string( 'tech4' );
|
||||
|
||||
SELECT diag_test_name( 'defs.technology_dependencies_view - Technologies with multiple dependencies' );
|
||||
SELECT ok( technology_dependencies = 'tech1,tech2' OR technology_dependencies = 'tech2,tech1' )
|
||||
FROM defs.technology_dependencies_view
|
||||
WHERE technology_name_id = _get_string( 'tech3' );
|
||||
|
||||
SELECT * FROM finish( );
|
||||
ROLLBACK;
|
|
@ -0,0 +1,15 @@
|
|||
/*
|
||||
* Test privileges on defs.technology_dependencies_view
|
||||
*/
|
||||
BEGIN;
|
||||
\i utils/strings.sql
|
||||
|
||||
SELECT plan( 1 );
|
||||
|
||||
SELECT diag_test_name( 'defs.technology_dependencies_view - No SELECT privilege' );
|
||||
SELECT throws_ok( $$
|
||||
SELECT * FROM defs.technology_dependencies_view;
|
||||
$$ , 42501 );
|
||||
|
||||
SELECT * FROM finish( );
|
||||
ROLLBACK;
|
Reference in a new issue