new: create tables & add campaigns, runs, ps_boards, single run results

- currently, test automatically opens sqlitebrowser
- ext package is not well checked
This commit is contained in:
Wataru Otsubo 2024-09-12 20:26:38 +09:00 committed by qwjyh
commit eba8d8f395
10 changed files with 1203 additions and 0 deletions

15
src/PSBoardDataBase.jl Normal file
View file

@ -0,0 +1,15 @@
module PSBoardDataBase
using SQLite
using DBInterface
using Tables
using DataFrames
using Dates
include("create_table.jl")
include("import_data.jl")
greet() = print("Hello World!")
end # module PSBoardDataBase

22
src/create_table.jl Normal file
View file

@ -0,0 +1,22 @@
"""
create_database(dbpath::AbstractString)
Create new database at `dbpath` and prepare all tables.
"""
function create_database(dbpath::AbstractString)
db::SQLite.DB = DBInterface.connect(SQLite.DB, dbpath)
create_database(db)
end
function create_database(db::SQLite.DB)
dirpath = @__DIR__
sql_creates::String = read("$dirpath/sql/create_table.sql", String) |> chomp
delim = "CREATE "
for sql_create in eachsplit(sql_creates, delim, keepempty = false)
stmt = DBInterface.prepare(db, delim * sql_create)
DBInterface.execute(stmt)
end
db
end

278
src/import_data.jl Normal file
View file

@ -0,0 +1,278 @@
function insert_qaqc_campaign_id(db::SQLite.DB)
campaigns = [1, 2, 3]
stmt = DBInterface.prepare(db, sql"INSERT INTO qaqc_campaigns VALUES (:id, :note)")
DBInterface.executemany(stmt, (id = campaigns, note = fill(nothing, size(campaigns))))
nothing
end
function insert_qaqc_positions(db::SQLite.DB)
stmt = DBInterface.prepare(
db,
sql"""
INSERT INTO qaqc_positions
VALUES(
:id,
:name,
:station,
:position
)
""",
)
DBInterface.executemany(
stmt,
(
id = 1:18,
name = ["B-$i-$j" for i in 0:1 for j in 1:9],
station = [fill(0, 9); fill(1, 9)],
position = [collect(1:9); collect(1:9)],
),
)
nothing
end
"""
Common preprocess(format) function for single result table.
"""
function prepare_single_result_df(single_result_table::DataFrame)
df = copy(single_result_table, copycols = true)
# timestamp format: 2024-08-07T06:18:09Z
# ignore the last 'Z' => [1:end-1]
transform!(
df,
:timestamp =>
ByRow(s -> ismissing(s) ? missing : DateTime(s[1:(end - 1)])) => :timestamp,
)
return df
end
"""
Common preprocess(format) function for runlist table.
"""
function prepare_runlist_df(runlist_table::DataFrame)
df = copy(runlist_table, copycols = true)
end
"""
Add PS Board IDs from single test result table.
"""
function add_psboard_ids(db::SQLite.DB, single_result_table::DataFrame)
df = combine(groupby(single_result_table, :motherboard_id)) do df
if df.daughterboard |> unique |> length |> ==(1)
return (daughterboard = df.daughterboard |> first,)
end
df = sort(df, :timestamp)
dropmissing!(df, :daughterboard)
return (daughterboard = df.daughterboard |> last,)
end
filter!(:motherboard_id => !=(999999), df)
stmt = DBInterface.prepare(
db,
sql"INSERT INTO ps_boards VALUES (:psbid, :daughterboardid)",
)
DBInterface.executemany(
stmt,
(psbid = df.motherboard_id, daughterboardid = df.daughterboard),
)
nothing
end
function add_qaqc_runlist(db::SQLite.DB, runlist_table::DataFrame)
stmt_insert_runid = DBInterface.prepare(
db,
sql"""
INSERT INTO qaqc_runs
VALUES (:runid, :campaign_id, :run_datetime, :note, :shifter, :logfile, :shiftscript_ver)
""",
)
runlist_table = dropmissing(runlist_table, Symbol("Run ID"))
@assert allunique(runlist_table, Symbol("Run ID"))
for row in eachrow(runlist_table)
try
DBInterface.execute(
stmt_insert_runid,
(
runid = row.var"Run ID",
campaign_id = row.var"Campaign ID",
run_datetime = nothing,
note = row.comment,
shifter = row.var"Shifter name",
logfile = nothing,
shiftscript_ver = nothing,
),
)
catch e
@error "error in putting run list" e
@info "row" row
end
end
nothing
end
function add_qaqc_single_result(
db::SQLite.DB,
single_result_table::DataFrame,
runlist_table::DataFrame,
)
position_id_map =
["B-$i-$j" for i in 0:1 for j in 1:9] |> enumerate .|> (x -> begin
(i, s) = x
s => i
end) |> Dict
stmt_search_runid = DBInterface.prepare(
db,
sql"""
SELECT id
FROM qaqc_runs
WHERE id = :runid
""",
)
stmt_insert_runid = DBInterface.prepare(
db,
sql"""
INSERT INTO qaqc_runs
VALUES (:runid, :campaign_id, :run_datetime, :note, :shifter, :logfile, :shiftscript_ver)
""",
)
stmt_update_runid = DBInterface.prepare(
db,
sql"""
UPDATE qaqc_runs
SET run_datetime = :run_datetime, shifter = :shifter, logfile = :logfile, shiftscript_ver = :shiftscript_ver
WHERE id = :runid
""",
)
stmt_insert_result = DBInterface.prepare(
db,
sql"""
INSERT INTO
qaqc_single_run_results(
runid,
psboard_id,
daughterboard_id,
position,
resistance_test_passed,
qspip,
recov,
power,
clock,
asdtp,
reset,
qaqc_result
)
VALUES (
:runid,
:psboard_id,
:daughterboard_id,
:position,
:resistance_test_passed,
:qspip,
:recov,
:power,
:clock,
:asdtp,
:reset,
:qaqc_result
)
""",
)
for row in eachrow(single_result_table)
if ismissing(row.runid)
@assert contains("resistance")(row.comment) || contains("CN15")(row.comment) "Unexpected row with id $(row.motherboard_id) $(row.comment)"
# DBInterface.execute(
# stmt_insert_result,
# (
# runid = row.runid,
# psboard_id = row.motherboard_id,
# daughterboard_id = row.daughterboard,
# position = nothing,
# resistance_test_passed = false,
# qspip = nothing,
# recov = nothing,
# power = nothing,
# clock = nothing,
# asdtp = nothing,
# reset = nothing,
# qaqc_result = nothing,
# ),
# )
# TODO: maybe these should not be in this table...
continue
end
# Add run if it's not in `qaqc_runs` table
# or update info on the run (such as datetime)
if DBInterface.execute(stmt_search_runid, (; runid = row.runid)) |> isempty
campaign_id = if row.runid < 63
1
elseif row.runid < 98
2
else
3
end
comment = let
row_run = filter(
Symbol("Run ID") => x -> !ismissing(x) && x == row.runid,
runlist_table,
)
if !isempty(row_run)
row_run.comment
else
""
end
end
DBInterface.execute(
stmt_insert_runid,
(
runid = row.runid,
campaign_id = campaign_id,
run_datetime = row.timestamp,
note = comment,
shifter = row.shifter,
logfile = row.qaqc_log_file,
shiftscript_ver = row.shiftscript_ver,
),
)
else
DBInterface.execute(
stmt_update_runid,
(
runid = row.runid,
run_datetime = row.timestamp,
shifter = row.shifter,
logfile = row.qaqc_log_file,
shiftscript_ver = row.shiftscript_ver,
),
)
end
DBInterface.execute(
stmt_insert_result,
(
runid = row.runid,
psboard_id = row.motherboard_id,
daughterboard_id = row.daughterboard,
position = position_id_map[row.position],
resistance_test_passed = true,
qspip = row.qspip,
recov = row.recov,
power = row.power,
clock = row.clock,
asdtp = row.asdtp,
reset = row.reset,
qaqc_result = row.qaqc_result,
),
)
end
nothing
end

98
src/sql/create_table.sql Normal file
View file

@ -0,0 +1,98 @@
CREATE TABLE ps_boards (
id INTEGER NOT NULL PRIMARY KEY,
daughterboard_id INTEGER
);
CREATE TABLE qaqc_single_run_results (
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
runid INTEGER NOT NULL,
psboard_id INTEGER NOT NULL,
daughterboard_id INTEGER,
position INTEGER,
resistance_test_passed BOOLEAN NOT NULL,
qspip INTEGER,
recov INTEGER,
power INTEGER,
clock INTEGER,
asdtp INTEGER,
reset INTEGER,
qaqc_result INTEGER,
FOREIGN KEY("runid") REFERENCES "qaqc_runs"("id"),
FOREIGN KEY("psboard_id") REFERENCES "ps_boards"("id"),
FOREIGN KEY("position") REFERENCES "qaqc_positions"("id")
);
CREATE TABLE qaqc_runs (
id INTEGER NOT NULL PRIMARY KEY,
campaign_id INTEGER,
run_datetime DATETIME,
note TEXT,
shifter TEXT NOT NULL,
logfile TEXT,
shiftscript_ver TEXT,
FOREIGN KEY("campaign_id") REFERENCES "qaqc_campaigns"("id")
);
CREATE TABLE qaqc_dispatch (
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
qaqc_campaign_id INTEGER,
psb_id INTEGER,
source_place TEXT NOT NULL,
destination TEXT NOT NULL,
time DATETIME,
FOREIGN KEY("qaqc_campaign_id") REFERENCES "qaqc_campaigns"("id")
);
CREATE TABLE qaqc_campaigns (
id INTEGER NOT NULL PRIMARY KEY,
note TEXT
);
CREATE TABLE qaqc_resistance_check (
id INTEGER NOT NULL PRIMARY KEY,
psb_id INTEGER NOT NULL,
passed BOOLEAN,
FOREIGN KEY("psb_id") REFERENCES "ps_boards"("id")
);
CREATE TABLE qaqc_extra_run_results (
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
runid INTEGER,
psboard_id INTEGER NOT NULL,
position INTEGER,
FOREIGN KEY("runid") REFERENCES "qaqc_runs"("id"),
FOREIGN KEY("psboard_id") REFERENCES "ps_boards"("id"),
FOREIGN KEY("position") REFERENCES "qaqc_positions"("id")
);
CREATE TABLE qaqc_positions (
id INTEGER NOT NULL PRIMARY KEY,
name TEXT NOT NULL UNIQUE,
station INTEGER NOT NULL,
position INTEGER NOT NULL
);
CREATE VIEW qaqc_single_run_table
AS
SELECT
qaqc_single_run_results.psboard_id,
qaqc_single_run_results.daughterboard_id,
qaqc_positions.name,
qaqc_single_run_results.runid,
qaqc_runs.run_datetime,
qaqc_runs.shiftscript_ver,
qaqc_runs.shifter,
qaqc_single_run_results.qspip,
qaqc_single_run_results.recov,
qaqc_single_run_results.power,
qaqc_single_run_results.clock,
qaqc_single_run_results.asdtp,
qaqc_single_run_results.reset,
qaqc_single_run_results.qaqc_result
FROM
qaqc_single_run_results,
qaqc_positions,
qaqc_runs
WHERE
qaqc_positions.id = qaqc_single_run_results.position AND
qaqc_runs.id = qaqc_single_run_results.runid