Skip to content
GitLab
Explore
Sign in
Register
Primary navigation
Search or go to…
Project
H
hivemind
Manage
Activity
Members
Labels
Plan
Issues
Issue boards
Milestones
Wiki
Code
Merge requests
Repository
Branches
Commits
Tags
Repository graph
Compare revisions
Snippets
Deploy
Releases
Package registry
Container Registry
Model registry
Operate
Terraform modules
Monitor
Incidents
Analyze
Value stream analytics
Contributor analytics
Repository analytics
Model experiments
Help
Help
Support
GitLab documentation
Compare GitLab plans
Community forum
Contribute to GitLab
Provide feedback
Keyboard shortcuts
?
Snippets
Groups
Projects
Show more breadcrumbs
hive
hivemind
Commits
03998f3f
Commit
03998f3f
authored
6 years ago
by
roadscape
Browse files
Options
Downloads
Patches
Plain Diff
migrations - db tuning for beta release
parent
bebdaca2
No related branches found
No related tags found
No related merge requests found
Changes
2
Hide whitespace changes
Inline
Side-by-side
Showing
2 changed files
hive/db/db_state.py
+60
-13
60 additions, 13 deletions
hive/db/db_state.py
hive/db/schema.py
+38
-31
38 additions, 31 deletions
hive/db/schema.py
with
98 additions
and
44 deletions
hive/db/db_state.py
+
60
−
13
View file @
03998f3f
...
...
@@ -3,7 +3,7 @@
import
time
import
logging
from
hive.db.schema
import
setup
,
build_metadata
,
teardown
,
DB_VERSION
from
hive.db.schema
import
setup
,
reset_autovac
,
build_metadata
,
teardown
,
DB_VERSION
from
hive.db.adapter
import
Db
log
=
logging
.
getLogger
(
__name__
)
...
...
@@ -82,14 +82,21 @@ class DbState:
@classmethod
def
_disableable_indexes
(
cls
):
to_locate
=
[
'
hive_posts_ix
1
'
,
# (
parent_
id)
'
hive_posts_ix
2
'
,
# (is_deleted
, depth
)
'
hive_follows_ix
2
'
,
# (following,
follower, state=1
)
'
hive_follows_ix
3
'
,
# (follower, following
, state=1
)
'
hive_posts_ix
3
'
,
# (
author, depth,
id)
'
hive_posts_ix
4
'
,
# (
parent_id, id,
is_deleted
=0
)
'
hive_follows_ix
5a
'
,
# (following,
state, created_at, follower
)
'
hive_follows_ix
5b
'
,
# (follower,
state, created_at,
following)
'
hive_reblogs_ix1
'
,
# (post_id, account, created_at)
'
hive_posts_cache_ix6
'
,
# (sc_trend, post_id)
'
hive_posts_cache_ix7
'
,
# (sc_hot, post_id)
'
hive_posts_cache_ix6a
'
,
# (sc_trend, post_id, paidout=0)
'
hive_posts_cache_ix6b
'
,
# (post_id, sc_trend, paidout=0)
'
hive_posts_cache_ix7a
'
,
# (sc_hot, post_id, paidout=0)
'
hive_posts_cache_ix7b
'
,
# (post_id, sc_hot, paidout=0)
'
hive_posts_cache_ix8
'
,
# (category, payout, depth, paidout=0)
'
hive_posts_cache_ix9a
'
,
# (depth, payout, post_id, paidout=0)
'
hive_posts_cache_ix9b
'
,
# (category, depth, payout, post_id, paidout=0)
'
hive_accounts_ix3
'
,
# (vote_weight, name VPO)
'
hive_accounts_ix4
'
,
# (id, name)
'
hive_accounts_ix5
'
,
# (cached_at, name)
]
to_return
=
[]
...
...
@@ -181,6 +188,7 @@ class DbState:
@classmethod
def
_check_migrations
(
cls
):
"""
Check current migration version and perform updates as needed.
"""
#pylint: disable=line-too-long
cls
.
_ver
=
cls
.
db
().
query_one
(
"
SELECT db_version FROM hive_state LIMIT 1
"
)
assert
cls
.
_ver
is
not
None
,
'
could not load state record
'
...
...
@@ -194,15 +202,11 @@ class DbState:
cls
.
_set_ver
(
3
)
if
cls
.
_ver
==
3
:
sql
=
"""
CREATE INDEX hive_accounts_ix3 ON hive_accounts
USING btree (vote_weight, name varchar_pattern_ops)
"""
cls
.
db
().
query
(
sql
)
cls
.
db
().
query
(
"
CREATE INDEX hive_accounts_ix3 ON hive_accounts (vote_weight, name varchar_pattern_ops)
"
)
cls
.
_set_ver
(
4
)
if
cls
.
_ver
==
4
:
sql
=
"""
CREATE INDEX hive_follows_ix4 ON public.hive_follows
USING btree (follower, following) WHERE state = 2;
"""
cls
.
db
().
query
(
sql
)
cls
.
db
().
query
(
"
CREATE INDEX hive_follows_ix4 ON hive_follows (follower, following) WHERE state = 2
"
)
cls
.
_set_ver
(
5
)
if
cls
.
_ver
==
5
:
...
...
@@ -215,6 +219,49 @@ class DbState:
Accounts
.
clear_ids
()
cls
.
_set_ver
(
6
)
if
cls
.
_ver
==
6
:
cls
.
db
().
query
(
"
DROP INDEX hive_posts_cache_ix6
"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_posts_cache_ix6a ON hive_posts_cache (sc_trend, post_id) WHERE is_paidout =
'
0
'"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_posts_cache_ix6b ON hive_posts_cache (post_id, sc_trend) WHERE is_paidout =
'
0
'"
)
cls
.
db
().
query
(
"
DROP INDEX hive_posts_cache_ix7
"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_posts_cache_ix7a ON hive_posts_cache (sc_hot, post_id) WHERE is_paidout =
'
0
'"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_posts_cache_ix7b ON hive_posts_cache (post_id, sc_hot) WHERE is_paidout =
'
0
'"
)
cls
.
_set_ver
(
7
)
if
cls
.
_ver
==
7
:
cls
.
db
().
query
(
"
CREATE INDEX hive_accounts_ix4 ON hive_accounts (id, name)
"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_accounts_ix5 ON hive_accounts (cached_at, name)
"
)
cls
.
_set_ver
(
8
)
if
cls
.
_ver
==
8
:
cls
.
db
().
query
(
"
DROP INDEX hive_follows_ix2
"
)
cls
.
db
().
query
(
"
DROP INDEX hive_follows_ix3
"
)
cls
.
db
().
query
(
"
DROP INDEX hive_follows_ix4
"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_follows_5a ON hive_follows (following, state, created_at, follower)
"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_follows_5b ON hive_follows (follower, state, created_at, following)
"
)
cls
.
_set_ver
(
9
)
if
cls
.
_ver
==
9
:
from
hive.indexer.follow
import
Follow
Follow
.
force_recount
()
cls
.
_set_ver
(
10
)
if
cls
.
_ver
==
10
:
cls
.
db
().
query
(
"
CREATE INDEX hive_posts_cache_ix8 ON hive_posts_cache (category, payout, depth) WHERE is_paidout =
'
0
'"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_posts_cache_ix9a ON hive_posts_cache (depth, payout, post_id) WHERE is_paidout =
'
0
'"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_posts_cache_ix9b ON hive_posts_cache (category, depth, payout, post_id) WHERE is_paidout =
'
0
'"
)
cls
.
_set_ver
(
11
)
if
cls
.
_ver
==
11
:
cls
.
db
().
query
(
"
DROP INDEX hive_posts_ix1
"
)
cls
.
db
().
query
(
"
DROP INDEX hive_posts_ix2
"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_posts_ix3 ON hive_posts (author, depth, id) WHERE is_deleted =
'
0
'"
)
cls
.
db
().
query
(
"
CREATE INDEX hive_posts_ix4 ON hive_posts (parent_id, id) WHERE is_deleted =
'
0
'"
)
cls
.
_set_ver
(
12
)
reset_autovac
(
cls
.
db
())
log
.
info
(
"
[HIVE] db version: %d
"
,
cls
.
_ver
)
assert
cls
.
_ver
==
DB_VERSION
,
"
migration missing or invalid DB_VERSION
"
# Example migration:
#if cls._ver == 1:
...
...
This diff is collapsed.
Click to expand it.
hive/db/schema.py
+
38
−
31
View file @
03998f3f
...
...
@@ -10,7 +10,7 @@ from sqlalchemy.types import BOOLEAN
#pylint: disable=line-too-long, too-many-lines
DB_VERSION
=
6
DB_VERSION
=
12
def
build_metadata
():
"""
Build schema def with SqlAlchemy
"""
...
...
@@ -64,6 +64,8 @@ def build_metadata():
sa
.
Index
(
'
hive_accounts_ix1
'
,
'
vote_weight
'
,
'
id
'
),
# core: quick ranks
sa
.
Index
(
'
hive_accounts_ix2
'
,
'
name
'
,
'
id
'
),
# core: quick id map
sa
.
Index
(
'
hive_accounts_ix3
'
,
'
vote_weight
'
,
'
name
'
,
postgresql_ops
=
dict
(
name
=
'
varchar_pattern_ops
'
)),
# API: lookup
sa
.
Index
(
'
hive_accounts_ix4
'
,
'
id
'
,
'
name
'
),
# API: quick filter/sort
sa
.
Index
(
'
hive_accounts_ix5
'
,
'
cached_at
'
,
'
name
'
),
# core/listen sweep
mysql_engine
=
'
InnoDB
'
,
mysql_default_charset
=
'
utf8mb4
'
)
...
...
@@ -88,8 +90,8 @@ def build_metadata():
sa
.
ForeignKeyConstraint
([
'
community
'
],
[
'
hive_accounts.name
'
],
name
=
'
hive_posts_fk2
'
),
sa
.
ForeignKeyConstraint
([
'
parent_id
'
],
[
'
hive_posts.id
'
],
name
=
'
hive_posts_fk3
'
),
sa
.
UniqueConstraint
(
'
author
'
,
'
permlink
'
,
name
=
'
hive_posts_ux1
'
),
sa
.
Index
(
'
hive_posts_ix
1
'
,
'
parent_id
'
),
# API
sa
.
Index
(
'
hive_posts_ix
2
'
,
'
is_deleted
'
,
'
depth
'
),
# API
sa
.
Index
(
'
hive_posts_ix
3
'
,
'
author
'
,
'
depth
'
,
'
id
'
,
postgresql_where
=
sql_text
(
"
is_deleted =
'
0
'"
)),
# API: author blog/comments
sa
.
Index
(
'
hive_posts_ix
4
'
,
'
parent_id
'
,
'
id
'
,
postgresql_where
=
sql_text
(
"
is_deleted =
'
0
'"
)),
# API: fetching children
mysql_engine
=
'
InnoDB
'
,
mysql_default_charset
=
'
utf8mb4
'
)
...
...
@@ -121,9 +123,8 @@ def build_metadata():
sa
.
Column
(
'
created_at
'
,
sa
.
DateTime
,
nullable
=
False
),
sa
.
UniqueConstraint
(
'
following
'
,
'
follower
'
,
name
=
'
hive_follows_ux3
'
),
# core
sa
.
Index
(
'
hive_follows_ix2
'
,
'
following
'
,
'
follower
'
,
postgresql_where
=
sql_text
(
"
state = 1
"
)),
# API
sa
.
Index
(
'
hive_follows_ix3
'
,
'
follower
'
,
'
following
'
,
postgresql_where
=
sql_text
(
"
state = 1
"
)),
# API
sa
.
Index
(
'
hive_follows_ix4
'
,
'
follower
'
,
'
following
'
,
postgresql_where
=
sql_text
(
"
state = 2
"
)),
# API
sa
.
Index
(
'
hive_follows_ix5a
'
,
'
following
'
,
'
state
'
,
'
created_at
'
,
'
follower
'
),
sa
.
Index
(
'
hive_follows_ix5b
'
,
'
follower
'
,
'
state
'
,
'
created_at
'
,
'
following
'
),
mysql_engine
=
'
InnoDB
'
,
mysql_default_charset
=
'
utf8mb4
'
)
...
...
@@ -281,8 +282,14 @@ def build_metadata():
sa
.
Index
(
'
hive_posts_cache_ix2
'
,
'
promoted
'
,
postgresql_where
=
sql_text
(
"
is_paidout =
'
0
'
AND promoted > 0
"
)),
# API
sa
.
Index
(
'
hive_posts_cache_ix3
'
,
'
payout_at
'
,
'
post_id
'
,
postgresql_where
=
sql_text
(
"
is_paidout =
'
0
'"
)),
# core
sa
.
Index
(
'
hive_posts_cache_ix6
'
,
'
sc_trend
'
,
'
post_id
'
),
# API
sa
.
Index
(
'
hive_posts_cache_ix7
'
,
'
sc_hot
'
,
'
post_id
'
),
# API
sa
.
Index
(
'
hive_posts_cache_ix6a
'
,
'
sc_trend
'
,
'
post_id
'
,
postgresql_where
=
sql_text
(
"
is_paidout =
'
0
'"
)),
# API: global trending
sa
.
Index
(
'
hive_posts_cache_ix7a
'
,
'
sc_hot
'
,
'
post_id
'
,
postgresql_where
=
sql_text
(
"
is_paidout =
'
0
'"
)),
# API: global hot
sa
.
Index
(
'
hive_posts_cache_ix6b
'
,
'
post_id
'
,
'
sc_trend
'
,
postgresql_where
=
sql_text
(
"
is_paidout =
'
0
'"
)),
# API: filtered trending
sa
.
Index
(
'
hive_posts_cache_ix7b
'
,
'
post_id
'
,
'
sc_hot
'
,
postgresql_where
=
sql_text
(
"
is_paidout =
'
0
'"
)),
# API: filtered hot
sa
.
Index
(
'
hive_posts_cache_ix8
'
,
'
category
'
,
'
payout
'
,
'
depth
'
,
postgresql_where
=
sql_text
(
"
is_paidout =
'
0
'"
)),
# API: tag stats
sa
.
Index
(
'
hive_posts_cache_ix9a
'
,
'
depth
'
,
'
payout
'
,
'
post_id
'
,
postgresql_where
=
sql_text
(
"
is_paidout =
'
0
'"
)),
# API: payout
sa
.
Index
(
'
hive_posts_cache_ix9b
'
,
'
category
'
,
'
depth
'
,
'
payout
'
,
'
post_id
'
,
postgresql_where
=
sql_text
(
"
is_paidout =
'
0
'"
)),
# API: filtered payout
mysql_engine
=
'
InnoDB
'
,
mysql_default_charset
=
'
utf8mb4
'
)
...
...
@@ -326,26 +333,26 @@ def setup(db):
db
.
query
(
sql
)
def
reset_autovac
(
db
):
"""
Initializes per-table autovacuum/autoanalyze params
"""
# consider using scale_factor = 0 with flat thresholds:
# autovacuum_vacuum_threshold, autovacuum_analyze_threshold
autovac_config
=
{
# default
'
hive_accounts
'
:
(
0.2
,
0.1
),
'
hive_
state
'
:
(
0.2
,
0.1
),
'
hive_
reblog
s
'
:
(
0.2
,
0.1
),
'
hive_p
ayment
s
'
:
(
0.2
,
0.1
),
# more aggresive
'
hive_
posts
'
:
(
0.01
0
,
0
.
00
5
),
'
hive_
post_tags
'
:
(
0.010
,
0.
00
5
),
'
hive_
feed_cache
'
:
(
0.01
0
,
0
.
00
5
),
# very aggresive
'
hive_posts_cache
'
:
(
0.0050
,
0.0025
),
# @36M, ~2/day, 3/day (~240k new tuples daily)
'
hive_blocks
'
:
(
0.0100
,
0.0014
),
# @20M, ~1/week, 1/day
'
hive_follows
'
:
(
0.0050
,
0.0025
)}
# @47M, ~1/day, 3/day (~300k new tuples daily)
for
table
,
(
vacuum_sf
,
analyze_sf
)
in
autovac_config
.
items
():
sql
=
"""
ALTER TABLE %s SET (
autovacuum_
vacuum
_scale_factor =
%s
,
autovacuum_analyze_
scale_factor
= %s)
"""
db
.
query
(
sql
%
(
table
,
vacuum
_sf
,
analyze
_sf
))
"""
Initializes
/resets
per-table autovacuum/autoanalyze params
.
We use a scale factor of 0 and specify exact threshold tuple counts,
per-table, in the format (autovacuum_threshold, autoanalyze_threshold).
"""
autovac_config
=
{
# vacuum analyze
'
hive_accounts
'
:
(
50000
,
100000
),
'
hive_
posts_cache
'
:
(
25000
,
25000
),
'
hive_
post
s
'
:
(
2500
,
10000
),
'
hive_p
ost_tag
s
'
:
(
5000
,
10000
),
'
hive_follows
'
:
(
5000
,
5000
),
'
hive_
feed_cache
'
:
(
500
0
,
5
000
),
'
hive_
blocks
'
:
(
5000
,
250
00
),
'
hive_
reblogs
'
:
(
500
0
,
5
000
),
'
hive_payments
'
:
(
5000
,
5000
),
}
for
table
,
(
n_vacuum
,
n_analyze
)
in
autovac_config
.
items
():
sql
=
"""
ALTER TABLE %s SET (autovacuum_vacuum_scale_factor = 0,
autovacuum_vacuum_threshold = %s,
autovacuum_
analyze
_scale_factor =
0
,
autovacuum_analyze_
threshold
= %s)
"""
db
.
query
(
sql
%
(
table
,
n_
vacuum
,
n_
analyze
))
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