stations.db updates
authorDan White <dan@whiteaudio.com>
Fri, 30 Dec 2022 19:49:56 +0000 (13:49 -0600)
committerDan White <dan@whiteaudio.com>
Fri, 30 Dec 2022 19:49:56 +0000 (13:49 -0600)
do-updates.sh
observations_analysis.sqbpro
stations-audit.sh [new file with mode: 0755]
stations-schema.sql [new file with mode: 0644]
stations.sqbpro [new file with mode: 0644]

index fa5582265fe58c092f4fe263d7575d5369cdc00c..7220295f51badffabb2ceade4ae7c5827949183e 100755 (executable)
@@ -15,6 +15,7 @@ echo "*** Fetching database items"
 
 echo "*** Fetching stations info"
 ../python-files/get-stations.py stations.json
+../python-files/update-stations stations.json stations.db
 
 echo
 echo "*** Getting observations"
index 9bfdcdf33f7814596a2978f0347e3093b217f6c8..2f9398f7bcdcb4f1fe9158f87d2353c61965b4e0 100644 (file)
@@ -1,4 +1,4 @@
-<?xml version="1.0" encoding="UTF-8"?><sqlb_project><db path="observations.db" foreign_keys="1" case_sensitive_like="0" temp_store="0" wal_autocheckpoint="1000" synchronous="2"/><attached/><window><current_tab id="3"/></window><tab_structure><column_width id="0" width="300"/><column_width id="1" width="0"/><column_width id="2" width="100"/><column_width id="3" width="6286"/><column_width id="4" width="0"/><expanded_item id="0" parent="1"/><expanded_item id="1" parent="1"/><expanded_item id="2" parent="1"/><expanded_item id="3" parent="1"/></tab_structure><tab_browse><current_table name="observations"/><default_encoding codec=""/><browse_table_settings><table schema="main" name="observations" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table><table schema="main" name="times_index" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table><table schema="main" name="times_index_node" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table><table schema="main" name="times_index_parent" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table><table schema="main" name="times_index_rowid" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table></browse_table_settings></tab_browse><tab_sql><sql name="SQL 6">-- Indexes make the world go 'round ... faster.
+<?xml version="1.0" encoding="UTF-8"?><sqlb_project><db path="observations.db" foreign_keys="1" case_sensitive_like="0" temp_store="0" wal_autocheckpoint="1000" synchronous="2"/><attached/><window><current_tab id="3"/></window><tab_structure><column_width id="0" width="300"/><column_width id="1" width="0"/><column_width id="2" width="100"/><column_width id="3" width="7736"/><column_width id="4" width="0"/><expanded_item id="0" parent="1"/><expanded_item id="1" parent="1"/><expanded_item id="2" parent="1"/><expanded_item id="3" parent="1"/></tab_structure><tab_browse><current_table name="observations"/><default_encoding codec=""/><browse_table_settings><table schema="main" name="observations" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table><table schema="main" name="times_index" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table><table schema="main" name="times_index_node" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table><table schema="main" name="times_index_parent" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table><table schema="main" name="times_index_rowid" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table></browse_table_settings></tab_browse><tab_sql><sql name="SQL 6">-- Indexes make the world go 'round ... faster.
 CREATE INDEX IF NOT EXISTS gs_norad_index
 ON observations(ground_station, norad_cat_id);
 
@@ -85,13 +85,18 @@ FROM observations
 GROUP BY ground_station, observer
 ORDER BY ground_station, count(id) DESC, observer;
 </sql><sql name="SQL 1">-- How many different observers have scheduled on each GS?
+--explain query plan
 SELECT
        ground_station,
        count(distinct observer) as num_observers,
-       count(id) AS num_obs
-FROM observations
+       count(o.id) AS num_obs
+FROM observations as o, times_index as i
+WHERE o.id = i.id
+       AND i.start &gt;= strftime(&quot;%s&quot;, &quot;2018-01-01&quot;)
+       AND i.start &lt; strftime(&quot;%s&quot;, &quot;2019-01-01&quot;)
 GROUP BY ground_station
-ORDER BY ground_station;
+ORDER BY num_obs DESC
+;
 </sql><sql name="SQL 9">-- How many different GS have observers scheduled on?
 SELECT
        observer,
@@ -99,5 +104,5 @@ SELECT
        count(id) AS num_obs
 FROM observations
 GROUP BY observer
-ORDER BY num_gs DESC;
-</sql><current_tab id="5"/></tab_sql></sqlb_project>
+ORDER BY num_obs DESC;
+</sql><sql name="SQL 11"></sql><current_tab id="7"/></tab_sql></sqlb_project>
diff --git a/stations-audit.sh b/stations-audit.sh
new file mode 100755 (executable)
index 0000000..2cedad8
--- /dev/null
@@ -0,0 +1,36 @@
+#!/bin/bash
+
+#for id in $(sqlite3 stations.db "SELECT id FROM stations WHERE rotator='';"); do
+for id in $(awk -F, 'NR>1 {print $1}' < gs-observer-obs.csv); do
+    foo=$(sqlite3 stations.db "SELECT id FROM stations WHERE id=$id AND rotator NOT IN (0, 1, 2);")
+    if [[ "$foo" == "" ]]; then
+        continue
+    fi
+    echo
+    echo $id
+    json=$(sqlite3 stations.db "SELECT antenna FROM stations WHERE id=$id;")
+    desc=$(sqlite3 stations.db "SELECT description FROM stations WHERE id=$id;")
+    seen=$(sqlite3 stations.db "SELECT last_seen FROM stations WHERE id=$id;")
+    status=$(sqlite3 stations.db "SELECT status FROM stations WHERE id=$id;")
+    echo $json | jq
+    echo $desc | fmt -70
+
+    orig=$(sqlite3 stations.db "SELECT rotator FROM stations WHERE id=$id;")
+    echo $orig
+    echo $seen
+    echo $status
+    read -e -p 'N axes: ' -i "$orig" axes
+
+    case $axes in
+        0 | 1 | 2)
+            sql="UPDATE stations SET rotator=$axes WHERE id=$id;"
+            ;;
+        q)
+            break
+            ;;
+        *)
+            continue
+            ;;
+    esac
+    sqlite3 stations.db "$sql"
+done
diff --git a/stations-schema.sql b/stations-schema.sql
new file mode 100644 (file)
index 0000000..f369ec8
--- /dev/null
@@ -0,0 +1,26 @@
+
+
+CREATE TABLE IF NOT EXISTS stations (
+    id INT PRIMARY KEY,
+    altitude REAL,
+    antenna TEXT CHECK(json_valid(antenna)),  -- array of objects
+    client_version TEXT,
+    created TEXT,       --  YYYY-mm-ddTHH:MMZ
+    description TEXT,
+    last_seen TEXT,     --  YYYY-mm-ddTHH:MMZ
+    lat REAL,
+    lng REAL,
+    min_horizon REAL,
+    name TEXT,
+    observations INT,
+    qthlocator TEXT,
+    status TEXT,
+    target_utilization INT,
+    rotator INT         -- 0, 1, or 2 axis rotation
+    );
+
+-- Then use JQ to make a CSV to fill the table.
+-- https://stackoverflow.com/a/46407771
+-- .mode csv
+-- .import stations.csv stations
+
diff --git a/stations.sqbpro b/stations.sqbpro
new file mode 100644 (file)
index 0000000..2fb8d38
--- /dev/null
@@ -0,0 +1,218 @@
+<?xml version="1.0" encoding="UTF-8"?><sqlb_project><db path="/home/dan/ed/satnogs/scheduling-bazaar/data/stations.db" foreign_keys="1" case_sensitive_like="0" temp_store="0" wal_autocheckpoint="1000" synchronous="2"/><attached/><window><current_tab id="1"/></window><tab_structure><column_width id="0" width="300"/><column_width id="1" width="0"/><column_width id="2" width="100"/><column_width id="3" width="2936"/><column_width id="4" width="0"/><expanded_item id="0" parent="1"/><expanded_item id="1" parent="1"/><expanded_item id="2" parent="1"/><expanded_item id="3" parent="1"/></tab_structure><tab_browse><current_table name="stations"/><default_encoding codec=""/><browse_table_settings><table schema="main" name="stations" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table><table schema="main" name="text" show_row_id="0" encoding="" plot_x_axis="" unlock_view_pk=""><sort/><column_widths/><filter_values/><display_formats/><hidden_columns/><plot_y_axes/></table></browse_table_settings></tab_browse><tab_sql><sql name="stations-schema.sql">CREATE TABLE IF NOT EXISTS stations (
+    id PRIMARY KEY,
+    altitude REAL,
+    antenna TEXT CHECK(json_valid(antenna)),  -- array of objects
+    client_version TEXT,
+    created TEXT,       --  YYYY-mm-ddTHH:MMZ
+    description TEXT,
+    last_seen TEXT,     --  YYYY-mm-ddTHH:MMZ
+    lat REAL,
+    lng REAL,
+    min_horizon REAL,
+    name TEXT,
+    observations INT,
+    qthlocator TEXT,
+    status TEXT,
+    target_utilization INT,
+    rotator INT         -- 0, 1, or 2 axis rotation
+    );
+
+-- Then, add rows from the stations.json.  This was done via CSV import, but it should
+-- be configured to directly ingest from the JSON in order to keep the DB up to date.
+</sql><sql name="SQL 2">-- Translate antenna_type into a presumed number of motion axes
+
+-- turnstile
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;turnstile&quot;;
+
+-- yagi
+UPDATE stations SET rotator = 2
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;yagi&quot;;
+
+-- quadrafilar
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;quadrafilar&quot;;
+
+-- vertical
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;vertical&quot;;
+
+-- cross-yagi
+UPDATE stations SET rotator = 2
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;cross-yagi&quot;;
+
+-- dipole
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;dipole&quot;;
+
+-- v-dipole
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;v-dipole&quot;;
+
+-- discone
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;discone&quot;;
+
+-- eggbeater
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;eggbeater&quot;;
+
+-- other omni
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;other omni&quot;;
+
+-- helical
+UPDATE stations SET rotator = 2
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;helical&quot;;
+
+-- ground
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;ground&quot;;
+
+-- lindenblad
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;lindenblad&quot;;
+
+-- other direct
+UPDATE stations SET rotator = 2
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;other direct&quot;;
+
+-- parabolic
+UPDATE stations SET rotator = 2
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;parabolic&quot;;
+
+-- patch
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;patch&quot;;
+
+-- paralindy
+UPDATE stations SET rotator = 0
+WHERE json_extract(antenna, &quot;$[0].antenna_type&quot;) = &quot;paralindy&quot;;
+</sql><sql name="SQL 7">-- Setup for searching name, description fields for various text.
+-- This is to find stations with different rotators than what may
+-- be implied by their declared antenna_type(s)
+CREATE VIRTUAL TABLE IF NOT EXISTS text 
+USING FTS5(id, name, description);
+
+INSERT OR REPLACE INTO text
+SELECT id, name, description from stations;
+</sql><sql name="SQL 8">-- Modify the rotator column to better reflect what the description claims
+SELECT DISTINCT
+       text.id,
+       text.name,
+       text.description,
+       stations.antenna,
+       stations.rotator
+FROM text, stations
+WHERE text.id = stations.id
+AND stations.rotator = 2
+AND text MATCH 'fixed'
+ORDER BY text.id;
+
+-- ok, look at the results above and decide which stations have only 0 or 1 axes or motion
+
+UPDATE stations
+SET rotator = 0
+WHERE id IN (66, 212, 1351, 1787, 1810, 1868, 1950, 2080, 2107, 2246, 2263,     
+             2372, 2430, 2501, 2650);
+
+                        
+-- Find another pattern that implies a rotator                  
+SELECT DISTINCT
+       text.id,
+       text.name,
+       text.description,
+       stations.antenna,
+       stations.rotator
+FROM text, stations
+WHERE text.id = stations.id
+AND text MATCH '5500'
+AND rotator &lt;&gt; 2
+ORDER BY text.id;
+
+-- There were a couple
+UPDATE stations SET rotator = 2 WHERE id IN (888, 2233);
+
+                        
+-- Third search
+SELECT DISTINCT
+       text.id,
+       text.name,
+       text.description,
+       stations.antenna,
+       stations.rotator
+FROM text, stations
+WHERE text.id = stations.id
+AND text MATCH 'spid'
+AND rotator &lt;&gt; 2
+ORDER BY text.id;
+
+-- Found another rotator
+UPDATE stations SET rotator = 2 WHERE id IN (2500);
+
+                        
+-- Fourth search
+SELECT DISTINCT
+       text.id,
+       text.name,
+       text.description,
+       stations.antenna,
+       stations.rotator
+FROM text, stations
+WHERE text.id = stations.id
+AND text MATCH 'azimuth'
+AND rotator &lt;&gt; 5
+ORDER BY text.id;
+
+-- Found more rotators
+UPDATE stations SET rotator = 2 WHERE id IN (357, 1146, 2221);
+
+-- And an azimuth-only station!
+UPDATE stations SET rotator = 1 WHERE id IN (1775);
+
+
+-- Fifth search
+SELECT DISTINCT
+       text.id,
+       text.name,
+       text.description,
+       stations.antenna,
+       stations.rotator
+FROM text, stations
+WHERE text.id = stations.id
+AND text MATCH 'elevation'
+AND rotator &lt;&gt; 5
+ORDER BY text.id;
+
+-- More no-rotator stations
+UPDATE stations SET rotator = 0 WHERE id IN (146, 484, 1640, 1710, 1789, 2029);
+
+-- Now would be a good time to find the stations with directional antennas but no rotator
+</sql><sql name="SQL 5">-- What is remaining?
+SELECT
+       json_extract(antenna, &quot;$[0].antenna_type&quot;) as type,
+       count(antenna) as num_type
+FROM stations
+--WHERE rotator NOT IN (0, 1, 2)
+GROUP BY type
+ORDER BY num_type DESC;</sql><sql name="SQL 4">SELECT
+       json_extract(antenna, &quot;$[0].antenna_type&quot;) as type,
+       count(antenna) as num_type
+FROM stations
+GROUP BY type
+ORDER BY num_type DESC;</sql><sql name="SQL 9">-- Number of stations by motion axes
+SELECT
+       rotator,
+       count(rotator) as num
+FROM stations
+GROUP BY rotator
+ORDER BY rotator;</sql><sql name="SQL 6">-- How many GS were created 
+SELECT
+       2022 as year,
+       status,
+       count(id) as num_new
+FROM stations
+WHERE strftime(&quot;%s&quot;, created) &lt; strftime(&quot;%s&quot;, printf(&quot;%d-01-01&quot;, year+1))
+       AND strftime(&quot;%s&quot;, created) &gt;= strftime(&quot;%s&quot;, printf(&quot;%d-01-01&quot;, year))
+GROUP BY status
+;</sql><current_tab id="4"/></tab_sql></sqlb_project>