dbinit.py revision 1758:74acd5b23964
18981Sandreas.hansson@arm.com
214208Sandreas.sandberg@arm.com# Copyright (c) 2003-2004 The Regents of The University of Michigan
311804Srjthakur@google.com# All rights reserved.
411904Spierre-yves.peneau@lirmm.fr#
511804Srjthakur@google.com# Redistribution and use in source and binary forms, with or without
68981Sandreas.hansson@arm.com# modification, are permitted provided that the following conditions are
78981Sandreas.hansson@arm.com# met: redistributions of source code must retain the above copyright
88981Sandreas.hansson@arm.com# notice, this list of conditions and the following disclaimer;
98981Sandreas.hansson@arm.com# redistributions in binary form must reproduce the above copyright
108981Sandreas.hansson@arm.com# notice, this list of conditions and the following disclaimer in the
118981Sandreas.hansson@arm.com# documentation and/or other materials provided with the distribution;
128981Sandreas.hansson@arm.com# neither the name of the copyright holders nor the names of its
138981Sandreas.hansson@arm.com# contributors may be used to endorse or promote products derived from
148981Sandreas.hansson@arm.com# this software without specific prior written permission.
158981Sandreas.hansson@arm.com#
168981Sandreas.hansson@arm.com# THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS
178981Sandreas.hansson@arm.com# "AS IS" AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT
188981Sandreas.hansson@arm.com# LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR
198981Sandreas.hansson@arm.com# A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT
208981Sandreas.hansson@arm.com# OWNER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL,
218981Sandreas.hansson@arm.com# SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT
228981Sandreas.hansson@arm.com# LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE,
238981Sandreas.hansson@arm.com# DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY
248981Sandreas.hansson@arm.com# THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT
258981Sandreas.hansson@arm.com# (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE
268981Sandreas.hansson@arm.com# OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
278981Sandreas.hansson@arm.com
288981Sandreas.hansson@arm.com#Permission is granted to use, copy, create derivative works and
298981Sandreas.hansson@arm.com#redistribute this software and such derivative works for any purpose,
308981Sandreas.hansson@arm.com#so long as the copyright notice above, this grant of permission, and
318981Sandreas.hansson@arm.com#the disclaimer below appear in all copies made; and so long as the
328981Sandreas.hansson@arm.com#name of The University of Michigan is not used in any advertising or
338981Sandreas.hansson@arm.com#publicity pertaining to the use or distribution of this software
348981Sandreas.hansson@arm.com#without specific, written prior authorization.
358981Sandreas.hansson@arm.com#
368981Sandreas.hansson@arm.com#THIS SOFTWARE IS PROVIDED AS IS, WITHOUT REPRESENTATION FROM THE
378981Sandreas.hansson@arm.com#UNIVERSITY OF MICHIGAN AS TO ITS FITNESS FOR ANY PURPOSE, AND WITHOUT
388981Sandreas.hansson@arm.com#WARRANTY BY THE UNIVERSITY OF MICHIGAN OF ANY KIND, EITHER EXPRESS OR
398981Sandreas.hansson@arm.com#IMPLIED, INCLUDING WITHOUT LIMITATION THE IMPLIED WARRANTIES OF
408981Sandreas.hansson@arm.com#MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE REGENTS OF
4111804Srjthakur@google.com#THE UNIVERSITY OF MICHIGAN SHALL NOT BE LIABLE FOR ANY DAMAGES,
4211904Spierre-yves.peneau@lirmm.fr#INCLUDING DIRECT, SPECIAL, INDIRECT, INCIDENTAL, OR CONSEQUENTIAL
438981Sandreas.hansson@arm.com#DAMAGES, WITH RESPECT TO ANY CLAIM ARISING OUT OF OR IN CONNECTION
448981Sandreas.hansson@arm.com#WITH THE USE OF THE SOFTWARE, EVEN IF IT HAS BEEN OR IS HEREAFTER
4511793Sbrandon.potter@amd.com#ADVISED OF THE POSSIBILITY OF SUCH DAMAGES.
4611793Sbrandon.potter@amd.com
479356Snilay@cs.wisc.eduimport MySQLdb
488981Sandreas.hansson@arm.com
498981Sandreas.hansson@arm.comclass MyDB(object):
508981Sandreas.hansson@arm.com    def __init__(self, options):
518981Sandreas.hansson@arm.com        self.name = options.db
5213892Sgabeblack@google.com        self.host = options.host
538981Sandreas.hansson@arm.com        self.user = options.user
548981Sandreas.hansson@arm.com        self.passwd = options.passwd
5512084Sspwilson2@wisc.edu        self.mydb = None
568981Sandreas.hansson@arm.com        self.cursor = None
5710902Sandreas.sandberg@arm.com
5814208Sandreas.sandberg@arm.com    def admin(self):
598981Sandreas.hansson@arm.com        self.close()
608981Sandreas.hansson@arm.com        self.mydb = MySQLdb.connect(db='mysql', host=self.host, user=self.user,
6110064Sandreas.hansson@arm.com                                    passwd=self.passwd)
6210902Sandreas.sandberg@arm.com        self.cursor = self.mydb.cursor()
638981Sandreas.hansson@arm.com
648981Sandreas.hansson@arm.com    def connect(self):
658981Sandreas.hansson@arm.com        self.close()
668981Sandreas.hansson@arm.com        self.mydb = MySQLdb.connect(db=self.name, host=self.host,
678981Sandreas.hansson@arm.com                                    user=self.user, passwd=self.passwd)
688981Sandreas.hansson@arm.com        self.cursor = self.mydb.cursor()
698981Sandreas.hansson@arm.com
708981Sandreas.hansson@arm.com    def close(self):
718981Sandreas.hansson@arm.com        if self.mydb is not None:
728981Sandreas.hansson@arm.com            self.mydb.close()
738981Sandreas.hansson@arm.com        self.cursor = None
748981Sandreas.hansson@arm.com
758981Sandreas.hansson@arm.com    def query(self, sql):
768981Sandreas.hansson@arm.com        self.cursor.execute(sql)
778981Sandreas.hansson@arm.com
788981Sandreas.hansson@arm.com    def drop(self):
7910994Sandreas.sandberg@arm.com        self.query('DROP DATABASE IF EXISTS %s' % self.name)
8010994Sandreas.sandberg@arm.com
8110994Sandreas.sandberg@arm.com    def create(self):
8210994Sandreas.sandberg@arm.com        self.query('CREATE DATABASE %s' % self.name)
8310994Sandreas.sandberg@arm.com
8410994Sandreas.sandberg@arm.com    def populate(self):
8510994Sandreas.sandberg@arm.com        #
8613784Sgabeblack@google.com        # Each run (or simulation) gets its own entry in the runs table to
8713784Sgabeblack@google.com        # group stats by where they were generated
888981Sandreas.hansson@arm.com        #
898981Sandreas.hansson@arm.com        # COLUMNS:
908981Sandreas.hansson@arm.com        #   'id' is a unique identifier for each run to be used in other
9113784Sgabeblack@google.com        #       tables.
928981Sandreas.hansson@arm.com        #   'name' is the user designated name for the data generated.  It is
938981Sandreas.hansson@arm.com        #       configured in the simulator.
9413892Sgabeblack@google.com        #   'user' identifies the user that generated the data for the given
958981Sandreas.hansson@arm.com        #       run.
968981Sandreas.hansson@arm.com        #   'project' another name to identify runs for a specific goal
978981Sandreas.hansson@arm.com        #   'date' is a timestamp for when the data was generated.  It can be
988981Sandreas.hansson@arm.com        #       used to easily expire data that was generated in the past.
998981Sandreas.hansson@arm.com        #   'expire' is a timestamp for when the data should be removed from
1008981Sandreas.hansson@arm.com        #       the database so we don't have years worth of junk.
1018981Sandreas.hansson@arm.com        #
1028981Sandreas.hansson@arm.com        # INDEXES:
1038981Sandreas.hansson@arm.com        #   'run' is indexed so you can find out details of a run if the run
1048981Sandreas.hansson@arm.com        #       was retreived from the data table.
1058981Sandreas.hansson@arm.com        #   'name' is indexed so that two all run names are forced to be unique
1068981Sandreas.hansson@arm.com        #
1078981Sandreas.hansson@arm.com        self.query('''
1088981Sandreas.hansson@arm.com        CREATE TABLE runs(
1098981Sandreas.hansson@arm.com            rn_id	SMALLINT UNSIGNED	NOT NULL AUTO_INCREMENT,
11014208Sandreas.sandberg@arm.com            rn_name	VARCHAR(200)		NOT NULL,
11114208Sandreas.sandberg@arm.com            rn_sample	VARCHAR(32)		NOT NULL,
11214208Sandreas.sandberg@arm.com            rn_user	VARCHAR(32)		NOT NULL,
11314208Sandreas.sandberg@arm.com            rn_project	VARCHAR(100)            NOT NULL,
11414208Sandreas.sandberg@arm.com            rn_date	TIMESTAMP		NOT NULL,
11514208Sandreas.sandberg@arm.com            rn_expire	TIMESTAMP               NOT NULL,
11614208Sandreas.sandberg@arm.com            PRIMARY KEY (rn_id),
11714208Sandreas.sandberg@arm.com            UNIQUE (rn_name,rn_sample)
11814208Sandreas.sandberg@arm.com        ) TYPE=InnoDB''')
11914208Sandreas.sandberg@arm.com
12014208Sandreas.sandberg@arm.com        #
12114208Sandreas.sandberg@arm.com        # We keep the bin names separate so that the data table doesn't get
12214208Sandreas.sandberg@arm.com        # huge since bin names are frequently repeated.
12314208Sandreas.sandberg@arm.com        #
12414208Sandreas.sandberg@arm.com        # COLUMNS:
12514208Sandreas.sandberg@arm.com        #   'id' is the unique bin identifer.
12614208Sandreas.sandberg@arm.com        #   'name' is the string name for the bin.
12714208Sandreas.sandberg@arm.com        #
12814208Sandreas.sandberg@arm.com        # INDEXES:
12914208Sandreas.sandberg@arm.com        #   'bin' is indexed to get the name of a bin when data is retrieved
13014208Sandreas.sandberg@arm.com        #       via the data table.
13114208Sandreas.sandberg@arm.com        #   'name' is indexed to get the bin id for a named bin when you want
13214208Sandreas.sandberg@arm.com        #       to search the data table based on a specific bin.
13314208Sandreas.sandberg@arm.com        #
13414208Sandreas.sandberg@arm.com        self.query('''
13514208Sandreas.sandberg@arm.com        CREATE TABLE bins(
13614208Sandreas.sandberg@arm.com            bn_id	SMALLINT UNSIGNED	NOT NULL AUTO_INCREMENT,
13714208Sandreas.sandberg@arm.com            bn_name	VARCHAR(255)		NOT NULL,
13814208Sandreas.sandberg@arm.com            PRIMARY KEY(bn_id),
13914208Sandreas.sandberg@arm.com            UNIQUE (bn_name)
14014208Sandreas.sandberg@arm.com        ) TYPE=InnoDB''')
14114208Sandreas.sandberg@arm.com
14214208Sandreas.sandberg@arm.com        #
14314208Sandreas.sandberg@arm.com        # The stat table gives us all of the data for a particular stat.
14414208Sandreas.sandberg@arm.com        #
14514208Sandreas.sandberg@arm.com        # COLUMNS:
14614208Sandreas.sandberg@arm.com        #   'stat' is a unique identifier for each stat to be used in other
14714208Sandreas.sandberg@arm.com        #       tables for references.
14814208Sandreas.sandberg@arm.com        #   'name' is simply the simulator derived name for a given
14914208Sandreas.sandberg@arm.com        #       statistic.
15014208Sandreas.sandberg@arm.com        #   'descr' is the description of the statistic and what it tells
15114208Sandreas.sandberg@arm.com        #       you.
15214208Sandreas.sandberg@arm.com        #   'type' defines what the stat tells you.  Types are:
15314208Sandreas.sandberg@arm.com        #       SCALAR: A simple scalar statistic that holds one value
15414208Sandreas.sandberg@arm.com        #       VECTOR: An array of statistic values.  Such a something that
15514208Sandreas.sandberg@arm.com        #           is generated per-thread.  Vectors exist to give averages,
15614208Sandreas.sandberg@arm.com        #	     pdfs, cdfs, means, standard deviations, etc across the
15714208Sandreas.sandberg@arm.com        #           stat values.
15814208Sandreas.sandberg@arm.com        #       DIST: Is a distribution of data.  When the statistic value is
15914208Sandreas.sandberg@arm.com        #	     sampled, its value is counted in a particular bucket.
16014208Sandreas.sandberg@arm.com        #           Useful for keeping track of utilization of a resource.
16114208Sandreas.sandberg@arm.com        #           (e.g. fraction of time it is 25% used vs. 50% vs. 100%)
16214208Sandreas.sandberg@arm.com        #       VECTORDIST: Can be used when the distribution needs to be
16314208Sandreas.sandberg@arm.com        #	     factored out into a per-thread distribution of data for
16414208Sandreas.sandberg@arm.com        #	     example.  It can still be summed across threads to find
16514208Sandreas.sandberg@arm.com        #           the total distribution.
16614208Sandreas.sandberg@arm.com        #       VECTOR2D: Can be used when you have a stat that is not only
16714208Sandreas.sandberg@arm.com        #           per-thread, but it is per-something else.  Like
16814208Sandreas.sandberg@arm.com        #           per-message type.
16914208Sandreas.sandberg@arm.com        #       FORMULA: This statistic is a formula, and its data must be
17014208Sandreas.sandberg@arm.com        #	     looked up in the formula table, for indicating how to
17114208Sandreas.sandberg@arm.com        #           present its values.
17214208Sandreas.sandberg@arm.com        #   'subdata' is potentially used by any of the vector types to
17314208Sandreas.sandberg@arm.com        #       give a specific name to all of the data elements within a
17414208Sandreas.sandberg@arm.com        #       stat.
17514208Sandreas.sandberg@arm.com        #   'print' indicates whether this stat should be printed ever.
17614208Sandreas.sandberg@arm.com        #       (Unnamed stats don't usually get printed)
17714208Sandreas.sandberg@arm.com        #   'prereq' only print the stat if the prereq is not zero.
17814208Sandreas.sandberg@arm.com        #   'prec' number of decimal places to print
17914208Sandreas.sandberg@arm.com        #   'nozero' don't print zero values
18014208Sandreas.sandberg@arm.com        #   'nonan' don't print NaN values
18114208Sandreas.sandberg@arm.com        #   'total' for vector type stats, print the total.
18214208Sandreas.sandberg@arm.com        #   'pdf' for vector type stats, print the pdf.
18314208Sandreas.sandberg@arm.com        #   'cdf' for vector type stats, print the cdf.
18414208Sandreas.sandberg@arm.com        #
18514208Sandreas.sandberg@arm.com        #   The Following are for dist type stats:
18614208Sandreas.sandberg@arm.com        #   'min' is the minimum bucket value. Anything less is an underflow.
18714208Sandreas.sandberg@arm.com        #   'max' is the maximum bucket value. Anything more is an overflow.
18814208Sandreas.sandberg@arm.com        #   'bktsize' is the approximate number of entries in each bucket.
18914208Sandreas.sandberg@arm.com        #   'size' is the number of buckets. equal to (min/max)/bktsize.
19014208Sandreas.sandberg@arm.com        #
19114208Sandreas.sandberg@arm.com        # INDEXES:
19214208Sandreas.sandberg@arm.com        #   'stat' is indexed so that you can find out details about a stat
19314208Sandreas.sandberg@arm.com        #       if the stat id was retrieved from the data table.
19414208Sandreas.sandberg@arm.com        #   'name' is indexed so that you can simply look up data about a
19514208Sandreas.sandberg@arm.com        #       named stat.
19614208Sandreas.sandberg@arm.com        #
19714208Sandreas.sandberg@arm.com        self.query('''
19814208Sandreas.sandberg@arm.com        CREATE TABLE stats(
19914208Sandreas.sandberg@arm.com            st_id	SMALLINT UNSIGNED	NOT NULL AUTO_INCREMENT,
20014208Sandreas.sandberg@arm.com            st_name	VARCHAR(255)		NOT NULL,
20114208Sandreas.sandberg@arm.com            st_descr	TEXT			NOT NULL,
20214208Sandreas.sandberg@arm.com            st_type	ENUM("SCALAR", "VECTOR", "DIST", "VECTORDIST",
20314208Sandreas.sandberg@arm.com                "VECTOR2D", "FORMULA")	NOT NULL,
20414208Sandreas.sandberg@arm.com            st_print	BOOL			NOT NULL,
20514208Sandreas.sandberg@arm.com            st_prereq	SMALLINT UNSIGNED	NOT NULL,
20614208Sandreas.sandberg@arm.com            st_prec	TINYINT			NOT NULL,
20714208Sandreas.sandberg@arm.com            st_nozero	BOOL			NOT NULL,
20814208Sandreas.sandberg@arm.com            st_nonan	BOOL			NOT NULL,
20914208Sandreas.sandberg@arm.com            st_total	BOOL			NOT NULL,
21014208Sandreas.sandberg@arm.com            st_pdf	BOOL			NOT NULL,
21114208Sandreas.sandberg@arm.com            st_cdf	BOOL			NOT NULL,
21214208Sandreas.sandberg@arm.com            st_min	DOUBLE			NOT NULL,
21314208Sandreas.sandberg@arm.com            st_max	DOUBLE			NOT NULL,
21414208Sandreas.sandberg@arm.com            st_bktsize	DOUBLE			NOT NULL,
21514208Sandreas.sandberg@arm.com            st_size	SMALLINT UNSIGNED	NOT NULL,
21614208Sandreas.sandberg@arm.com            PRIMARY KEY (st_id),
21714208Sandreas.sandberg@arm.com            UNIQUE (st_name)
21814208Sandreas.sandberg@arm.com        ) TYPE=InnoDB''')
21914208Sandreas.sandberg@arm.com
22014208Sandreas.sandberg@arm.com        #
22114208Sandreas.sandberg@arm.com        # This is the main table of data for stats.
22214208Sandreas.sandberg@arm.com        #
22314208Sandreas.sandberg@arm.com        # COLUMNS:
22414208Sandreas.sandberg@arm.com        #   'stat' refers to the stat field given in the stat table.
22514208Sandreas.sandberg@arm.com        #
22614208Sandreas.sandberg@arm.com        #   'x' referrs to the first dimension of a multi-dimensional stat. For
22714208Sandreas.sandberg@arm.com        #       a vector, x will start at 0 and increase for each vector
22814208Sandreas.sandberg@arm.com        #       element.
22914208Sandreas.sandberg@arm.com        #       For a distribution:
23014208Sandreas.sandberg@arm.com        #       -1: sum (for calculating standard deviation)
23114208Sandreas.sandberg@arm.com        #       -2: sum of squares (for calculating standard deviation)
23214208Sandreas.sandberg@arm.com        #       -3: total number of samples taken (for calculating
23314208Sandreas.sandberg@arm.com        #           standard deviation)
23414208Sandreas.sandberg@arm.com        #       -4: minimum value
23514208Sandreas.sandberg@arm.com        #       -5: maximum value
23614208Sandreas.sandberg@arm.com        #       -6: underflow
23714208Sandreas.sandberg@arm.com        #       -7: overflow
23814208Sandreas.sandberg@arm.com        #   'y' is used by a VECTORDIST and the VECTOR2D to describe the second
23914208Sandreas.sandberg@arm.com        #       dimension.
24014208Sandreas.sandberg@arm.com        #   'run' is the run that the data was generated from.  Details up in
24114208Sandreas.sandberg@arm.com        #       the run table
24214208Sandreas.sandberg@arm.com        #   'tick' is a timestamp generated by the simulator.
24314208Sandreas.sandberg@arm.com        #   'bin' is the name of the bin that the data was generated in, if
24414208Sandreas.sandberg@arm.com        #       any.
24511804Srjthakur@google.com        #   'data' is the actual stat value.
24611804Srjthakur@google.com        #
24711804Srjthakur@google.com        # INDEXES:
24811804Srjthakur@google.com        #   'stat' is indexed so that a user can find all of the data for a
24911804Srjthakur@google.com        #       particular stat. It is not unique, because that specific stat
25011804Srjthakur@google.com        #       can be found in many runs, bins, and samples, in addition to
25111804Srjthakur@google.com        #       having entries for the mulidimensional cases.
25211804Srjthakur@google.com        #   'run' is indexed to allow a user to remove all of the data for a
25311804Srjthakur@google.com        #       particular execution run.  It can also be used to allow the
25411804Srjthakur@google.com        #       user to print out all of the data for a given run.
25511804Srjthakur@google.com        #
25611804Srjthakur@google.com        self.query('''
25711804Srjthakur@google.com        CREATE TABLE data(
25811804Srjthakur@google.com            dt_stat	SMALLINT UNSIGNED	NOT NULL,
25911804Srjthakur@google.com            dt_x	SMALLINT		NOT NULL,
26011804Srjthakur@google.com            dt_y	SMALLINT		NOT NULL,
26111804Srjthakur@google.com            dt_run	SMALLINT UNSIGNED	NOT NULL,
26211804Srjthakur@google.com            dt_tick	BIGINT UNSIGNED		NOT NULL,
26311804Srjthakur@google.com            dt_bin	SMALLINT UNSIGNED	NOT NULL,
26411804Srjthakur@google.com            dt_data	DOUBLE			NOT NULL,
26511804Srjthakur@google.com            INDEX (dt_stat),
26611804Srjthakur@google.com            INDEX (dt_run),
26711804Srjthakur@google.com            UNIQUE (dt_stat,dt_x,dt_y,dt_run,dt_tick,dt_bin)
26811804Srjthakur@google.com        ) TYPE=InnoDB;''')
26911804Srjthakur@google.com
27011804Srjthakur@google.com        #
27111804Srjthakur@google.com        # Names and descriptions for multi-dimensional stats (vectors, etc.)
27211804Srjthakur@google.com        # are stored here instead of having their own entry in the statistics
27311804Srjthakur@google.com        # table. This allows all parts of a single stat to easily share a
27411804Srjthakur@google.com        # single id.
27511804Srjthakur@google.com        #
27611804Srjthakur@google.com        # COLUMNS:
27711804Srjthakur@google.com        #   'stat' is the unique stat identifier from the stat table.
27811804Srjthakur@google.com        #   'x' is the first dimension for multi-dimensional stats
27911804Srjthakur@google.com        #       corresponding to the data table above.
28011804Srjthakur@google.com        #   'y' is the second dimension for multi-dimensional stats
28111804Srjthakur@google.com        #       corresponding to the data table above.
28211804Srjthakur@google.com        #   'name' is the specific subname for the unique stat,x,y combination.
28311804Srjthakur@google.com        #   'descr' is the specific description for the uniqe stat,x,y
28411804Srjthakur@google.com        #        combination.
28511804Srjthakur@google.com        #
28611804Srjthakur@google.com        # INDEXES:
28711804Srjthakur@google.com        #   'stat' is indexed so you can get the subdata for a specific stat.
28811804Srjthakur@google.com        #
28911804Srjthakur@google.com        self.query('''
29011804Srjthakur@google.com        CREATE TABLE subdata(
29111804Srjthakur@google.com            sd_stat	SMALLINT UNSIGNED	NOT NULL,
29211804Srjthakur@google.com            sd_x	SMALLINT		NOT NULL,
29311804Srjthakur@google.com            sd_y	SMALLINT		NOT NULL,
29411804Srjthakur@google.com            sd_name	VARCHAR(255)		NOT NULL,
29511804Srjthakur@google.com            sd_descr	TEXT,
29611804Srjthakur@google.com            UNIQUE (sd_stat,sd_x,sd_y)
29711804Srjthakur@google.com        ) TYPE=InnoDB''')
29811804Srjthakur@google.com
29911804Srjthakur@google.com
30011804Srjthakur@google.com        #
30111804Srjthakur@google.com        # The formula table is maintained separately from the data table
30211804Srjthakur@google.com        # because formula data, unlike other stat data cannot be represented
30311804Srjthakur@google.com        # there.
30411804Srjthakur@google.com        #
30511804Srjthakur@google.com        # COLUMNS:
30611804Srjthakur@google.com        #   'stat' refers to the stat field generated in the stat table.
30711804Srjthakur@google.com        #   'formula' is the actual string representation of the formula
30811804Srjthakur@google.com        #       itself.
30911804Srjthakur@google.com        #
31011804Srjthakur@google.com        # INDEXES:
31111804Srjthakur@google.com        #   'stat' is indexed so that you can just look up a formula.
31211804Srjthakur@google.com        #
31311804Srjthakur@google.com        self.query('''
31411804Srjthakur@google.com        CREATE TABLE formulas(
31511804Srjthakur@google.com            fm_stat	SMALLINT UNSIGNED	NOT NULL,
31611804Srjthakur@google.com            fm_formula	BLOB			NOT NULL,
31711804Srjthakur@google.com            PRIMARY KEY(fm_stat)
31811804Srjthakur@google.com        ) TYPE=InnoDB''')
31911804Srjthakur@google.com
32011804Srjthakur@google.com        #
32111804Srjthakur@google.com        # Each stat used in each formula is kept in this table.  This way, if
32211804Srjthakur@google.com        # you want to print out a particular formula, you can simply find out
32311804Srjthakur@google.com        # which stats you need by looking in this table.  Additionally, when
32411804Srjthakur@google.com        # you remove a stat from the stats table and data table, you remove
32511804Srjthakur@google.com        # any references to the formula in this table.  When a formula is no
32611804Srjthakur@google.com        # longer referred to, you remove its entry.
32711804Srjthakur@google.com        #
32811804Srjthakur@google.com        # COLUMNS:
32911804Srjthakur@google.com        #   'stat' is the stat id from the stat table above.
33011804Srjthakur@google.com        #   'child' is the stat id of a stat that is used for this formula.
33111804Srjthakur@google.com        #       There may be many children for any given 'stat' (formula)
33211804Srjthakur@google.com        #
33311804Srjthakur@google.com        # INDEXES:
33411804Srjthakur@google.com        #   'stat' is indexed so you can look up all of the children for a
33511804Srjthakur@google.com        #       particular stat.
33611804Srjthakur@google.com        #   'child' is indexed so that you can remove an entry when a stat is
33711804Srjthakur@google.com        #       removed.
33811804Srjthakur@google.com        #
33911804Srjthakur@google.com        self.query('''
34011804Srjthakur@google.com        CREATE TABLE formula_ref(
34111804Srjthakur@google.com            fr_stat	SMALLINT UNSIGNED	NOT NULL,
34211804Srjthakur@google.com            fr_run	SMALLINT UNSIGNED	NOT NULL,
34311804Srjthakur@google.com            UNIQUE (fr_stat,fr_run),
3448981Sandreas.hansson@arm.com            INDEX (fr_stat),
3458981Sandreas.hansson@arm.com            INDEX (fr_run)
3468981Sandreas.hansson@arm.com        ) TYPE=InnoDB''')
34711804Srjthakur@google.com
34811804Srjthakur@google.com        # COLUMNS:
34911139Sandreas.hansson@arm.com        #   'event' is the unique event id from the event_desc table
35011139Sandreas.hansson@arm.com        #   'run' is simulation run id that this event took place in
35110994Sandreas.sandberg@arm.com        #   'tick' is the tick when the event happened
35210994Sandreas.sandberg@arm.com        #
35311804Srjthakur@google.com        # INDEXES:
35411804Srjthakur@google.com        #   'event' is indexed so you can look up all occurences of a
35511804Srjthakur@google.com        #       specific event
35611804Srjthakur@google.com        #   'run' is indexed so you can find all events in a run
35711804Srjthakur@google.com        #   'tick' is indexed because we want the unique thing anyway
35814084Schunchenhsu@google.com        #   'event,run,tick' is unique combination
35914084Schunchenhsu@google.com        self.query('''
36011139Sandreas.hansson@arm.com        CREATE TABLE events(
36111139Sandreas.hansson@arm.com            ev_event	SMALLINT UNSIGNED	NOT NULL,
36210994Sandreas.sandberg@arm.com            ev_run	SMALLINT UNSIGNED	NOT NULL,
3638981Sandreas.hansson@arm.com            ev_tick	BIGINT   UNSIGNED       NOT NULL,
3648981Sandreas.hansson@arm.com            INDEX(ev_event),
3658981Sandreas.hansson@arm.com            INDEX(ev_run),
3668981Sandreas.hansson@arm.com            INDEX(ev_tick),
3678981Sandreas.hansson@arm.com            UNIQUE(ev_event,ev_run,ev_tick)
3688981Sandreas.hansson@arm.com        ) TYPE=InnoDB''')
3698981Sandreas.hansson@arm.com
3708981Sandreas.hansson@arm.com        # COLUMNS:
3718981Sandreas.hansson@arm.com        #   'id' is the unique description id
3728981Sandreas.hansson@arm.com        #   'name' is the name of the event that occurred
3738981Sandreas.hansson@arm.com        #
3748981Sandreas.hansson@arm.com        # INDEXES:
3758981Sandreas.hansson@arm.com        #   'id' is indexed because it is the primary key and is what you use
3768981Sandreas.hansson@arm.com        #       to look up the descriptions
3778981Sandreas.hansson@arm.com        #   'name' is indexed so one can find the event based on name
3788981Sandreas.hansson@arm.com        #
37911139Sandreas.hansson@arm.com        self.query('''
38011139Sandreas.hansson@arm.com        CREATE TABLE event_names(
38111804Srjthakur@google.com            en_id	SMALLINT UNSIGNED	NOT NULL AUTO_INCREMENT,
38211804Srjthakur@google.com            en_name	VARCHAR(255)		NOT NULL,
3838981Sandreas.hansson@arm.com            PRIMARY KEY (en_id),
3848981Sandreas.hansson@arm.com            UNIQUE (en_name)
3858981Sandreas.hansson@arm.com        ) TYPE=InnoDB''')
38611284Sandreas.hansson@arm.com
38711284Sandreas.hansson@arm.com    def clean(self):
3889785Sandreas.hansson@arm.com        self.query('''
3899542Sandreas.hansson@arm.com        DELETE data
3908981Sandreas.hansson@arm.com        FROM data
3918981Sandreas.hansson@arm.com        LEFT JOIN runs ON dt_run=rn_id
39211284Sandreas.hansson@arm.com        WHERE rn_id IS NULL''')
3938981Sandreas.hansson@arm.com
3948981Sandreas.hansson@arm.com        self.query('''
3958981Sandreas.hansson@arm.com        DELETE formula_ref
3969785Sandreas.hansson@arm.com        FROM formula_ref
3979542Sandreas.hansson@arm.com        LEFT JOIN runs ON fr_run=rn_id
3988981Sandreas.hansson@arm.com        WHERE rn_id IS NULL''')
3998981Sandreas.hansson@arm.com
40010994Sandreas.sandberg@arm.com        self.query('''
40111139Sandreas.hansson@arm.com        DELETE formulas
40210994Sandreas.sandberg@arm.com        FROM formulas
40310994Sandreas.sandberg@arm.com        LEFT JOIN formula_ref ON fm_stat=fr_stat
40411804Srjthakur@google.com        WHERE fr_stat IS NULL''')
40511847Spierre-yves.peneau@lirmm.fr
40611847Spierre-yves.peneau@lirmm.fr        self.query('''
40711804Srjthakur@google.com        DELETE stats
4088981Sandreas.hansson@arm.com        FROM stats
4098981Sandreas.hansson@arm.com        LEFT JOIN data ON st_id=dt_stat
4108981Sandreas.hansson@arm.com        WHERE dt_stat IS NULL''')
4118981Sandreas.hansson@arm.com
4128981Sandreas.hansson@arm.com        self.query('''
4138981Sandreas.hansson@arm.com        DELETE subdata
4148981Sandreas.hansson@arm.com        FROM subdata
4158981Sandreas.hansson@arm.com        LEFT JOIN data ON sd_stat=dt_stat
4168981Sandreas.hansson@arm.com        WHERE dt_stat IS NULL''')
4178981Sandreas.hansson@arm.com
4188981Sandreas.hansson@arm.com        self.query('''
4198981Sandreas.hansson@arm.com        DELETE bins
42011139Sandreas.hansson@arm.com        FROM bins
42111139Sandreas.hansson@arm.com        LEFT JOIN data ON bn_id=dt_bin
4228981Sandreas.hansson@arm.com        WHERE dt_bin IS NULL''')
4239785Sandreas.hansson@arm.com
4248981Sandreas.hansson@arm.com        self.query('''
4258981Sandreas.hansson@arm.com        DELETE events
4268981Sandreas.hansson@arm.com        FROM events
4278981Sandreas.hansson@arm.com        LEFT JOIN runs ON ev_run=rn_id
4289785Sandreas.hansson@arm.com        WHERE rn_id IS NULL''')
4298981Sandreas.hansson@arm.com
4308981Sandreas.hansson@arm.com        self.query('''
4318981Sandreas.hansson@arm.com        DELETE event_names
4329785Sandreas.hansson@arm.com        FROM event_names
4338981Sandreas.hansson@arm.com        LEFT JOIN events ON en_id=ev_event
4348981Sandreas.hansson@arm.com        WHERE ev_event IS NULL''')
4358981Sandreas.hansson@arm.com