DO $$ DECLARE inicio_vigencia DATE; v_error TEXT := ''; BEGIN -- Verificar agency_id único IF (SELECT COUNT(*) FROM (SELECT agency_id FROM z_agency GROUP BY agency_id HAVING COUNT(*) > 1) AS duplicated) > 0 THEN update gtfs_archivo set status = 'Error - Agency_id duplicados' where trim(upper(status))='PROCESANDO' ; v_error:= '1 La validacion de archivos detecto errores en los archivos GTFS'; END IF; -- Verificar route_id único IF (SELECT COUNT(*) FROM (SELECT route_id FROM z_routes GROUP BY route_id HAVING COUNT(*) > 1) AS duplicated) > 0 THEN update gtfs_archivo set status = 'Error - Route_id duplicados' where trim(upper(status))='PROCESANDO' ; v_error:= '2 La validacion de archivos detecto errores en los archivos GTFS'; END IF; -- Verificar service_id único en calendar IF (SELECT COUNT(*) FROM (SELECT service_id FROM z_calendar GROUP BY service_id HAVING COUNT(*) > 1) AS duplicated) > 0 THEN update gtfs_archivo set status = 'Error - service_id duplicados en calendar' where trim(upper(status))='PROCESANDO' ; v_error:= '3 La validacion de archivos detecto errores en los archivos GTFS'; END IF; -- Verificar trip_id único IF (SELECT COUNT(*) FROM (SELECT trip_id FROM z_trips GROUP BY trip_id HAVING COUNT(*) > 1) AS duplicated) > 0 THEN update gtfs_archivo set status = 'Error - Trip_id duplicados ' where trim(upper(status))='PROCESANDO' ; v_error:= '4 La validacion de archivos detecto errores en los archivos GTFS'; END IF; -- Verificar stop_id único IF (SELECT COUNT(*) FROM (SELECT stop_id FROM z_stops GROUP BY stop_id HAVING COUNT(*) > 1) AS duplicated) > 0 THEN update gtfs_archivo set status = 'Error - Stop_id duplicados' where trim(upper(status))='PROCESANDO' ; v_error:= '5 La validacion de archivos detecto errores en los archivos GTFS'; END IF; -- Verificar referencias cruzadas entre trips y routes IF (SELECT COUNT(*) FROM z_trips WHERE route_id NOT IN (SELECT route_id FROM z_routes)) > 0 THEN update gtfs_archivo set status = 'Error - Trips_id con route_id que no existen' where trim(upper(status))='PROCESANDO' ; v_error:= '6 La validacion de archivos detecto errores en los archivos GTFS'; END IF; -- Verificar referencias cruzadas entre stop_times y trips IF (SELECT COUNT(*) FROM z_stop_times WHERE trip_id NOT IN (SELECT trip_id FROM z_trips)) > 0 THEN update gtfs_archivo set status = 'Error - Stop_times con trips_id que no existen' where trim(upper(status))='PROCESANDO' ; v_error:= '7 La validacion de archivos detecto errores en los archivos GTFS'; END IF; -- Verificar referencias cruzadas entre stop_times y stops IF (SELECT COUNT(*) FROM z_stop_times WHERE stop_id NOT IN (SELECT stop_id FROM z_stops)) > 0 THEN update gtfs_archivo set status = 'Error - stop_time con stop_id que no existen' where trim(upper(status))='PROCESANDO' ; v_error:= '8 La validacion de archivos detecto errores en los archivos GTFS'; END IF; /*WITH inicio_calendar AS ( SELECT MIN(start_date) AS inicio FROM z_calendar ), inicio_calendar_dates AS ( SELECT MIN(date) AS inicio FROM z_calendar_dates WHERE exception_type = 1 ) SELECT LEAST( COALESCE((SELECT inicio FROM inicio_calendar), CURRENT_DATE), COALESCE((SELECT inicio FROM inicio_calendar_dates), CURRENT_DATE) ) INTO inicio_vigencia;*/ SELECT MIN(start_date) INTO inicio_vigencia FROM z_calendar; update gtfs_archivo set valid_from= inicio_vigencia where trim(upper(status))='PROCESANDO' ; IF CURRENT_DATE < inicio_vigencia THEN update gtfs_archivo set status = 'PENDIENTE' where trim(upper(status))='PROCESANDO' ; v_error:= '9 EL ARCHIVO AUN NO ESTA VIGENTE POR FECHA'; END IF; if v_error = '' THEN /* ASEGURA QUE CADA TRIPS TENGA UN SOLO GUION EN SU DESCRIPCION */ UPDATE z_trips SET trip_headsign = CASE WHEN (LENGTH(trip_headsign) - LENGTH(REPLACE(trip_headsign, '-', '')) = 2) THEN regexp_replace(trip_headsign, '^(.*)-(.*)-(.*)$', '\1-\2~\3') ELSE trip_headsign end WHERE trip_headsign LIKE '%-%-%'; -- update z_routes -- set route_long_name = replace (route_long_name,replace( -- (select distinct trip_headsign from z_trips where route_id =z_routes.route_id and trip_headsign like '%~%' ),'~','-' -- ), -- (select distinct trip_headsign from z_trips where route_id =z_routes.route_id and trip_headsign like '%~%' ) -- ) -- WHERE route_long_name LIKE '%-%-%-%-%'; update gtfs_archivo set vigente = False where vigente = true and id_red in (select id_red from gtfs_archivo where trim(upper(status))='PROCESANDO' ); ALTER TABLE linea_paradero drop CONSTRAINT IF EXISTS linea_paradero_id_linea_fkey; ----- ALTER TABLE gtfs_stop_times drop CONSTRAINT IF EXISTS fk_gtfs_sto_reference_gtfs_tri; ----- ALTER TABLE gtfs_frequencie drop CONSTRAINT IF EXISTS fk_gtfs_fre_reference_gtfs_tri; ----- DELETE FROM gtfs_calendar; ----- insert into gtfs_calendar select service_id, monday::bool , tuesday::bool , wednesday::bool , thursday::bool ,friday::bool ,saturday::bool ,sunday::bool from z_calendar zc; ----- update paradero set vigente = true, stop_name= (select stop_name from z_stops where stop_id=paradero.id_paradero::text limit 1 ), stop_desc=(select stop_desc from z_stops where stop_id=paradero.id_paradero::text limit 1 ), stop_lat =(select stop_lat from z_stops where stop_id=paradero.id_paradero::text limit 1)::float(8), stop_lon =(select stop_lon from z_stops where stop_id=paradero.id_paradero::text limit 1)::float(8), stop_code=(select stop_code from z_stops where stop_id=paradero.id_paradero::text limit 1) where id_paradero::text in (select stop_id from z_stops ); ----- insert into paradero select stop_id, null as id_comuna, null as id_tipo_paradero, true, stop_code , stop_name , stop_desc , stop_lat::float(8) , stop_lon::float(8) , zone_id , stop_url , location_type , parent_station ,null as stop_time_zone , wheelchair_boarding::numeric from z_stops zs where stop_id not in (select id_paradero::text from paradero); ----- delete from linea_paradero; ----- CREATE TABLE IF NOT EXISTS z_verifica_route ( route_id text NULL, route_short_name text NULL ); delete from linea l where id_linea in ( select route_id||'-0' from z_verifica_route as v where coalesce((select count(*) from z_routes as r where r.route_id=v.route_id and r.route_short_name = v.route_short_name),0)=0 union select route_id||'-1' from z_verifica_route as v where coalesce((select count(*) from z_routes as r where r.route_id=v.route_id and r.route_short_name = v.route_short_name),0)=0 union select route_id from z_verifica_route as v where coalesce((select count(*) from z_routes as r where r.route_id=v.route_id and r.route_short_name = v.route_short_name),0)=0 ) ; delete from z_verifica_route ; insert into z_verifica_route select route_id, route_short_name from z_routes ; ----- update linea set vigente = false where id_red in (select id_red from gtfs_archivo where trim(upper(status))='PROCESANDO' ) and id_linea not in ( select trim(zr.route_id)||'-'||trim(zt.direction_id::varchar) from z_routes zr inner join z_trips zt on zr.route_id =zt.route_id ); ----- update linea set vigente = true where id_red in (select id_red from gtfs_archivo where trim(upper(status))='PROCESANDO' ) and id_linea in ( select trim(zr.route_id)||'-'||trim(zt.direction_id::varchar) from z_routes zr inner join z_trips zt on zr.route_id =zt.route_id ); ----- insert into linea select distinct trim(zr.route_id)||'-'||trim(zt.direction_id::varchar) as route_id, null,--zr.agency_id , substring(zt.trip_headsign FROM '(\S+) -') as route_short_name , zr.route_desc , zr.route_type::numeric , zr.route_url, zr.route_color , zr.route_text_color , zt.trip_headsign as route_long_name , true , (select id_red from gtfs_archivo where trim(upper(status))='PROCESANDO' limit 1) as id_red from z_routes zr inner join z_trips zt on zr.route_id =zt.route_id and replace (zt.trip_headsign,' ','') =replace ((SPLIT_PART(route_long_name, '-', 1)||'-'||SPLIT_PART(route_long_name, '-', 2)),' ','') where route_long_name not like '%'||route_short_name ||'%' and (trim(zr.route_id)||'-'||trim(zt.direction_id::varchar) ) not in (select id_linea from linea ) union select distinct trim(zr.route_id)||'-'||trim(zt.direction_id::varchar) as route_id, null,--zr.agency_id , substring(zt.trip_headsign FROM '(\S+) -') as route_short_name , zr.route_desc , zr.route_type::numeric , zr.route_url, zr.route_color , zr.route_text_color , zt.trip_headsign as route_long_name , true , (select id_red from gtfs_archivo where trim(upper(status))='PROCESANDO' limit 1) as id_red from z_routes zr inner join z_trips zt on zr.route_id =zt.route_id and replace (zt.trip_headsign,' ','') =replace ((SPLIT_PART(route_long_name, '-', 3)||'-'||SPLIT_PART(route_long_name, '-', 4)),' ','') where route_long_name not like '%'||route_short_name ||'%' and (trim(zr.route_id)||'-'||trim(zt.direction_id::varchar) ) not in (select id_linea from linea ) union select distinct trim(zr.route_id)||'-'||trim(zt.direction_id::varchar) as route_id, null,--zr.agency_id , route_short_name , zr.route_desc , zr.route_type::numeric , zr.route_url, zr.route_color , zr.route_text_color , zt.trip_headsign as route_long_name , true , (select id_red from gtfs_archivo where trim(upper(status))='PROCESANDO' limit 1) as id_red from z_routes zr inner join z_trips zt on zr.route_id =zt.route_id and ( position('-' in zt.trip_headsign) = 0 or route_long_name like '%'||route_short_name ||'%' ) where (trim(zr.route_id)||'-'||trim(zt.direction_id::varchar) ) not in (select id_linea from linea ) order by 1; ----- truncate table gtfs_shape; ----- insert into gtfs_shape select shape_id,shape_pt_lat::float8,shape_pt_lon::float8, shape_pt_sequence::numeric,shape_dist_traveled::float8 from z_shapes zs; ----- truncate table gtfs_stop_times; ----- truncate table gtfs_frequencie; ----- truncate table gtfs_trips; ----- insert into gtfs_trips select trip_id, trim(route_id)||'-'||trim(direction_id::varchar) as route_id, shape_id ,null as regreso, trip_headsign,trip_short_name,direction_id::numeric,service_id::varchar,block_id from z_trips zt; ----- insert into gtfs_stop_times select stop_id,trip_id,arrival_time,stop_sequence::numeric,stop_headsign,departure_time,drop_off_type::numeric,null as shape_dist_traveled , timepoint::numeric , pickup_type::numeric from z_stop_times zst ; ----- insert into linea_paradero (id_linea , id_paradero ) SELECT DISTINCT l.id_linea , p.id_paradero FROM linea l JOIN gtfs_trips t ON l.id_linea =t.id_linea JOIN gtfs_stop_times st ON t.id_trip = st.id_trip JOIN paradero p ON st.id_paradero = p.id_paradero; ----- UPDATE paradero SET stop_name = REGEXP_REPLACE( REGEXP_REPLACE( stop_name, '\yentre\y', '-entre', 'gi' ), '\yesq\y', '-esq', 'gi' ); ----- update paradero set id_comuna = (select id_comuna from comuna_georeferencia as c where ST_Contains(c.geom, ST_SetSRID(ST_MakePoint(paradero.stop_lon, paradero.stop_lat), 4326)) limit 1) where id_comuna is not null; ----- insert into dispositivo select 'QRCode-'||id_paradero , id_paradero , true, null, 3 from paradero as p where id_paradero not in (select id_paradero from dispositivo as d where id_tipo_dispositivo=3 and d.id_paradero = p.id_paradero); ----- ALTER TABLE linea_paradero ADD CONSTRAINT linea_paradero_id_linea_fkey FOREIGN KEY (id_linea) REFERENCES linea(id_linea); ----- ALTER TABLE gtfs_stop_times ADD CONSTRAINT fk_gtfs_sto_reference_gtfs_tri FOREIGN KEY (id_trip) REFERENCES gtfs_trips(id_trip) ON DELETE RESTRICT ON UPDATE RESTRICT; ----- ALTER TABLE gtfs_frequencie ADD CONSTRAINT fk_gtfs_fre_reference_gtfs_tri FOREIGN KEY (id_trip) REFERENCES gtfs_trips(id_trip) ON DELETE RESTRICT ON UPDATE RESTRICT; ----- update paradero p set id_comuna = ( select id_comuna from comuna_georeferencia cg where st_contains(cg.geom, st_setsrid(st_makepoint(p.stop_lon, p.stop_lat) ,4326)) limit 1) where id_comuna is null; CREATE TABLE IF NOT EXISTS gtfs_validaciones ( id_gtfs int4 not null, route_id text NULL, route_long_name text NULL, observacion text NULL ); insert into gtfs_validaciones select (select id_gtfs from gtfs_archivo where trim(upper(status))='PROCESANDO' ), route_id, route_long_name, 'Ruta sin Trips Asociados' from z_routes where route_id not in (select route_id from z_trips ) ; update gtfs_archivo set vigente = true , status = case when ( select count(*) from gtfs_validaciones where id_gtfs =(select id_gtfs from gtfs_archivo where trim(upper(status))='PROCESANDO' ) ) =0 then 'GTFS CARGADO' else 'GTFS CARGADO CON REPAROS' END where trim(upper(status))='PROCESANDO' ; END IF; END$$;