Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

report migration #9

Open
wants to merge 39 commits into
base: develop
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from 34 commits
Commits
Show all changes
39 commits
Select commit Hold shift + click to select a range
7f00593
Initial commit
extreme4all Apr 12, 2022
2447a37
init
extreme4all Apr 12, 2022
30a0d31
db_creation
extreme4all May 1, 2022
597f504
Create create.sh
extreme4all May 1, 2022
ec47ece
Update insert_playerdata_dev.sql
extreme4all May 11, 2022
2c932aa
some fixes
extreme4all May 16, 2022
fabe906
join lateral
extreme4all May 19, 2022
d858824
seperate files
extreme4all May 25, 2022
6cdc7c5
restructuring
extreme4all Jul 10, 2022
2b7009a
Update 003_insert_playerdata_dev.sql
extreme4all Jul 10, 2022
a2fef56
Update 003_insert_playerdata_dev.sql
extreme4all Jul 10, 2022
aeed5c8
Update create.sh
extreme4all Jul 10, 2022
d327e37
modified: database/002_insert_players.sql
extreme4all Aug 29, 2022
9f00da6
Update create.sh
extreme4all Aug 29, 2022
01b4a28
Update 002_insert_players.sql
extreme4all Oct 1, 2022
b212b12
Update 002_insert_players.sql
extreme4all Oct 24, 2022
befa6b7
init
extreme4all Jan 17, 2023
f82f256
random save
Apr 18, 2024
c83e5f0
modified: migrate_highscore_data.py
Apr 24, 2024
8766246
update
May 24, 2024
3a3080f
migration scripts
Jun 18, 2024
283fa82
init
extreme4all Jul 23, 2024
dd3e221
progress
extreme4all Jul 30, 2024
bc7e743
batching
extreme4all Aug 1, 2024
3289411
format code
extreme4all Aug 1, 2024
84d053c
best working solution
extreme4all Aug 1, 2024
54457de
saving
extreme4all Aug 3, 2024
eda1725
saving
extreme4all Aug 3, 2024
d6d331e
saving
extreme4all Aug 3, 2024
4ca80a2
saving
extreme4all Aug 3, 2024
379e15f
saving
extreme4all Aug 3, 2024
a2b3dcc
cleanup
extreme4all Nov 13, 2024
582b28c
Report data migration query
connect-web Nov 23, 2024
6b63ca4
Added query into python.
connect-web Nov 23, 2024
1150f29
Added query to use where not exists for the insert instead of where i…
connect-web Nov 23, 2024
0124c7e
Query to drop and re-create tables, for the tests.
connect-web Nov 23, 2024
0b5a8a8
- Bug fix
connect-web Nov 23, 2024
5b52171
Added async func wrappers around new queries.
connect-web Nov 23, 2024
065c255
Added a benchmark test to record execution time of queries
connect-web Nov 23, 2024
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
3 changes: 3 additions & 0 deletions database/000_recreate_playerdata_dev.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
DROP DATABASE IF EXISTS playerdata_dev;
CREATE DATABASE playerdata_dev;
GRANT SELECT, INSERT, UPDATE, DELETE, EVENT, TRIGGER ON `playerdata\_dev`.* TO 'event_admin'@'localhost'; ALTER USER 'event_admin'@'localhost' ;
19 changes: 19 additions & 0 deletions database/001_insert_apiUser.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
insert ignore into apiPermissions (id, permission) values
(1, 'verify_ban'),
(2, 'verify_players'),
(3, 'request_highscores')
;

insert ignore into apiUser (id, username, token, ratelimit, is_active) values
(1, 'verify_ban', 'verify_ban', -1, 1),
(2, 'verify_players', 'verify_players', -1, 1),
(3, 'request_highscores', 'request_highscores', -1, 1)
;

insert ignore into apiUserPerms (user_id, permission_id) VALUES
(1,1),
(1,2),
(1,3),
(2,2),
(3,3)
;
50 changes: 50 additions & 0 deletions database/002_insert_players.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,50 @@
/*
Insert players
*/
insert ignore into playerdata_dev.Labels
select * from playerdata.Labels order by id desc;
update playerdata_dev.Labels set id=0 where label='Unknown';

insert ignore into playerdata_dev.LabelJagex
select * from playerdata.LabelJagex;

insert ignore into playerdata_dev.Players
select p.* from playerdata.Labels lb
join lateral (
select
pl.*
from playerdata.Players pl
where lb.id = pl.label_id
limit 100
) p on (1=1)
;

/*
insert ignore into playerdata_dev.Players
select * from playerdata.Players pl
where 1=1
and pl.label_id = 0 -- unkown player
and pl.id not in (select id from playerdata_dev.Players)
limit 100
;

insert ignore into playerdata_dev.Players
select * from playerdata.Players pl
where 1=1
and pl.label_id = 1 -- real player
and pl.id not in (select id from playerdata_dev.Players)
limit 15000
;
*/

/*
Encrypt player names
*/
update playerdata_dev.Players
set
name=HEX(AES_ENCRYPT(name, "Victor_careers_onto_THE9_free0_endorser.")),
normalized_name=HEX(AES_ENCRYPT(normalized_name, "Victor_careers_onto_THE9_free0_endorser."))
;
/*
To decrypt the encryption: ES_DECRYPT(BINARY(UNHEX(setting_value)), 'key')
*/
17 changes: 17 additions & 0 deletions database/003_insert_playerdata_dev.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
/*
Generic data
*/
insert ignore into playerdata_dev.PredictionsFeedback
select pr.* from playerdata.PredictionsFeedback pr
join playerdata_dev.Players pl on pr.voter_id = pl.id or pr.subject_id=pl.id;

insert ignore into playerdata_dev.reportLatest
select rp.* from playerdata.reportLatest rp
join playerdata_dev.Players pl on rp.reported_id = pl.id;

insert ignore into playerdata_dev.Predictions
select pr.* from playerdata.Predictions pr
join playerdata_dev.Players pl on pr.id = pl.id;

ALTER TABLE playerdata_dev.Predictions CHANGE `name` `name` VARCHAR(64) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL;
update playerdata_dev.Predictions set name=HEX(AES_ENCRYPT(name, "Victor_careers_onto_THE9_free0_endorser."));
12 changes: 12 additions & 0 deletions database/004_insert_playerHiscoreData.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
insert ignore into playerdata_dev.playerHiscoreData
select phd.* from playerdata.playerHiscoreData phd
join playerdata_dev.Players pl on phd.Player_id = pl.id;

insert ignore into playerdata_dev.playerHiscoreDataLatest
select phd.* from playerdata.playerHiscoreDataLatest phd
join playerdata_dev.Players pl on phd.Player_id = pl.id;

insert ignore into playerdata_dev.playerHiscoreDataXPChange
select phd.* from playerdata.playerHiscoreDataXPChange phd
join playerdata_dev.Players pl on phd.Player_id = pl.id;

21 changes: 21 additions & 0 deletions database/005_insert_reports.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
insert ignore into playerdata_dev.Reports
select a.* from playerdata_dev.Players pl
join lateral (
select
plr.*
from playerdata.Reports plr
where plr.reportedid = pl.id
limit 100
) a on (1=1)
;

insert ignore into playerdata_dev.Reports
select a.* from playerdata_dev.Players pl
join lateral (
select
plr.*
from playerdata.Reports plr
where plr.reportingid = pl.id
limit 100
) a on (1=1)
;
14 changes: 14 additions & 0 deletions database/create.sh
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
#!/bin/sh

sudo mysql -u root < /home/ubuntu/000_recreate_playerdata_dev.sql
sudo mysqldump -u root --no-data --routines --triggers --events --databases playerdata| sudo mysql -u root playerdata_dev
sudo mysql -u root playerdata_dev < /home/ubuntu/001_insert_apiUser.sql
sudo mysql -u root playerdata_dev < /home/ubuntu/002_insert_players.sql
sudo mysql -u root playerdata_dev < /home/ubuntu/003_insert_playerdata_dev.sql
sudo mysql -u root playerdata_dev < /home/ubuntu/004_insert_playerHiscoreData.sql
sudo mysql -u root playerdata_dev < /home/ubuntu/005_insert_reports.sql
sudo mysqldump -u root --routines --events --databases playerdata_dev | sed 's/playerdata_dev/playerdata/g'| gzip > 100_playerdata_dev.sql.gz

# sudo mysql -u root playerdata_dev < /home/ubuntu/insert_playerReports.sql
# sudo mysql -u root playerdata_dev < /home/ubuntu/insert_playerReportsManual.sql
# sudo mysql -u root playerdata_dev < /home/ubuntu/insert_playerLocationsDetail.sql
21 changes: 21 additions & 0 deletions database/xx_insert_playerLocationsDetail.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
insert ignore into playerdata_dev.playerLocations
select a.* from playerdata_dev.Players pl
join lateral (
select
plo.*
from playerdata.playerLocations plo
where plo.reported_id = pl.id
limit 100
) a on (1=1)
;

insert ignore into playerdata_dev.playerLocationsDetail
select a.* from playerdata_dev.Players pl
join lateral (
select
pld.*
from playerdata.playerLocationsDetail pld
where pld.reported_id = pl.id
limit 100
) a on (1=1)
;
21 changes: 21 additions & 0 deletions database/xx_insert_playerReports.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
insert ignore into playerdata_dev.playerReports
select a.* from playerdata_dev.Players pl
join lateral (
select
plr.*
from playerdata.playerReports plr
where plr.reported_id = pl.id
limit 100
) a on (1=1)
;

insert ignore into playerdata_dev.playerReports
select a.* from playerdata_dev.Players pl
join lateral (
select
plr.*
from playerdata.playerReports plr
where plr.reporting_id = pl.id
limit 100
) a on (1=1)
;
21 changes: 21 additions & 0 deletions database/xx_insert_playerReportsManual.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
insert ignore into playerdata_dev.playerReportsManual
select a.* from playerdata_dev.Players pl
join lateral (
select
prm.*
from playerdata.playerReportsManual prm
where prm.reporting_id = pl.id
limit 100
) a on (1=1)
;

insert ignore into playerdata_dev.playerReportsManual
select a.* from playerdata_dev.Players pl
join lateral (
select
prm.*
from playerdata.playerReportsManual prm
where prm.reported_id = pl.id
limit 100
) a on (1=1)
;
18 changes: 18 additions & 0 deletions notes.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
## setup
```
python -m venv .venv
.venv\Scripts\activate
python -m pip install --upgrade pip
pip install -r requirements.txt
```
# for admin purposes saving & upgrading
run this in cmd

```
venv\Scripts\activate
call pip freeze > requirements.txt
powershell "(Get-Content requirements.txt) | ForEach-Object { $_ -replace '==', '>=' } | Set-Content requirements.txt"
call pip install -r requirements.txt --upgrade
call pip freeze > requirements.txt
powershell "(Get-Content requirements.txt) | ForEach-Object { $_ -replace '>=', '==' } | Set-Content requirements.txt"
```
13 changes: 10 additions & 3 deletions report_migration/migrate_report_data.py
Original file line number Diff line number Diff line change
Expand Up @@ -20,14 +20,21 @@
autoflush=False,
)

with open('report_data.sql','r') as x:
migration_query = x.read()

async def main():
await migrate_selection(1, 100_000)

async def migrate_selection(startId, endId):
# get a session
async with Session() as session:
session: AsyncSession
# get a transaction
params = {"startId": startId, "endId": endId}
async with session.begin():
# do something
pass
await session.execute(sqla.text(migration_query+" COMMIT;"), params=params)



if __name__ == "__main__":
asyncio.run(main())
131 changes: 131 additions & 0 deletions report_migration/report_data.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,131 @@
-- Step 1: Create temp_batch table
DROP TEMPORARY TABLE IF EXISTS temp_batch;

CREATE TEMPORARY TABLE IF NOT EXISTS temp_batch (
ID BIGINT NOT NULL,
created_at TIMESTAMP,
reportedID INT,
reportingID INT,
region_id INT,
x_coord INT,
y_coord INT,
z_coord INT,
timestamp TIMESTAMP,
manual_detect TINYINT,
on_members_world INT,
on_pvp_world TINYINT,
world_number INT,
equip_head_id INT,
equip_amulet_id INT,
equip_torso_id INT,
equip_legs_id INT,
equip_boots_id INT,
equip_cape_id INT,
equip_hands_id INT,
equip_weapon_id INT,
equip_shield_id INT,
equip_ge_value BIGINT,
report_sighting_id INT DEFAULT NULL,
report_location_id INT DEFAULT NULL,
report_gear_id INT DEFAULT NULL
);

-- Step 2: Insert data into temp_batch (manually adjust startId, endId, and batch_size as needed)

INSERT INTO temp_batch (ID, created_at, reportedID, reportingID, region_id, x_coord, y_coord, z_coord,
timestamp, manual_detect, on_members_world, on_pvp_world, world_number,
equip_head_id, equip_amulet_id, equip_torso_id, equip_legs_id, equip_boots_id,
equip_cape_id, equip_hands_id, equip_weapon_id, equip_shield_id, equip_ge_value)
SELECT ID, created_at, reportedID, reportingID, region_id, x_coord, y_coord, z_coord,
timestamp, manual_detect, on_members_world, on_pvp_world, world_number,
equip_head_id, equip_amulet_id, equip_torso_id, equip_legs_id, equip_boots_id,
equip_cape_id, equip_hands_id, equip_weapon_id, equip_shield_id, equip_ge_value
FROM Reports
WHERE ID > :startId AND ID <= :endId -- Python Variables
ORDER BY ID ASC;

-- Step 3: Update temp_batch with existing foreign keys from report_sighting
UPDATE temp_batch AS tb
LEFT JOIN report_sighting AS rs
ON tb.reportingID = rs.reporting_id AND tb.reportedID = rs.reported_id AND tb.manual_detect = rs.manual_detect
SET tb.report_sighting_id = rs.report_sighting_id;



-- Debug: Check temp_batch after update
-- SELECT * FROM temp_batch WHERE report_sighting_id IS NULL;

-- Step 4: Insert missing rows into report_sighting
INSERT INTO report_sighting (reporting_id, reported_id, manual_detect)
SELECT DISTINCT reportingID, reportedID, manual_detect
FROM temp_batch
WHERE report_sighting_id IS NULL
ORDER BY reportingID, reportedID, manual_detect;

-- Debug: Check rows inserted into report_sighting
-- SELECT * FROM report_sighting ORDER BY report_sighting_id DESC LIMIT 10;

-- Step 5: Update temp_batch with newly inserted report_sighting IDs
UPDATE temp_batch AS tb
JOIN report_sighting AS rs
ON tb.reportingID = rs.reporting_id AND tb.reportedID = rs.reported_id AND tb.manual_detect = rs.manual_detect
SET tb.report_sighting_id = rs.report_sighting_id
WHERE tb.report_sighting_id IS NULL;
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Any reason you did not adopt this from migrate_report_sighting

INSERT INTO report_sighting (reporting_id, reported_id, manual_detect)
SELECT DISTINCT tb.reportingID , tb.reportedID , IFNULL(tb..manual_detect,0) from temp_batch tb
WHERE 1
    AND NOT EXISTS (
        SELECT 1 FROM report_sighting rs
        WHERE 1
            AND tb.reportingID = rs.reporting_id
            AND tb.reportedID = rs.reported_id
            AND IFNULL(tb.manual_detect,0) = rs.manual_detect
);

Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Step 3 finds existing report_sighting_id and sets it to the temp_batch

so when step 4 mentions "WHERE report_sighting_id IS NULL" it does the same as
"AND NOT EXISTS (
SELECT 1 FROM report_sighting rs
WHERE 1
AND tb.reportingID = rs.reporting_id
AND tb.reportedID = rs.reported_id
AND IFNULL(tb.manual_detect,0) = rs.manual_detect
);"

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

yes you are correct, but is there any particular reason you went for two updates?


-- Debug: Verify report_sighting_id is updated
-- SELECT * FROM temp_batch;

-- Step 6: Insert missing rows into report_gear
INSERT INTO report_gear (equip_head_id, equip_amulet_id, equip_torso_id, equip_legs_id,
equip_boots_id, equip_cape_id, equip_hands_id, equip_weapon_id, equip_shield_id)
SELECT DISTINCT equip_head_id, equip_amulet_id, equip_torso_id, equip_legs_id,
equip_boots_id, equip_cape_id, equip_hands_id, equip_weapon_id, equip_shield_id
FROM temp_batch
WHERE report_gear_id IS NULL
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

if you want to commit to the update table idea you'll have to check every table first

ORDER BY equip_head_id, equip_amulet_id, equip_torso_id, equip_legs_id,
equip_boots_id, equip_cape_id, equip_hands_id, equip_weapon_id, equip_shield_id;

-- Debug: Check rows inserted into report_gear
-- SELECT * FROM report_gear ORDER BY report_gear_id DESC LIMIT 10;

-- Step 7: Update temp_batch with newly inserted report_gear IDs
UPDATE temp_batch AS tb
JOIN report_gear AS rg
ON tb.equip_head_id = rg.equip_head_id AND tb.equip_amulet_id = rg.equip_amulet_id
AND tb.equip_torso_id = rg.equip_torso_id AND tb.equip_legs_id = rg.equip_legs_id
AND tb.equip_boots_id = rg.equip_boots_id AND tb.equip_cape_id = rg.equip_cape_id
AND tb.equip_hands_id = rg.equip_hands_id AND tb.equip_weapon_id = rg.equip_weapon_id
AND tb.equip_shield_id = rg.equip_shield_id
SET tb.report_gear_id = rg.report_gear_id
WHERE tb.report_gear_id IS NULL;

-- Debug: Verify report_gear_id is updated
-- SELECT * FROM temp_batch;

-- Step 8: Insert missing rows into report_location
INSERT INTO report_location (region_id, x_coord, y_coord, z_coord)
SELECT DISTINCT region_id, x_coord, y_coord, z_coord
FROM temp_batch
WHERE report_location_id IS NULL
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

if you want to commit to the update table idea you'll have to check every table first

ORDER BY region_id, x_coord, y_coord, z_coord;

-- Debug: Check rows inserted into report_location
-- SELECT * FROM report_location ORDER BY report_location_id DESC LIMIT 10;

-- Step 9: Update temp_batch with newly inserted report_location IDs
UPDATE temp_batch AS tb
JOIN report_location AS rl
ON tb.region_id = rl.region_id AND tb.x_coord = rl.x_coord
AND tb.y_coord = rl.y_coord AND tb.z_coord = rl.z_coord
SET tb.report_location_id = rl.report_location_id
WHERE tb.report_location_id IS NULL;

-- Debug: Verify report_location_id is updated
-- SELECT * FROM temp_batch;

-- Step 10: Final insert into the report table
INSERT IGNORE INTO report (report_sighting_id, report_location_id, report_gear_id, created_at, reported_at,
on_members_world, on_pvp_world, world_number, region_id)
SELECT DISTINCT report_sighting_id, report_location_id, report_gear_id, created_at, timestamp,
on_members_world, on_pvp_world, world_number, region_id
FROM temp_batch;
Empty file added test.sql
Empty file.