some design, data model, data migration script
This commit is contained in:
15
scripts/datamigation/create_instances.sql
Normal file
15
scripts/datamigation/create_instances.sql
Normal file
@@ -0,0 +1,15 @@
|
||||
-- PostgreSQL treats unquoted identifiers as case-insensitive, converting them to lowercase. If your column's actual name includes uppercase letters or mixed case, you should quote it when referencing it in your SQL query
|
||||
|
||||
create table instances as select
|
||||
id as rowid
|
||||
, host as domain
|
||||
, config->'description' as slogan
|
||||
, config->'longDescription' as description
|
||||
, languages
|
||||
, CASE WHEN config->'registrationsOpen' = 'true' THEN 1 ELSE 0 END as open
|
||||
, config->'version' as version
|
||||
, "connectivityStats"->'country' as location
|
||||
, 0 as failure
|
||||
, CAST(extract(epoch from "createdAt") as integer) as "createdAt"
|
||||
, CAST(extract(epoch from "updatedAt") as integer) as "updatedAt"
|
||||
from instance;
|
24
scripts/datamigation/import_data.sh
Executable file
24
scripts/datamigation/import_data.sh
Executable file
@@ -0,0 +1,24 @@
|
||||
#!/bin/bash -eu
|
||||
|
||||
CMDD=$(dirname $(realpath $0))
|
||||
|
||||
pgdump_file=$1
|
||||
sqlite_db=$2
|
||||
|
||||
export PGPASSWORD=${DB_PASS}
|
||||
PGCONN="-h ${DB_HOST} -p ${DB_PORT} -U ${DB_USER}"
|
||||
PSQL="psql ${PGCONN}"
|
||||
PGDUMP="pg_dump ${PGCONN}"
|
||||
|
||||
$PSQL <<< "drop database if exists ${DB_NAME}"
|
||||
$PSQL <<< "create database ${DB_NAME}"
|
||||
$PSQL -d ${DB_NAME} < $pgdump_file
|
||||
$PSQL -d ${DB_NAME} < ${CMDD}/create_instances.sql
|
||||
|
||||
rm ${sqlite_db}
|
||||
sqlite3 ${sqlite_db} < schema.sql
|
||||
$PGDUMP -d ${DB_NAME} --no-comments --section=data --data-only --column-inserts --no-owner -t instances | awk 'NR>22' | sed -e 's/ public\.instances / instances /' | sqlite3 ${sqlite_db}
|
||||
$PSQL -d ${DB_NAME} --csv < ${CMDD}/query_stats.sql | sqlite3 ${sqlite_db} ".import --skip 1 --csv '|cat -' stats"
|
||||
|
||||
sqlite3 ${sqlite_db} <<< 'select count(*) from instances'
|
||||
sqlite3 ${sqlite_db} <<< 'select count(*) from stats'
|
14
scripts/datamigation/query_stats.sql
Normal file
14
scripts/datamigation/query_stats.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
select
|
||||
CAST(extract(epoch from "createdAt") as integer) as "insertedAt"
|
||||
, "instanceId"
|
||||
, COALESCE((stats->>'numberOfUsers')::integer, -1) as users
|
||||
, COALESCE((stats->>'numberOfLocalGroups')::integer, -1) as local_groups
|
||||
, COALESCE((stats->>'numberOfGroups')::integer, -1) as total_groups
|
||||
, COALESCE((stats->>'numberOfLocalEvents')::integer, -1) as local_events
|
||||
, COALESCE((stats->>'numberOfEvents')::integer, -1) as total_events
|
||||
, COALESCE((stats->>'numberOfLocalComments')::integer, -1) as localcomments
|
||||
, COALESCE((stats->>'numberOfComments')::integer, -1) as total_comments
|
||||
, COALESCE((stats->>'numberOfInstanceFollowings')::integer, -1) as followings
|
||||
, COALESCE((stats->>'numberOfInstanceFollowers')::integer, -1) as followers
|
||||
from history
|
||||
order by "insertedAt", "instanceId"
|
Reference in New Issue
Block a user