Files
@ e8e04440f196
Branch filter:
Location: EGD-mine/queries.py - annotation
e8e04440f196
7.8 KiB
text/x-python
dotaz timeToPeak
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 | 4ebd2c7c3657 4ebd2c7c3657 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 d72a89609095 d72a89609095 d72a89609095 d72a89609095 c41a90c1ee53 bc762fdfee0f c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 d72a89609095 d72a89609095 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 c41a90c1ee53 4ebd2c7c3657 e9a044cb8ce8 d72a89609095 d72a89609095 c41a90c1ee53 4ebd2c7c3657 e9a044cb8ce8 e9a044cb8ce8 c41a90c1ee53 e9a044cb8ce8 c41a90c1ee53 e9a044cb8ce8 4ebd2c7c3657 c41a90c1ee53 4ebd2c7c3657 6048d5c40c9b 4ebd2c7c3657 4ebd2c7c3657 6048d5c40c9b 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 6048d5c40c9b 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 4ebd2c7c3657 d72a89609095 bc762fdfee0f d72a89609095 d72a89609095 d72a89609095 e9a044cb8ce8 d72a89609095 d72a89609095 e9a044cb8ce8 e9a044cb8ce8 4ebd2c7c3657 4ebd2c7c3657 d72a89609095 d72a89609095 d72a89609095 d72a89609095 d72a89609095 d72a89609095 d72a89609095 6048d5c40c9b bc762fdfee0f 6127b170f21c 6127b170f21c 6127b170f21c 6127b170f21c 6127b170f21c 6127b170f21c 6127b170f21c 6127b170f21c 6127b170f21c 6127b170f21c 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 1765f32cd4dc 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b 6048d5c40c9b c41a90c1ee53 c41a90c1ee53 1765f32cd4dc bc762fdfee0f 9c927dc379bc 9c927dc379bc 9c927dc379bc 9c927dc379bc 9c927dc379bc 9c927dc379bc 9c927dc379bc 9c927dc379bc ed00726edba5 ed00726edba5 9c927dc379bc 4ebd2c7c3657 4ebd2c7c3657 1765f32cd4dc 9c927dc379bc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc 1765f32cd4dc c41a90c1ee53 c41a90c1ee53 051ee2d1dbdd bc762fdfee0f 8d852e1a7103 8d852e1a7103 8d852e1a7103 8d852e1a7103 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 6127b170f21c 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 051ee2d1dbdd 6127b170f21c 8732ad224e56 8732ad224e56 8732ad224e56 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 8732ad224e56 8732ad224e56 8732ad224e56 8732ad224e56 8732ad224e56 8732ad224e56 8732ad224e56 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 e8e04440f196 c41a90c1ee53 6127b170f21c 6048d5c40c9b 1765f32cd4dc 1765f32cd4dc 051ee2d1dbdd 8732ad224e56 e8e04440f196 | import sys
from egd import connection
cursor=connection.cursor()
def yearStart(year):
return "{0}-01-01".format(year)
def playerYear(name,year):
"""Výsledky hráče s daným jménem pro daný rok."""
query="""
select name, datum, win_count, game_count, rating_after, rating_after-rating_before
from players natural join players_performance as pp join tournaments as ts on pp.tournament_code=ts.code
where name=? and datum>=date(?) and datum<date(?)
order by datum asc
"""
date1=yearStart(year)
date2=yearStart(year+1)
res=cursor.execute(query,(name,date1,date2))
print("jméno\tdatum\tpočet výher\tpočet partií\trating po turnaji\tzměna")
for rec in res:
print("\t".join([str(x) for x in rec]))
def _yearByCountry(year):
"""Počty hráčů s turnajem odehraným v daném roce, dělené podle země původu. Při změně příslušnosti se hráč započítá oběma zemím."""
date1=yearStart(year)
date2=yearStart(year+1)
query="""
select p_country_code,count(pin) as player_count from (
select pin,count(*),p_country_code from
players_performance_tournaments
where datum>=date(?) and datum<date(?)
group by pin,p_country_code
)
group by p_country_code
order by p_country_code asc
"""
return cursor.execute(query,(date1,date2))
def yearsByCountry(year1,year2):
res=dict()
for year in range(year1,year2):
records=_yearByCountry(year)
for (countryCode,playerCount) in records:
if countryCode not in res:
res[countryCode]=dict()
res[countryCode][year]=playerCount
print("\r",year,end="",file=sys.stderr)
print("\r",end="",file=sys.stderr)
print("Počty aktivních hráčů podle let")
print("kód země\t"+"\t".join(str(y) for y in range(year1,year2)))
for countryCode in sorted(res.keys()):
print(countryCode,end="\t")
print("\t".join(str(res[countryCode].get(y,0)) for y in range(year1,year2)))
def timeRank(year,country):
"""Výpis hráčů dané země aktivních v daném roce."""
date1=yearStart(year)
date2=yearStart(year+1)
query="""
select ppt.pin,date(?)-min_datum-1,min_datum,ppt.rating_after as rating,name
from
(select pin,min(datum) as min_datum,max(datum) as max_datum from players_performance_tournaments where datum<date(?) group by pin having max_datum>=date(?)) as subq
join players_performance_tournaments as ppt on subq.pin=ppt.pin and subq.max_datum=ppt.datum natural join players
where ppt.p_country_code=?
order by rating desc
"""
res=cursor.execute(query,(date2,date2,date1,country))
print("pin\tcelé roky hraní\tprvní turnaj\trating")
for rec in res:
print("\t".join([str(x) for x in rec]))
def _populationStrength(year,country):
"""Rozdělení populace země v daném roce podle ratingu (po stovkách). Uvažují se pouze aktivní hráči."""
date1=yearStart(year)
date2=yearStart(year+1)
query="""
select round((rating_after-50)/100)*100 as rating, count(ppt.pin)
from players_performance_tournaments as ppt
join (select pin,max(datum) as max_datum from players_performance_tournaments where datum>=date(?) and datum<date(?) and p_country_code=? group by pin) as subq on ppt.pin=subq.pin and ppt.datum=subq.max_datum
group by rating
order by rating desc
"""
return cursor.execute(query,(date1,date2,country))
def populationStrength(year1,year2,country):
res=dict()
for year in range(year1,year2):
records=_populationStrength(year,country)
for (rating,playerCount) in records:
if rating not in res:
res[rating]=dict()
res[rating][year]=playerCount
print("\r",year,end="",file=sys.stderr)
print("\r",end="",file=sys.stderr)
print("Počty aktivních hráčů v {0} s uvedeným a vyšším ratingem".format(country))
print("rating\t"+"\t".join(str(y) for y in range(year1,year2)))
for rating in sorted(res.keys()):
print(rating,end="\t")
print("\t".join(str(res[rating].get(y,0)) for y in range(year1,year2)))
def _populationAge(year,country):
"""Rozdělení populace země v daném roce podle doby hraní (celých let od prvního turnaje). Uvažují se pouze aktivní hráči."""
date1=yearStart(year)
date2=yearStart(year+1)
query="""
select date(?)-min_datum-1 as playing_years,count(pin)
from (
select ppt1.pin,min(ppt1.datum) as min_datum
from players_performance_tournaments as ppt1
join players_performance_tournaments as ppt2 on ppt1.pin=ppt2.pin
where ppt2.datum>=date(?) and ppt2.datum<date(?) and ppt2.p_country_code=?
group by ppt2.pin
)
group by playing_years
"""
return cursor.execute(query,(date2,date1,date2,country))
def populationAge(year1,year2,country):
res=dict()
for year in range(year1,year2):
records=_populationAge(year,country)
for (age,playerCount) in records:
if age not in res:
res[age]=dict()
res[age][year]=playerCount
print("\r",year,end="",file=sys.stderr)
print("\r",end="",file=sys.stderr)
print("Počty aktivních hráčů v {0} hrajících tolik a více let".format(country))
print("roky hraní\t"+"\t".join(str(y) for y in range(year1,year2)))
for age in sorted(res.keys()):
print(age,end="\t")
print("\t".join(str(res[age].get(y,0)) for y in range(year1,year2)))
def _tournamentAttendance(year):
"""Návštěvnosti turnajů za daný rok, dělené podle země konání."""
date1=yearStart(year)
date2=yearStart(year+1)
query="""select country_code,sum(player_count) from tournaments where datum>=date(?) and datum<date(?) group by country_code"""
return cursor.execute(query,(date1,date2))
def tournamentAttendance(year1,year2):
res=dict()
for year in range(year1,year2):
records=_tournamentAttendance(year)
for (country,attendance) in records:
if country not in res:
res[country]=dict()
res[country][year]=attendance
print("\r",year,end="",file=sys.stderr)
print("\r",end="",file=sys.stderr)
print("Návštěvnosti (počty hráčů) na turnajích podle let")
print("kód země\t"+"\t".join(str(y) for y in range(year1,year2)))
for country in sorted(res.keys()):
print(country,end="\t")
print("\t".join(str(res[country].get(y,0)) for y in range(year1,year2)))
def fetchByRating(strongerThan,country=""):
"""Hráči, kteří dosáhli rating strongerThan nebo vyšší, nepovinně filtrovaní podle země, seřazení od nejlepšího dosaženého ratingu."""
query="""
select pin,name,max(rating_after) as max_rating
from players_performance natural join players
where rating_after>=? and (?='' or country_code=?)
group by pin
order by max_rating desc"""
res=cursor.execute(query,(strongerThan,country,country))
print("pin\tjméno\tmax rating")
for rec in res:
print("\t".join([str(x) for x in rec]))
def timeToPeak():
"""Jakého hráči dosáhli maximálního ratingu a jak dlouho jim to trvalo.
Uvažuje hráče začínající s ratingem<=600 a s vrcholem před 1.1.2017."""
# join on pin, max_rating může duplikovat řádky, když měl hráč stejný max_rating vícekrát.
# proto ten ošklivý vnější group by :-ú
query="""
select subq.pin,min(min_rating),min(max_rating),min(_min_datum) as min_datum,min(datum) as peak_datum,min(datum)-min(_min_datum) as time_to_peak
from players_performance_tournaments as ppt
join (select pin,min(rating_before) as min_rating,max(rating_after) as max_rating,min(datum) as _min_datum from players_performance_tournaments group by pin having min_rating<=600) as subq on ppt.pin=subq.pin and ppt.rating_after=max_rating
group by ppt.pin
having peak_datum<date('2017-01-01')
"""
res=cursor.execute(query)
print("pin\tmin rating\tmax rating\tprvní turnaj\tdosažení max ratingu\troky k max ratingu")
for rec in res:
print("\t".join([str(x) for x in rec]))
# playerYear("Kotowski Jaroslav",2017)
# timeRank(2017,"CZ")
# yearsByCountry(2001,2018)
# populationStrength(2001,2018,"RU")
# populationAge(2001,2018,"RU")
# tournamentAttendance(2001,2018)
# fetchByRating(2600,"CZ")
# timeToPeak()
|