Skip to content
GitLab
Explore
Sign in
Primary navigation
Search or go to…
Project
B
backend
Manage
Activity
Members
Labels
Plan
Issues
Issue boards
Milestones
Iterations
Wiki
Code
Merge requests
Repository
Branches
Commits
Tags
Repository graph
Compare revisions
Locked files
Build
Pipelines
Jobs
Pipeline schedules
Test cases
Artifacts
Deploy
Package registry
Container registry
Operate
Terraform modules
Analyze
Value stream analytics
Contributor analytics
CI/CD analytics
Repository analytics
Code review analytics
Issue analytics
Insights
Help
Help
Support
GitLab documentation
Compare GitLab plans
GitLab community forum
Contribute to GitLab
Provide feedback
Keyboard shortcuts
?
Snippets
Groups
Projects
Show more breadcrumbs
videoag
backend
Commits
573bf1a5
Commit
573bf1a5
authored
3 months ago
by
Simon Künzel
Browse files
Options
Downloads
Patches
Plain Diff
Add view stats migration script
parent
bda47816
No related branches found
No related tags found
No related merge requests found
Pipeline
#7587
passed
3 months ago
Stage: build
Stage: run
Pipeline: backend
#7588
Changes
2
Pipelines
1
Show whitespace changes
Inline
Side-by-side
Showing
2 changed files
api/migrate_stats.sql
+109
-0
109 additions, 0 deletions
api/migrate_stats.sql
api/migration.sql
+7
-6
7 additions, 6 deletions
api/migration.sql
with
116 additions
and
6 deletions
api/migrate_stats.sql
0 → 100644
+
109
−
0
View file @
573bf1a5
DELETE
FROM
lecture_daily_watch_stats
;
DELETE
FROM
lecture_watch_stats
;
DELETE
FROM
unknown_video
;
CREATE
OR
REPLACE
PROCEDURE
temp_count_lecture_view
(
lec_id
int
,
watch_timestamp
timestamp
)
AS
$$
BEGIN
INSERT
INTO
lecture_watch_stats
(
lecture_id
,
segment_duration_sec
,
view_count
,
total_watched_seconds
,
average_watch_speed
)
VALUES
(
lec_id
,
5
,
1
,
0
,
1
)
ON
CONFLICT
(
lecture_id
)
DO
UPDATE
SET
view_count
=
lecture_watch_stats
.
view_count
+
1
;
INSERT
INTO
lecture_daily_watch_stats
(
lecture_id
,
"date"
,
view_count
)
VALUES
(
lec_id
,
watch_timestamp
::
date
,
1
)
ON
CONFLICT
(
lecture_id
,
"date"
)
DO
UPDATE
SET
view_count
=
lecture_daily_watch_stats
.
view_count
+
1
;
END
;
$$
LANGUAGE
plpgsql
;
CREATE
OR
REPLACE
PROCEDURE
temp_count_video_view
(
vid_id
int
,
watch_timestamp
timestamp
)
AS
$$
DECLARE
current_lecture_id
int
;
BEGIN
SELECT
lecture_id
FROM
videos_data
WHERE
id
=
vid_id
INTO
current_lecture_id
;
IF
current_lecture_id
IS
NULL
THEN
INSERT
INTO
unknown_video
(
video_id
,
view_count
)
VALUES
(
vid_id
,
1
)
ON
CONFLICT
(
video_id
)
DO
UPDATE
SET
view_count
=
unknown_video
.
view_count
+
1
;
ELSE
CALL
temp_count_lecture_view
(
current_lecture_id
,
watch_timestamp
);
IF
EXISTS
(
SELECT
1
FROM
publish_medium
WHERE
id
=
vid_id
)
THEN
INSERT
INTO
publish_medium_watch_stats
(
publish_medium_id
,
view_count
,
total_watched_seconds
)
VALUES
(
vid_id
,
1
,
0
)
ON
CONFLICT
(
publish_medium_id
)
DO
UPDATE
SET
view_count
=
publish_medium_watch_stats
.
view_count
+
1
;
END
IF
;
END
IF
;
END
;
$$
LANGUAGE
plpgsql
;
DO
$$
DECLARE
total_processing_count
int
;
processed_count
int
;
video_watcher
record
;
log_entry
record
;
last_entry_timestamp
timestamp
;
BEGIN
SELECT
COUNT
(
*
)
FROM
(
SELECT
1
FROM
hlslog
GROUP
BY
id
,
lecture
)
INTO
total_processing_count
;
SELECT
0
INTO
processed_count
;
FOR
video_watcher
IN
(
SELECT
id
,
lecture
FROM
hlslog
GROUP
BY
id
,
lecture
)
LOOP
SELECT
NULL
INTO
last_entry_timestamp
;
IF
processed_count
%
10000
=
0
THEN
RAISE
NOTICE
'(hlslog) Processed %/% (% %%)'
,
processed_count
,
total_processing_count
,
(
processed_count
::
double
precision
/
total_processing_count
*
100
)::
int
;
END
IF
;
SELECT
processed_count
+
1
INTO
processed_count
;
FOR
log_entry
IN
(
SELECT
*
FROM
hlslog
WHERE
id
=
video_watcher
.
id
AND
lecture
=
video_watcher
.
lecture
ORDER
BY
"time"
ASC
)
LOOP
IF
last_entry_timestamp
IS
NOT
NULL
AND
log_entry
.
"time"
>
(
last_entry_timestamp
+
interval
'6 hours'
)
THEN
CALL
temp_count_lecture_view
(
video_watcher
.
lecture
,
last_entry_timestamp
);
END
IF
;
SELECT
log_entry
.
"time"
INTO
last_entry_timestamp
;
END
LOOP
;
IF
last_entry_timestamp
IS
NOT
NULL
THEN
CALL
temp_count_lecture_view
(
video_watcher
.
lecture
,
last_entry_timestamp
);
END
IF
;
END
LOOP
;
END
;
$$
;
DO
$$
DECLARE
total_processing_count
int
;
processed_count
int
;
video_watcher
record
;
log_entry
record
;
last_entry_timestamp
timestamp
;
BEGIN
SELECT
COUNT
(
*
)
FROM
(
SELECT
1
FROM
log
GROUP
BY
id
,
video
)
INTO
total_processing_count
;
SELECT
0
INTO
processed_count
;
FOR
video_watcher
IN
(
SELECT
id
,
video
FROM
log
GROUP
BY
id
,
video
)
LOOP
SELECT
NULL
INTO
last_entry_timestamp
;
IF
processed_count
%
10000
=
0
THEN
RAISE
NOTICE
'(log) Processed %/% (% %%)'
,
processed_count
,
total_processing_count
,
(
processed_count
::
double
precision
/
total_processing_count
*
100
)::
int
;
END
IF
;
SELECT
processed_count
+
1
INTO
processed_count
;
FOR
log_entry
IN
(
SELECT
*
FROM
log
WHERE
id
=
video_watcher
.
id
AND
video
=
video_watcher
.
video
ORDER
BY
"time"
ASC
)
LOOP
IF
last_entry_timestamp
IS
NOT
NULL
AND
log_entry
.
"time"
>
(
last_entry_timestamp
+
interval
'6 hours'
)
THEN
CALL
temp_count_video_view
(
video_watcher
.
video
,
last_entry_timestamp
);
END
IF
;
SELECT
log_entry
.
"time"
INTO
last_entry_timestamp
;
END
LOOP
;
IF
last_entry_timestamp
IS
NOT
NULL
THEN
CALL
temp_count_video_view
(
video_watcher
.
video
,
last_entry_timestamp
);
END
IF
;
END
LOOP
;
END
;
$$
;
\ No newline at end of file
This diff is collapsed.
Click to expand it.
api/migration.sql
+
7
−
6
View file @
573bf1a5
UPDATE
data
.
job
SET
cause_job_id
=
NULL
,
cause_user_id
=
NULL
WHERE
id
>=
0
;
UPDATE
data
.
job
SET
cause_job_id
=
NULL
,
cause_user_id
=
NULL
WHERE
id
>=
0
;
DELETE
FROM
lecture_daily_watch_stats
;
DELETE
FROM
data
.
lecture_daily_watch_stats
;
DELETE
FROM
lecture_watch_stats
;
DELETE
FROM
data
.
lecture_watch_stats
;
DELETE
FROM
publish_medium_segment_watch_stats
;
DELETE
FROM
data
.
publish_medium_segment_watch_stats
;
DELETE
FROM
publish_medium_watch_client_stats
;
DELETE
FROM
data
.
publish_medium_watch_stats
;
DELETE
FROM
publish_medium_watch_log_entry
;
DELETE
FROM
data
.
publish_medium_watch_client_stats
;
DELETE
FROM
publish_medium_watcher
;
DELETE
FROM
data
.
publish_medium_watch_log_entry
;
DELETE
FROM
data
.
publish_medium_watcher
;
DELETE
FROM
data
.
featured
WHERE
id
>=
0
;
DELETE
FROM
data
.
featured
WHERE
id
>=
0
;
DELETE
FROM
data
.
announcement
WHERE
id
>=
0
;
DELETE
FROM
data
.
announcement
WHERE
id
>=
0
;
...
...
This diff is collapsed.
Click to expand it.
Preview
0%
Loading
Try again
or
attach a new file
.
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Save comment
Cancel
Please
register
or
sign in
to comment