Files
hamview/sql.go
maze fb898bb058
Some checks failed
Run tests / test (1.25) (push) Has been cancelled
Run tests / test (stable) (push) Has been cancelled
Initial import
2026-02-22 20:27:07 +01:00

237 lines
6.8 KiB
Go

package hamview
const (
sqlCreateRadio = `
CREATE TABLE IF NOT EXISTS radio (
id BIGSERIAL PRIMARY KEY,
name VARCHAR(64) NOT NULL UNIQUE,
is_online BOOLEAN NOT NULL DEFAULT false,
device VARCHAR(100),
manufacturer VARCHAR(100),
firmware_date TIMESTAMPTZ,
firmware_version VARCHAR(32),
antenna VARCHAR(100),
modulation VARCHAR(16) NOT NULL,
protocol VARCHAR(16) NOT NULL,
latitude NUMERIC(10, 8), -- GPS latitude in decimal degrees
longitude NUMERIC(11, 8), -- GPS longitude in decimal degrees
altitude REAL, -- Altitude in meters
frequency DOUBLE PRECISION,
bandwidth DOUBLE PRECISION,
rx_frequency DOUBLE PRECISION,
tx_frequency DOUBLE PRECISION,
power REAL,
gain REAL,
lora_sf SMALLINT,
lora_cr SMALLINT,
extra JSONB
);
`
sqlIndexRadioName = `CREATE INDEX IF NOT EXISTS idx_radio_name ON radio(name);`
sqlIndexRadioProtocol = `CREATE INDEX IF NOT EXISTS idx_radio_protocol ON radio(protocol);`
sqlGeometryRadioPosition = `SELECT AddGeometryColumn('public', 'radio', 'position', 4326, 'POINT', 2);`
)
const (
sqlCreateAPRSStation = `
CREATE TABLE IF NOT EXISTS aprs_station (
id BIGSERIAL PRIMARY KEY,
address VARCHAR(10) NOT NULL UNIQUE,
last_heard TIMESTAMPTZ NOT NULL,
last_path TEXT[],
last_comment TEXT
);
`
sqlCreateAPRSPacket = `
CREATE TABLE IF NOT EXISTS aprs_packet (
id BIGSERIAL PRIMARY KEY,
src_address VARCHAR(10) NOT NULL,
dst_address VARCHAR(10) NOT NULL,
comment TEXT,
payload BYTEA,
raw BYTEA,
received_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
`
)
const (
sqlCreateMeshCorePacket = `
CREATE TABLE IF NOT EXISTS meshcore_packet (
id BIGSERIAL PRIMARY KEY,
snr REAL NOT NULL DEFAULT 0,
rssi SMALLINT NOT NULL DEFAULT 0,
hash BYTEA NOT NULL, -- Used for deduplication
route_type SMALLINT NOT NULL,
payload_type SMALLINT NOT NULL,
path BYTEA,
payload BYTEA,
raw BYTEA,
parsed JSONB,
received_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
`
sqlIndexMeshCorePacketHash = `CREATE INDEX IF NOT EXISTS idx_meshcore_packet_hash ON meshcore_packet(hash);`
sqlIndexMeshCorePacketPayloadType = `CREATE INDEX IF NOT EXISTS idx_meshcore_packet_payload_type ON meshcore_packet(payload_type);`
)
const (
sqlCreateMeshCoreNode = `
CREATE TABLE IF NOT EXISTS meshcore_node (
id BIGSERIAL PRIMARY KEY,
last_advert_id BIGINT NOT NULL REFERENCES meshcore_packet(id) ON DELETE CASCADE,
node_type SMALLINT NOT NULL DEFAULT 0,
public_key BYTEA NOT NULL UNIQUE,
name TEXT,
local_time TIMESTAMPTZ NOT NULL,
first_heard TIMESTAMPTZ NOT NULL DEFAULT NOW(),
last_heard TIMESTAMPTZ NOT NULL DEFAULT NOW(),
last_latitude NUMERIC(10, 8), -- GPS latitude in decimal degrees
last_longitude NUMERIC(11, 8), -- GPS longitude in decimal degrees
last_position GEOMETRY(POINT, 4326)
);
`
sqlIndexMeshCoreNodePublicKey = `CREATE INDEX IF NOT EXISTS idx_meshcore_node_public_key ON meshcore_node(public_key);`
sqlIndexMeshCoreNodeName = `CREATE INDEX IF NOT EXISTS idx_meshcore_node_name ON meshcore_node(name);`
sqlAlterMeshCoreNodePrefix = `ALTER TABLE meshcore_node ADD COLUMN IF NOT EXISTS prefix BYTEA GENERATED ALWAYS AS (substring(public_key, 0, 2)) STORED;`
sqlGeometryMeshCoreNodePosition = `SELECT AddGeometryColumn('public', 'meshcore_node', 'position', 4326, 'POINT', 2);`
sqlAlterMeshCoreNodeLastPosition = `
ALTER TABLE meshcore_node
ADD COLUMN last_position GEOMETRY(Point, 4326)
GENERATED ALWAYS AS (
CASE
WHEN last_latitude IS NOT NULL AND last_longitude IS NOT NULL THEN ST_SetSRID(ST_MakePoint(last_latitude, last_longitude), 4326)
ELSE NULL
END
) STORED;`
)
const (
sqlCreateMeshCoreNodePosition = `
CREATE TABLE IF NOT EXISTS meshcore_node_position (
id BIGSERIAL PRIMARY KEY,
node_id BIGINT NOT NULL REFERENCES meshcore_node(id) ON DELETE CASCADE,
heard_at TIMESTAMPTZ NOT NULL,
latitude NUMERIC(10, 8), -- GPS latitude in decimal degrees
longitude NUMERIC(11, 8) -- GPS longitude in decimal degrees
);
`
sqlGeometryMeshCoreNodePositionPosition = `SELECT AddGeometryColumn('public', 'meshcore_node_position', 'position', 4326, 'POINT', 2);`
sqlIndexMeshCoreNodePositionPosition = `CREATE INDEX IF NOT EXISTS idx_meshcore_node_position_position ON meshcore_node_position USING GIST (position);`
)
const (
sqlSelectMeshCoreNodesLastPosition = `
WITH ranked_positions AS (
SELECT
node_id, latitude, longitude, position,
ROW_NUMBER() OVER (PARTITION BY node_id ORDER BY heard_at DESC) as rn
FROM meshcore_node_position
)
SELECT
r.snr,
r.rssi,
n.name,
n.public_key,
n.prefix,
n.node_type,
n.first_heard,
n.last_heard,
p.latitude,
p.longitude
FROM
meshcore_node n
LEFT JOIN ranked_positions p ON n.id = p.node_id AND p.rn = 1
LEFT JOIN meshcore_packet r ON r.id = n.last_advert_id
WHERE
n.node_type = $1
ORDER BY last_heard DESC LIMIT $2;
`
sqlSelectMeshCorePackets = `
SELECT
snr,
rssi,
hash,
route_type,
payload_type,
path,
received_at,
raw,
parsed
FROM
meshcore_packet
ORDER BY
received_at DESC
LIMIT $1;
`
sqlSelectMeshCorePacketsByHash = `
SELECT
snr,
rssi,
hash,
route_type,
payload_type,
path,
received_at,
raw,
parsed
FROM
meshcore_packet
WHERE
hash = $1
ORDER BY
received_at DESC;
`
sqlSelectMeshCorePacketsByRepeaterWindowed = `
SELECT
to_timestamp(round(EXTRACT(EPOCH FROM received_at) / $1) * $1) as window,
cast(to_hex(get_byte(path, length(path)-2)) as text) AS repeater,
count(id) AS packets
FROM
meshcore_packet
WHERE
length(path) >= 2 AND
received_at >= $2
GROUP BY
round(EXTRACT(EPOCH FROM received_at) / $1),
cast(to_hex(get_byte(path, length(path)-2)) as text);
`
sqlSelectMeshCorePacketPathNodes = `
WITH RECURSIVE
params AS (
$1::BYTEA as path,
$2::NUMERIC(10, 8) as start_latitude,
$3::NUMERIC(11, 8) as start_longitude,
$4::DOUBLE PRECISION as max_range_m
),
path_prefix AS (
SELECT
)
`
)
const (
sqlCreateMeshCoreIdentity = `
CREATE TABLE IF NOT EXISTS meshcore_identity (
id BIGSERIAL PRIMARY KEY,
name VARCHAR(32) NOT NULL UNIQUE,
public_key BYTEA(32) NOT NULL UNIQUE,
private_key BYTEA(64) NOT NULL
);
`
)
const (
sqlCreateMeshCoreGroup = `
CREATE TABLE IF NOT EXISTS meshcore_group (
id BIGSERIAL PRIMARY KEY,
name VARCHAR(32) NOT NULL UNIQUE,
hash SMALLINT NOT NULL,
shared_key VARCHAR(64) NOT NULL,
is_public BOOLEAN NOT NULL DEFAULT FALSE
);
`
)