-- Copyright 2012 The Kyua Authors.1-- All rights reserved.2--3-- Redistribution and use in source and binary forms, with or without4-- modification, are permitted provided that the following conditions are5-- met:6--7-- * Redistributions of source code must retain the above copyright8-- notice, this list of conditions and the following disclaimer.9-- * Redistributions in binary form must reproduce the above copyright10-- notice, this list of conditions and the following disclaimer in the11-- documentation and/or other materials provided with the distribution.12-- * Neither the name of Google Inc. nor the names of its contributors13-- may be used to endorse or promote products derived from this software14-- without specific prior written permission.15--16-- THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS17-- "AS IS" AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT18-- LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR19-- A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT20-- OWNER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL,21-- SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT22-- LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE,23-- DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY24-- THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT25-- (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE26-- OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.2728-- \file store/schema_v2.sql29-- Definition of the database schema.30--31-- The whole contents of this file are wrapped in a transaction. We want32-- to ensure that the initial contents of the database (the table layout as33-- well as any predefined values) are written atomically to simplify error34-- handling in our code.353637BEGIN TRANSACTION;383940-- -------------------------------------------------------------------------41-- Metadata.42-- -------------------------------------------------------------------------434445-- Database-wide properties.46--47-- Rows in this table are immutable: modifying the metadata implies writing48-- a new record with a new schema_version greater than all existing49-- records, and never updating previous records. When extracting data from50-- this table, the only "valid" row is the one with the highest51-- scheam_version. All the other rows are meaningless and only exist for52-- historical purposes.53--54-- In other words, this table keeps the history of the database metadata.55-- The only reason for doing this is for debugging purposes. It may come56-- in handy to know when a particular database-wide operation happened if57-- it turns out that the database got corrupted.58CREATE TABLE metadata (59schema_version INTEGER PRIMARY KEY CHECK (schema_version >= 1),60timestamp TIMESTAMP NOT NULL CHECK (timestamp >= 0)61);626364-- -------------------------------------------------------------------------65-- Contexts.66-- -------------------------------------------------------------------------676869-- Execution contexts.70--71-- A context represents the execution environment of a particular action.72-- Because every action is invoked by the user, the context may have73-- changed. We record such information for information and debugging74-- purposes.75CREATE TABLE contexts (76context_id INTEGER PRIMARY KEY AUTOINCREMENT,77cwd TEXT NOT NULL7879-- TODO(jmmv): Record the run-time configuration.80);818283-- Environment variables of a context.84CREATE TABLE env_vars (85context_id INTEGER REFERENCES contexts,86var_name TEXT NOT NULL,87var_value TEXT NOT NULL,8889PRIMARY KEY (context_id, var_name)90);919293-- -------------------------------------------------------------------------94-- Actions.95-- -------------------------------------------------------------------------969798-- Representation of user-initiated actions.99--100-- An action is an operation initiated by the user. At the moment, the101-- only operation Kyua supports is the "test" operation (in the future we102-- should be able to store, e.g. build logs). To keep things simple the103-- database schema is restricted to represent one single action.104CREATE TABLE actions (105action_id INTEGER PRIMARY KEY AUTOINCREMENT,106context_id INTEGER REFERENCES contexts107);108109110-- -------------------------------------------------------------------------111-- Test suites.112--113-- The tables in this section represent all the components that form a test114-- suite. This includes data about the test suite itself (test programs115-- and test cases), and also the data about particular runs (test results).116--117-- As you will notice, every object belongs to a particular action, has a118-- unique identifier and there is no attempt to deduplicate data. This119-- comes from the fact that a test suite is not "stable" over time: i.e. on120-- each execution of the test suite, test programs and test cases may have121-- come and gone. This has the interesting result of making the122-- distinction of a test case and a test result a pure syntactic123-- difference, because there is always a 1:1 relation.124--125-- The code that performs the processing of the actions is the component in126-- charge of finding correlations between test programs and test cases127-- across different actions.128-- -------------------------------------------------------------------------129130131-- Representation of the metadata objects.132--133-- The way this table works is like this: every time we record a metadata134-- object, we calculate what its identifier should be as the last rowid of135-- the table. All properties of that metadata object thus receive the same136-- identifier.137CREATE TABLE metadatas (138metadata_id INTEGER NOT NULL,139140-- The name of the property.141property_name TEXT NOT NULL,142143-- One of the values of the property.144property_value TEXT,145146PRIMARY KEY (metadata_id, property_name)147);148149150-- Optimize the loading of the metadata of any single entity.151--152-- The metadata_id column of the metadatas table is not enough to act as a153-- primary key, yet we need to locate entries in the metadatas table solely by154-- their identifier.155--156-- TODO(jmmv): I think this index is useless given that the primary key in the157-- metadatas table includes the metadata_id as the first component. Need to158-- verify this and drop the index or this comment appropriately.159CREATE INDEX index_metadatas_by_id160ON metadatas (metadata_id);161162163-- Representation of a test program.164--165-- At the moment, there are no substantial differences between the166-- different interfaces, so we can simplify the design by with having a167-- single table representing all test caes. We may need to revisit this in168-- the future.169CREATE TABLE test_programs (170test_program_id INTEGER PRIMARY KEY AUTOINCREMENT,171action_id INTEGER REFERENCES actions,172173-- The absolute path to the test program. This should not be necessary174-- because it is basically the concatenation of root and relative_path.175-- However, this allows us to very easily search for test programs176-- regardless of where they were executed from. (I.e. different177-- combinations of root + relative_path can map to the same absolute path).178absolute_path TEXT NOT NULL,179180-- The path to the root of the test suite (where the Kyuafile lives).181root TEXT NOT NULL,182183-- The path to the test program, relative to the root.184relative_path TEXT NOT NULL,185186-- Name of the test suite the test program belongs to.187test_suite_name TEXT NOT NULL,188189-- Reference to the various rows of metadatas.190metadata_id INTEGER,191192-- The name of the test program interface.193--194-- Note that this indicates both the interface for the test program and195-- its test cases. See below for the corresponding detail tables.196interface TEXT NOT NULL197);198199200-- Optimize the lookup of test programs by the action they belong to.201CREATE INDEX index_test_programs_by_action_id202ON test_programs (action_id);203204205-- Representation of a test case.206--207-- At the moment, there are no substantial differences between the208-- different interfaces, so we can simplify the design by with having a209-- single table representing all test caes. We may need to revisit this in210-- the future.211CREATE TABLE test_cases (212test_case_id INTEGER PRIMARY KEY AUTOINCREMENT,213test_program_id INTEGER REFERENCES test_programs,214name TEXT NOT NULL,215216-- Reference to the various rows of metadatas.217metadata_id INTEGER218);219220221-- Optimize the loading of all test cases that are part of a test program.222CREATE INDEX index_test_cases_by_test_programs_id223ON test_cases (test_program_id);224225226-- Representation of test case results.227--228-- Note that there is a 1:1 relation between test cases and their results.229-- This is a result of storing the information of a test case on every230-- single action.231CREATE TABLE test_results (232test_case_id INTEGER PRIMARY KEY REFERENCES test_cases,233result_type TEXT NOT NULL,234result_reason TEXT,235236start_time TIMESTAMP NOT NULL,237end_time TIMESTAMP NOT NULL238);239240241-- Collection of output files of the test case.242CREATE TABLE test_case_files (243test_case_id INTEGER NOT NULL REFERENCES test_cases,244245-- The raw name of the file.246--247-- The special names '__STDOUT__' and '__STDERR__' are reserved to hold248-- the stdout and stderr of the test case, respectively. If any of249-- these are empty, there will be no corresponding entry in this table250-- (hence why we do not allow NULLs in these fields).251file_name TEXT NOT NULL,252253-- Pointer to the file itself.254file_id INTEGER NOT NULL REFERENCES files,255256PRIMARY KEY (test_case_id, file_name)257);258259260-- -------------------------------------------------------------------------261-- Verbatim files.262-- -------------------------------------------------------------------------263264265-- Copies of files or logs generated during testing.266--267-- TODO(jmmv): This will probably grow to unmanageable sizes. We should add a268-- hash to the file contents and use that as the primary key instead.269CREATE TABLE files (270file_id INTEGER PRIMARY KEY,271272contents BLOB NOT NULL273);274275276-- -------------------------------------------------------------------------277-- Initialization of values.278-- -------------------------------------------------------------------------279280281-- Create a new metadata record.282--283-- For every new database, we want to ensure that the metadata is valid if284-- the database creation (i.e. the whole transaction) succeeded.285--286-- If you modify the value of the schema version in this statement, you287-- will also have to modify the version encoded in the backend module.288INSERT INTO metadata (timestamp, schema_version)289VALUES (strftime('%s', 'now'), 2);290291292COMMIT TRANSACTION;293294295