Add script to import whitelisted address
This commit is contained in:
149
scripts/privy/import-privy-users.sh
Executable file
149
scripts/privy/import-privy-users.sh
Executable file
@@ -0,0 +1,149 @@
|
||||
#!/bin/bash
|
||||
|
||||
# Script to import privy-users.csv into WhitelistAccounts table
|
||||
# Uses connection string from appsettings.ProductionLocal.json
|
||||
|
||||
set -e # Exit on error
|
||||
|
||||
# Get the directory where this script is located
|
||||
SCRIPT_DIR="$(cd "$(dirname "${BASH_SOURCE[0]}")" && pwd)"
|
||||
PROJECT_ROOT="$(cd "$SCRIPT_DIR/../.." && pwd)"
|
||||
CSV_FILE="$SCRIPT_DIR/privy-users.csv"
|
||||
SETTINGS_FILE="$PROJECT_ROOT/src/Managing.Api/appsettings.ProductionLocal.json"
|
||||
|
||||
# Check if CSV file exists
|
||||
if [ ! -f "$CSV_FILE" ]; then
|
||||
echo "Error: CSV file not found at $CSV_FILE"
|
||||
exit 1
|
||||
fi
|
||||
|
||||
# Check if settings file exists
|
||||
if [ ! -f "$SETTINGS_FILE" ]; then
|
||||
echo "Error: Settings file not found at $SETTINGS_FILE"
|
||||
exit 1
|
||||
fi
|
||||
|
||||
# Extract connection string from JSON (using sed for macOS compatibility)
|
||||
CONNECTION_STRING=$(grep '"ConnectionString"' "$SETTINGS_FILE" | sed 's/.*"ConnectionString": "\([^"]*\)".*/\1/')
|
||||
|
||||
if [ -z "$CONNECTION_STRING" ]; then
|
||||
echo "Error: Could not extract connection string from settings file"
|
||||
exit 1
|
||||
fi
|
||||
|
||||
# Parse connection string parameters (macOS compatible)
|
||||
HOST=$(echo "$CONNECTION_STRING" | sed -n 's/.*Host=\([^;]*\).*/\1/p')
|
||||
PORT=$(echo "$CONNECTION_STRING" | sed -n 's/.*Port=\([^;]*\).*/\1/p')
|
||||
DATABASE=$(echo "$CONNECTION_STRING" | sed -n 's/.*Database=\([^;]*\).*/\1/p')
|
||||
USERNAME=$(echo "$CONNECTION_STRING" | sed -n 's/.*Username=\([^;]*\).*/\1/p')
|
||||
PASSWORD=$(echo "$CONNECTION_STRING" | sed -n 's/.*Password=\([^;]*\).*/\1/p')
|
||||
|
||||
# Export password for psql
|
||||
export PGPASSWORD="$PASSWORD"
|
||||
|
||||
echo "Connecting to database: $DATABASE@$HOST:$PORT"
|
||||
echo "Importing from: $CSV_FILE"
|
||||
echo ""
|
||||
|
||||
# Create SQL script as a here-document
|
||||
psql -h "$HOST" -p "$PORT" -U "$USERNAME" -d "$DATABASE" <<EOF
|
||||
|
||||
-- Create temporary table to hold raw CSV data
|
||||
CREATE TEMP TABLE IF NOT EXISTS temp_privy_import (
|
||||
id TEXT,
|
||||
created_at TEXT,
|
||||
custom_metadata TEXT,
|
||||
is_guest TEXT,
|
||||
mfa_enabled TEXT,
|
||||
external_ethereum_accounts TEXT,
|
||||
external_solana_accounts TEXT,
|
||||
embedded_ethereum_accounts TEXT,
|
||||
embedded_solana_accounts TEXT,
|
||||
smart_wallet_accounts TEXT,
|
||||
email_account TEXT,
|
||||
phone_account TEXT,
|
||||
google_account TEXT,
|
||||
apple_account TEXT,
|
||||
spotify_account TEXT,
|
||||
linkedin_account TEXT,
|
||||
twitter_account TEXT,
|
||||
discord_account TEXT,
|
||||
github_account TEXT,
|
||||
instagram_account TEXT,
|
||||
tiktok_account TEXT,
|
||||
line_account TEXT,
|
||||
twitch_account TEXT,
|
||||
telegram_account TEXT,
|
||||
farcaster_account TEXT,
|
||||
custom_auth_account TEXT,
|
||||
passkey_account TEXT
|
||||
);
|
||||
|
||||
-- Copy data from CSV file
|
||||
\copy temp_privy_import FROM '$CSV_FILE' WITH (FORMAT csv, DELIMITER E'\t', HEADER true, ENCODING 'UTF8')
|
||||
|
||||
-- Insert into WhitelistAccounts table with data transformation
|
||||
INSERT INTO "WhitelistAccounts" (
|
||||
"PrivyId",
|
||||
"PrivyCreationDate",
|
||||
"EmbeddedWallet",
|
||||
"ExternalEthereumAccount",
|
||||
"TwitterAccount",
|
||||
"IsWhitelisted",
|
||||
"CreatedAt"
|
||||
)
|
||||
SELECT
|
||||
id AS "PrivyId",
|
||||
-- Parse the date string: "Fri Jan 31 2025 14:52:20 GMT+0000 (Coordinated Universal Time)"
|
||||
-- Extract the date part before "GMT" and convert to timestamp
|
||||
TO_TIMESTAMP(
|
||||
REGEXP_REPLACE(
|
||||
created_at,
|
||||
' GMT\+0000 \(.*\)$',
|
||||
''
|
||||
),
|
||||
'Dy Mon DD YYYY HH24:MI:SS'
|
||||
) AS "PrivyCreationDate",
|
||||
-- Extract first embedded wallet (split by comma if multiple, take first)
|
||||
NULLIF(TRIM(SPLIT_PART(embedded_ethereum_accounts, ',', 1)), '') AS "EmbeddedWallet",
|
||||
-- Extract first external ethereum account (split by comma if multiple, take first)
|
||||
NULLIF(TRIM(SPLIT_PART(external_ethereum_accounts, ',', 1)), '') AS "ExternalEthereumAccount",
|
||||
-- Extract Twitter account (remove @ if present, take first if multiple)
|
||||
NULLIF(TRIM(REGEXP_REPLACE(SPLIT_PART(twitter_account, ',', 1), '^@', '')), '') AS "TwitterAccount",
|
||||
false AS "IsWhitelisted",
|
||||
NOW() AS "CreatedAt"
|
||||
FROM temp_privy_import
|
||||
WHERE
|
||||
-- Only import rows with required fields
|
||||
id IS NOT NULL
|
||||
AND id != ''
|
||||
AND embedded_ethereum_accounts IS NOT NULL
|
||||
AND TRIM(embedded_ethereum_accounts) != ''
|
||||
AND created_at IS NOT NULL
|
||||
AND created_at != ''
|
||||
-- Skip duplicates based on PrivyId or EmbeddedWallet
|
||||
AND NOT EXISTS (
|
||||
SELECT 1 FROM "WhitelistAccounts"
|
||||
WHERE "PrivyId" = temp_privy_import.id
|
||||
OR "EmbeddedWallet" = NULLIF(TRIM(SPLIT_PART(temp_privy_import.embedded_ethereum_accounts, ',', 1)), '')
|
||||
);
|
||||
|
||||
-- Show summary
|
||||
SELECT
|
||||
COUNT(*) AS "TotalImported",
|
||||
COUNT(DISTINCT "PrivyId") AS "UniquePrivyIds",
|
||||
COUNT("ExternalEthereumAccount") AS "WithExternalAccount",
|
||||
COUNT("TwitterAccount") AS "WithTwitterAccount"
|
||||
FROM "WhitelistAccounts";
|
||||
|
||||
-- Clean up temporary table
|
||||
DROP TABLE IF EXISTS temp_privy_import;
|
||||
|
||||
EOF
|
||||
|
||||
# Unset password
|
||||
unset PGPASSWORD
|
||||
|
||||
echo ""
|
||||
echo "Import completed successfully!"
|
||||
|
||||
Reference in New Issue
Block a user