Commit 8f80a573 authored by Sergio Bruni's avatar Sergio Bruni

'm'

parent 9f53eef4
......@@ -1422,3 +1422,120 @@ WHERE x_crd_a <> 0 AND x_crd_a IS NOT NULL
GROUP BY t2.id_station, t2.id_network
```
**Querone che filtra i rinex condivisi e diversi sulla rete a priorità più alta**
```
WITH stations as (SELECT * FROM (VALUES (28), (972)) as t),
rn as (
select b.id_rinex_file, b.id_network from (
select
max(n.priority_rinex) priority_rinex,
r.id_station,
r.reference_date
from rinex_file_network rn
JOIN rinex_file r ON rn.id_rinex_file=r.id
JOIN network n ON n.id=rn.id_network
where r.id_station IN (select * from stations)
GROUP BY r.id_station, r.reference_date
) a
JOIN (
select
n.priority_rinex priority_rinex,
r.id_station,
r.reference_date,
rn.id_rinex_file,
rn.id_network
from rinex_file_network rn
JOIN rinex_file r ON rn.id_rinex_file=r.id
JOIN network n ON n.id=rn.id_network
where r.id_station IN (select * from stations)
) b
ON a.id_station=b.id_station
AND a.reference_date=b.reference_date
AND a.priority_rinex=b.priority_rinex
)
SELECT
w1.network_name,
w1.priority_rinex,
w1.station_id,
CONCAT(marker, monument_num, receiver_num, country_code) AS station,
w1.reference_date AS day,
w1.receiver_type,
w1.receiver_number,
UPPER(w1.receiver_version) AS receiver_version,
w1.antenna_number,
w1.antenna_type,
w1.antenna_dome,
w1.antenna_delta_h,
w1.antenna_delta_e,
w1.antenna_delta_n
FROM
(
SELECT
n.name AS network_name,
n.priority_rinex,
n.id AS network_id,
s.id as station_id,
s.marker,
s.monument_num,
s.receiver_num,
s.country_code,
r.reference_date,
UPPER(r.receiver_type) AS receiver_type,
r.receiver_number,
UPPER(r.receiver_version) AS receiver_version,
r.antenna_number,
r.antenna_type,
r.antenna_delta_h,
r.antenna_delta_e,
r.antenna_delta_n,
r.antenna_dome,
LEAD(n.id) OVER (ORDER BY s.id, reference_date DESC) AS prev_network_id,
LEAD(s.id) OVER (ORDER BY s.id, reference_date DESC) AS prev_station_id,
LEAD(r.receiver_number) OVER (ORDER BY s.id, reference_date DESC) AS prev_receiver_number,
LEAD(upper(r.receiver_type)) OVER (ORDER BY s.id, reference_date DESC) AS prev_receiver_type,
LEAD(upper(r.receiver_version)) OVER (ORDER BY s.id, reference_date DESC) AS prev_receiver_version,
LEAD(r.antenna_number) OVER (ORDER BY s.id, reference_date DESC) AS prev_antenna_number,
LEAD(r.antenna_type) OVER (ORDER BY s.id, reference_date DESC) AS prev_antenna_type,
LEAD(r.antenna_delta_h) OVER (ORDER BY s.id, reference_date DESC) AS prev_antenna_delta_h,
LEAD(r.antenna_delta_e) OVER (ORDER BY s.id, reference_date DESC) AS prev_antenna_delta_e,
LEAD(r.antenna_delta_n) OVER (ORDER BY s.id, reference_date DESC) AS prev_antenna_delta_n,
LEAD(r.antenna_dome) OVER (ORDER BY s.id, reference_date DESC) AS prev_antenna_dome
FROM rinex_file r
JOIN station s ON s.id=r.id_station
JOIN rn ON rn.id_rinex_file=r.id
JOIN network n ON n.id=rn.id_network
WHERE
s.id IN (select * from stations)
--s.id IN (select s.id from station s JOIN station_network sn ON s.id=sn.id_station and sn.id_network=21)
--s.id IN (1184, 2979, 2063, 3099) -- DEBUG
AND r.status = 1
and r.reference_date > '0001-01-01 00:00:00'
and r.reference_date < '9999-12-31 23:59:59.999999'
--n.id IN (39, 40)
--s.id=88
-- and date_part('YEAR', r.reference_date) = 2019
-- and r.reference_date < '9999-01-01'
ORDER BY s.id, reference_date, n.id DESC
) AS W1
WHERE
-- w1.network_id IS DISTINCT FROM w1.prev_network_id
w1.station_id IS DISTINCT FROM w1.prev_station_id
OR w1.receiver_type IS DISTINCT FROM w1.prev_receiver_type
OR w1.receiver_number IS DISTINCT FROM w1.prev_receiver_number
OR w1.receiver_version IS DISTINCT FROM w1.prev_receiver_version
OR w1.antenna_number IS DISTINCT FROM w1.prev_antenna_number
OR w1.antenna_type IS DISTINCT FROM w1.prev_antenna_type
OR w1.antenna_delta_h IS DISTINCT FROM w1.prev_antenna_delta_h
OR w1.antenna_delta_e IS DISTINCT FROM w1.prev_antenna_delta_e
OR w1.antenna_delta_n IS DISTINCT FROM w1.prev_antenna_delta_n
OR w1.antenna_dome IS DISTINCT FROM w1.prev_antenna_dome
ORDER BY
w1.station_id,
w1.reference_date,
w1.network_name
ASC
```
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment