Created
February 22, 2017 20:15
-
-
Save Zia-/f4b6eb5cb48c537b7ca9301bdcf36410 to your computer and use it in GitHub Desktop.
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
CREATE OR REPLACE FUNCTION pgr_labelGraph( | |
edge_table text, | |
id text default 'id', | |
source text default 'source', | |
target text default 'target', | |
subgraph text default 'subgraph', | |
rows_where text default 'true' | |
) | |
RETURNS character varying AS | |
$BODY$ | |
DECLARE | |
naming record; | |
schema_name text; | |
table_name text; | |
garbage text; | |
incre integer; | |
table_schema_name text; | |
query text; | |
ecnt integer; | |
sql1 text; | |
rec1 record; | |
sql2 text; | |
rec2 record; | |
rec_count record; | |
rec_single record; | |
graph_id integer; | |
gids int []; | |
BEGIN | |
raise notice 'Processing:'; | |
raise notice 'pgr_brokenGraph(''%'',''%'',''%'',''%'',''%'',''%'')', edge_table,id,source,target,subgraph,rows_where; | |
raise notice 'Performing initial checks, please hold on ...'; | |
Raise Notice 'Starting - Checking table ...'; | |
BEGIN | |
raise debug 'Checking % table existance', edge_table; | |
execute 'select * from pgr_getTableName('|| quote_literal(edge_table) ||')' into naming; | |
schema_name = naming.sname; | |
table_name = naming.tname; | |
table_schema_name = schema_name||'.'||table_name; | |
IF schema_name is null then | |
raise notice 'no schema'; | |
return 'FAIL'; | |
else | |
if table_name is null then | |
raise notice 'no table'; | |
return 'FAIL'; | |
end if; | |
end if; | |
END; | |
Raise Notice 'Ending - Checking table'; | |
Raise Notice 'Starting - Checking columns'; | |
BEGIN | |
raise debug 'Checking exitance of necessary columns inside % table', edge_table; | |
execute 'select * from pgr_isColumnInTable('|| quote_literal(table_schema_name) ||', '|| quote_literal(id) ||')' into naming; | |
if naming.pgr_iscolumnintable = 'f' then | |
raise notice 'no id column'; | |
return 'FAIL'; | |
end if; | |
execute 'select * from pgr_isColumnInTable('|| quote_literal(table_schema_name) ||', '|| quote_literal(source) ||')' into naming; | |
if naming.pgr_iscolumnintable = 'f' then | |
raise notice 'no source column'; | |
return 'FAIL'; | |
end if; | |
execute 'select * from pgr_isColumnInTable('|| quote_literal(table_schema_name) ||', '|| quote_literal(target) ||')' into naming; | |
if naming.pgr_iscolumnintable = 'f' then | |
raise notice 'no target column'; | |
return 'FAIL'; | |
end if; | |
execute 'select * from pgr_isColumnInTable('|| quote_literal(table_schema_name) ||', '|| quote_literal(subgraph) ||')' into naming; | |
if naming.pgr_iscolumnintable = 't' then | |
raise notice 'subgraph column already in the table'; | |
return 'FAIL'; | |
end if; | |
END; | |
Raise Notice 'Ending - Checking columns'; | |
Raise Notice 'Starting - Checking rows_where condition'; | |
BEGIN | |
raise debug 'Checking rows_where condition'; | |
query='select count(*) from '|| pgr_quote_ident(table_schema_name) ||' where '|| rows_where; | |
execute query into ecnt; | |
raise debug '-->Rows where condition: OK'; | |
raise debug ' --> OK'; | |
EXCEPTION WHEN OTHERS THEN | |
raise notice 'Got %', SQLERRM; | |
Raise notice 'ERROR: Condition is not correct. Please execute the following query to test your condition'; | |
Raise notice '%', query; | |
return 'FAIL'; | |
END; | |
Raise Notice 'Ending - Checking rows_where condition'; | |
garbage := 'garbage001'; | |
incre := 1; | |
Raise Notice 'Starting - Checking temporary column'; | |
Begin | |
raise debug 'Checking Checking temporary columns existance'; | |
While True | |
Loop | |
execute 'select * from pgr_isColumnInTable('|| quote_literal(table_schema_name) ||', '|| quote_literal(garbage) ||')' into naming; | |
If naming.pgr_iscolumnintable = 't' THEN | |
incre := incre + 1; | |
garbage := 'garbage00'||incre||''; | |
ELSE | |
EXIT; | |
END IF; | |
End Loop; | |
End; | |
Raise Notice 'Ending - Checking temporary column'; | |
Raise Notice 'Starting - Calculating subgraphs'; | |
BEGIN | |
--------- Add necessary columns ---------- | |
EXECUTE 'ALTER TABLE '|| pgr_quote_ident(table_schema_name) ||' ADD COLUMN ' || pgr_quote_ident(subgraph) || ' INTEGER DEFAULT -1'; | |
EXECUTE 'ALTER TABLE '|| pgr_quote_ident(table_schema_name) ||' ADD COLUMN ' || pgr_quote_ident(garbage) || ' INTEGER DEFAULT 0'; | |
graph_id := 1; | |
EXECUTE 'select count(*) as count from '|| pgr_quote_ident(table_schema_name) ||' where '|| rows_where ||'' into rec_count; | |
if rec_count.count = 0 then | |
RETURN 'rows_where condition generated 0 rows'; | |
end if; | |
WHILE TRUE | |
LOOP | |
---------- Assign the very first -1 row graph_id ---------- | |
EXECUTE 'SELECT ' || pgr_quote_ident(id) || ' AS gid FROM '|| pgr_quote_ident(table_schema_name) ||' WHERE '|| rows_where ||' AND ' || pgr_quote_ident(subgraph) || ' = -1 LIMIT 1' INTO rec_single; | |
EXECUTE 'UPDATE '|| pgr_quote_ident(table_schema_name) ||' SET ' || pgr_quote_ident(subgraph) || ' = ' || graph_id || ' WHERE ' || pgr_quote_ident(id) || ' = ' || rec_single.gid || ''; | |
--------- Search other rows with that particular graph_id ----------- | |
WHILE TRUE | |
LOOP | |
EXECUTE 'SELECT COUNT(*) FROM '|| pgr_quote_ident(table_schema_name) ||' WHERE ' || pgr_quote_ident(subgraph) || ' = ' || graph_id || ' AND ' || pgr_quote_ident(garbage) || ' = 0' into rec_count; | |
----------- The following if else will check those rows which already have entertained ------------ | |
IF (rec_count.count > 0) THEN | |
sql1 := 'SELECT ' || pgr_quote_ident(id) || ' AS gid, ' || pgr_quote_ident(source) || ' AS source, ' || pgr_quote_ident(target) || ' AS target FROM '|| pgr_quote_ident(table_schema_name) ||' WHERE ' || pgr_quote_ident(subgraph) || ' = ' || graph_id || ' AND ' || pgr_quote_ident(garbage) || ' = 0'; | |
FOR rec1 IN EXECUTE sql1 | |
LOOP | |
sql2 := 'SELECT ' || pgr_quote_ident(id) || ' AS gid, ' || pgr_quote_ident(source) || ' AS source, ' || pgr_quote_ident(target) || ' AS target FROM '|| pgr_quote_ident(table_schema_name) ||' WHERE '|| pgr_quote_ident(source) ||' = '|| rec1.source ||' OR '|| pgr_quote_ident(target) ||' = '|| rec1.source ||' OR '|| pgr_quote_ident(source) ||' = '|| rec1.target ||' OR '|| pgr_quote_ident(target) ||' = '|| rec1.target ||''; | |
FOR rec2 IN EXECUTE sql2 | |
LOOP | |
EXECUTE 'UPDATE '|| pgr_quote_ident(table_schema_name) ||' SET ' || pgr_quote_ident(subgraph) || ' = ' || graph_id || ' WHERE ' || pgr_quote_ident(id) || ' = ' || rec2.gid || ''; | |
END LOOP; | |
EXECUTE 'UPDATE '|| pgr_quote_ident(table_schema_name) ||' SET ' || pgr_quote_ident(garbage) || ' = 1 WHERE ' || pgr_quote_ident(id) || ' = ' || rec1.gid || ''; | |
END LOOP; | |
ELSE | |
EXIT; | |
END IF; | |
END LOOP; | |
------ Following is to exit the while loop. 0 means no more -1 id. | |
EXECUTE 'SELECT COUNT(*) AS count FROM '|| pgr_quote_ident(table_schema_name) ||' WHERE '|| rows_where ||' AND ' || pgr_quote_ident(subgraph) || ' = -1' INTO rec_count; | |
If (rec_count.count = 0) THEN | |
EXIT; | |
ELSE | |
graph_id := graph_id + 1; | |
END IF; | |
END LOOP; | |
----------- Drop garbage column ------------ | |
EXECUTE 'ALTER TABLE '|| pgr_quote_ident(table_schema_name) ||' DROP COLUMN ' || pgr_quote_ident(garbage) ||''; | |
Raise Notice 'Successfully complicated calculating subgraphs'; | |
END; | |
Raise Notice 'Ending - Calculating subgraphs'; | |
RETURN 'OK'; | |
END; | |
$BODY$ | |
LANGUAGE plpgsql VOLATILE STRICT; | |
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- The following should be OK | |
select pgr_labelGraph('ways'); | |
select pgr_labelGraph('Ways'); | |
select pgr_labelGraph('ways', 'id'); | |
select pgr_labelGraph('ways', 'id', 'source'); | |
select pgr_labelGraph('ways', 'id', 'source', 'target'); | |
select pgr_labelGraph('ways', 'id', 'source', 'target', 'subgraph'); | |
select pgr_labelGraph('ways', 'id', 'source', 'target', 'subgraph', 'id<100'); | |
-- When table located in another schema e03 | |
select pgr_labelGraph('e03.ways'); | |
select pgr_labelGraph('e03.Ways'); | |
select pgr_labelGraph('e03.ways', 'id'); | |
select pgr_labelGraph('e03.ways', 'id', 'source'); | |
select pgr_labelGraph('e03.ways', 'id', 'source', 'target'); | |
select pgr_labelGraph('e03.ways', 'id', 'source', 'target', 'subgraph'); | |
select pgr_labelGraph('e03.ways', 'id', 'source', 'target', 'subgraph', 'id<100'); | |
-- When using the named notation | |
select pgr_labelGraph('e03.calles', target:='destino', subgraph:='subgraph', id:='gido', source:='salida'); | |
select pgr_labelGraph('e03.calles', rows_where:='gido<100', id:='gido', source:='salida', target:='destino', subgraph:='subgraph'); | |
-- The following should FAIL | |
select pgr_labelGraph('id', 'ways'); | |
select pgr_labelGraph('ways', 'id', 'sourc', 'target'); | |
select pgr_labelGraph('ways', 'id', 'source', 'Target'); | |
select pgr_labelGraph('ways', 'id', 'source', 'target', 'subgraph', 'id<'); | |
-- When table located in another schema e03 | |
select pgr_labelGraph('e03.calles'); | |
select pgr_labelGraph('e03.Calles'); | |
select pgr_labelGraph('id', 'e03.calles'); | |
select pgr_labelGraph('e03.calles', 'id', 'sourc', 'target'); | |
select pgr_labelGraph('e03.calles', 'gido', 'source', 'target', 'subgraph', 'id<'); | |
select pgr_labelGraph('e03.calles', 'gid', 'salida', 'target', 'subgraph', 'id<10'); | |
select pgr_labelGraph('e03.calles', 'gid', 'salida', 'destino', 'subgraph', 'id<10 AND id>100'); | |
-- When using the named notation | |
select pgr_labelGraph('e03.calles', target:='destino', subgraph:='subgraph', id:='gido'); | |
select pgr_labelGraph('e03.calles', target:='destino', subgraph:='subgraph', id:='gido', source:='salido'); | |
select pgr_labelGraph(rows_where:='gido<100', id:='gido', source:='salida', 'e03.calles', target:='destino', subgraph:='subgraph'); | |
-- The following should return "rows_where condition generated 0 rows" | |
select pgr_labelGraph('ways', 'id', 'source', 'target', 'subgraph', 'id<10 AND id>100'); | |
select pgr_labelGraph('e03.calles', id:='gido', rows_where:='gido<100 AND gido>200', source:='salida', target:='destino', subgraph:='subgraph'); |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment