Path: blob/main/contrib/kyua/store/migrate_v1_v2.sql
39478 views
-- Copyright 2013 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/v1-to-v2.sql29-- Migration of a database with version 1 of the schema to version 2.30--31-- Version 2 appeared in revision 9a73561a1e3975bba4cbfd19aee6b2365a39519e32-- and its changes were:33--34-- * Changed the primary key of the metadata table to be the35-- schema_version, not the timestamp. Because timestamps only have36-- second resolution, the old schema made testing of schema migrations37-- difficult.38--39-- * Introduced the metadatas table, which holds the metadata of all test40-- programs and test cases in an abstract manner regardless of their41-- interface.42--43-- * Added the metadata_id field to the test_programs and test_cases44-- tables, referencing the new metadatas table.45--46-- * Changed the precision of the timeout metadata field to be in seconds47-- rather than in microseconds. There is no data loss, and the code that48-- writes the metadata is simplified.49--50-- * Removed the atf_* and plain_* tables.51--52-- * Added missing indexes to improve the performance of reports.53--54-- * Added missing column affinities to the absolute_path and relative_path55-- columns of the test_programs table.565758-- TODO(jmmv): Implement addition of missing affinities.596061--62-- Change primary key of the metadata table.63--646566CREATE TABLE new_metadata (67schema_version INTEGER PRIMARY KEY CHECK (schema_version >= 1),68timestamp TIMESTAMP NOT NULL CHECK (timestamp >= 0)69);7071INSERT INTO new_metadata (schema_version, timestamp)72SELECT schema_version, timestamp FROM metadata;7374DROP TABLE metadata;75ALTER TABLE new_metadata RENAME TO metadata;767778--79-- Add the new tables, columns and indexes.80--818283CREATE TABLE metadatas (84metadata_id INTEGER NOT NULL,85property_name TEXT NOT NULL,86property_value TEXT,8788PRIMARY KEY (metadata_id, property_name)89);909192-- Upgrade the test_programs table by adding missing column affinities and93-- the new metadata_id column.94CREATE TABLE new_test_programs (95test_program_id INTEGER PRIMARY KEY AUTOINCREMENT,96action_id INTEGER REFERENCES actions,9798absolute_path TEXT NOT NULL,99root TEXT NOT NULL,100relative_path TEXT NOT NULL,101test_suite_name TEXT NOT NULL,102metadata_id INTEGER,103interface TEXT NOT NULL104);105PRAGMA foreign_keys = OFF;106INSERT INTO new_test_programs (test_program_id, action_id, absolute_path,107root, relative_path, test_suite_name,108interface)109SELECT test_program_id, action_id, absolute_path, root, relative_path,110test_suite_name, interface FROM test_programs;111DROP TABLE test_programs;112ALTER TABLE new_test_programs RENAME TO test_programs;113PRAGMA foreign_keys = ON;114115116ALTER TABLE test_cases ADD COLUMN metadata_id INTEGER;117118119CREATE INDEX index_metadatas_by_id120ON metadatas (metadata_id);121CREATE INDEX index_test_programs_by_action_id122ON test_programs (action_id);123CREATE INDEX index_test_cases_by_test_programs_id124ON test_cases (test_program_id);125126127--128-- Data migration129--130-- This is, by far, the trickiest part of the migration.131-- TODO(jmmv): Describe the trickiness in here.132--133134135-- Auxiliary table to construct the final contents of the metadatas table.136--137-- We construct the contents by writing a row for every metadata property of138-- every test program and test case. Entries corresponding to a test program139-- will have the test_program_id field set to not NULL and entries corresponding140-- to test cases will have the test_case_id set to not NULL.141--142-- The tricky part, however, is to create the individual identifiers for every143-- metadata entry. We do this by picking the minimum ROWID of a particular set144-- of properties that map to a single test_program_id or test_case_id.145CREATE TABLE tmp_metadatas (146test_program_id INTEGER DEFAULT NULL,147test_case_id INTEGER DEFAULT NULL,148interface TEXT NOT NULL,149property_name TEXT NOT NULL,150property_value TEXT NOT NULL,151152UNIQUE (test_program_id, test_case_id, property_name)153);154CREATE INDEX index_tmp_metadatas_by_test_case_id155ON tmp_metadatas (test_case_id);156CREATE INDEX index_tmp_metadatas_by_test_program_id157ON tmp_metadatas (test_program_id);158159160-- Populate default metadata values for all test programs and test cases.161--162-- We do this first to ensure that all test programs and test cases have163-- explicit values for their metadata. Because we want to keep historical data164-- for the tests, we must record these values unconditionally instead of relying165-- on the built-in values in the code.166--167-- Once this is done, we override any values explicity set by the tests.168CREATE TABLE tmp_default_metadata (169default_name TEXT PRIMARY KEY,170default_value TEXT NOT NULL171);172INSERT INTO tmp_default_metadata VALUES ('allowed_architectures', '');173INSERT INTO tmp_default_metadata VALUES ('allowed_platforms', '');174INSERT INTO tmp_default_metadata VALUES ('description', '');175INSERT INTO tmp_default_metadata VALUES ('has_cleanup', 'false');176INSERT INTO tmp_default_metadata VALUES ('required_configs', '');177INSERT INTO tmp_default_metadata VALUES ('required_files', '');178INSERT INTO tmp_default_metadata VALUES ('required_memory', '0');179INSERT INTO tmp_default_metadata VALUES ('required_programs', '');180INSERT INTO tmp_default_metadata VALUES ('required_user', '');181INSERT INTO tmp_default_metadata VALUES ('timeout', '300');182INSERT INTO tmp_metadatas183SELECT test_program_id, NULL, interface, default_name, default_value184FROM test_programs JOIN tmp_default_metadata;185INSERT INTO tmp_metadatas186SELECT NULL, test_case_id, interface, default_name, default_value187FROM test_programs JOIN test_cases188ON test_cases.test_program_id = test_programs.test_program_id189JOIN tmp_default_metadata;190DROP TABLE tmp_default_metadata;191192193-- Populate metadata overrides from plain test programs.194UPDATE tmp_metadatas195SET property_value = (196SELECT CAST(timeout / 1000000 AS TEXT) FROM plain_test_programs AS aux197WHERE aux.test_program_id = tmp_metadatas.test_program_id)198WHERE test_program_id IS NOT NULL AND property_name = 'timeout'199AND interface = 'plain';200UPDATE tmp_metadatas201SET property_value = (202SELECT DISTINCT CAST(timeout / 1000000 AS TEXT)203FROM test_cases AS aux JOIN plain_test_programs204ON aux.test_program_id == plain_test_programs.test_program_id205WHERE aux.test_case_id = tmp_metadatas.test_case_id)206WHERE test_case_id IS NOT NULL AND property_name = 'timeout'207AND interface = 'plain';208209210CREATE INDEX index_tmp_atf_test_cases_multivalues_by_test_case_id211ON atf_test_cases_multivalues (test_case_id);212213214-- Populate metadata overrides from ATF test cases.215UPDATE atf_test_cases SET description = '' WHERE description IS NULL;216UPDATE atf_test_cases SET required_user = '' WHERE required_user IS NULL;217218UPDATE tmp_metadatas219SET property_value = (220SELECT description FROM atf_test_cases AS aux221WHERE aux.test_case_id = tmp_metadatas.test_case_id)222WHERE test_case_id IS NOT NULL AND property_name = 'description'223AND interface = 'atf';224UPDATE tmp_metadatas225SET property_value = (226SELECT has_cleanup FROM atf_test_cases AS aux227WHERE aux.test_case_id = tmp_metadatas.test_case_id)228WHERE test_case_id IS NOT NULL AND property_name = 'has_cleanup'229AND interface = 'atf';230UPDATE tmp_metadatas231SET property_value = (232SELECT CAST(timeout / 1000000 AS TEXT) FROM atf_test_cases AS aux233WHERE aux.test_case_id = tmp_metadatas.test_case_id)234WHERE test_case_id IS NOT NULL AND property_name = 'timeout'235AND interface = 'atf';236UPDATE tmp_metadatas237SET property_value = (238SELECT CAST(required_memory AS TEXT) FROM atf_test_cases AS aux239WHERE aux.test_case_id = tmp_metadatas.test_case_id)240WHERE test_case_id IS NOT NULL AND property_name = 'required_memory'241AND interface = 'atf';242UPDATE tmp_metadatas243SET property_value = (244SELECT required_user FROM atf_test_cases AS aux245WHERE aux.test_case_id = tmp_metadatas.test_case_id)246WHERE test_case_id IS NOT NULL AND property_name = 'required_user'247AND interface = 'atf';248UPDATE tmp_metadatas249SET property_value = (250SELECT GROUP_CONCAT(aux.property_value, ' ')251FROM atf_test_cases_multivalues AS aux252WHERE aux.test_case_id = tmp_metadatas.test_case_id AND253aux.property_name = 'require.arch')254WHERE test_case_id IS NOT NULL AND property_name = 'allowed_architectures'255AND interface = 'atf'256AND EXISTS(SELECT 1 FROM atf_test_cases_multivalues AS aux257WHERE aux.test_case_id = tmp_metadatas.test_case_id258AND property_name = 'require.arch');259UPDATE tmp_metadatas260SET property_value = (261SELECT GROUP_CONCAT(aux.property_value, ' ')262FROM atf_test_cases_multivalues AS aux263WHERE aux.test_case_id = tmp_metadatas.test_case_id AND264aux.property_name = 'require.machine')265WHERE test_case_id IS NOT NULL AND property_name = 'allowed_platforms'266AND interface = 'atf'267AND EXISTS(SELECT 1 FROM atf_test_cases_multivalues AS aux268WHERE aux.test_case_id = tmp_metadatas.test_case_id269AND property_name = 'require.machine');270UPDATE tmp_metadatas271SET property_value = (272SELECT GROUP_CONCAT(aux.property_value, ' ')273FROM atf_test_cases_multivalues AS aux274WHERE aux.test_case_id = tmp_metadatas.test_case_id AND275aux.property_name = 'require.config')276WHERE test_case_id IS NOT NULL AND property_name = 'required_configs'277AND interface = 'atf'278AND EXISTS(SELECT 1 FROM atf_test_cases_multivalues AS aux279WHERE aux.test_case_id = tmp_metadatas.test_case_id280AND property_name = 'require.config');281UPDATE tmp_metadatas282SET property_value = (283SELECT GROUP_CONCAT(aux.property_value, ' ')284FROM atf_test_cases_multivalues AS aux285WHERE aux.test_case_id = tmp_metadatas.test_case_id AND286aux.property_name = 'require.files')287WHERE test_case_id IS NOT NULL AND property_name = 'required_files'288AND interface = 'atf'289AND EXISTS(SELECT 1 FROM atf_test_cases_multivalues AS aux290WHERE aux.test_case_id = tmp_metadatas.test_case_id291AND property_name = 'require.files');292UPDATE tmp_metadatas293SET property_value = (294SELECT GROUP_CONCAT(aux.property_value, ' ')295FROM atf_test_cases_multivalues AS aux296WHERE aux.test_case_id = tmp_metadatas.test_case_id AND297aux.property_name = 'require.progs')298WHERE test_case_id IS NOT NULL AND property_name = 'required_programs'299AND interface = 'atf'300AND EXISTS(SELECT 1 FROM atf_test_cases_multivalues AS aux301WHERE aux.test_case_id = tmp_metadatas.test_case_id302AND property_name = 'require.progs');303304305-- Fill metadata_id pointers in the test_programs and test_cases tables.306UPDATE test_programs307SET metadata_id = (308SELECT MIN(ROWID) FROM tmp_metadatas309WHERE tmp_metadatas.test_program_id = test_programs.test_program_id310);311UPDATE test_cases312SET metadata_id = (313SELECT MIN(ROWID) FROM tmp_metadatas314WHERE tmp_metadatas.test_case_id = test_cases.test_case_id315);316317318-- Populate the metadatas table based on tmp_metadatas.319INSERT INTO metadatas (metadata_id, property_name, property_value)320SELECT (321SELECT MIN(ROWID) FROM tmp_metadatas AS s322WHERE s.test_program_id = tmp_metadatas.test_program_id323), property_name, property_value324FROM tmp_metadatas WHERE test_program_id IS NOT NULL;325INSERT INTO metadatas (metadata_id, property_name, property_value)326SELECT (327SELECT MIN(ROWID) FROM tmp_metadatas AS s328WHERE s.test_case_id = tmp_metadatas.test_case_id329), property_name, property_value330FROM tmp_metadatas WHERE test_case_id IS NOT NULL;331332333-- Drop temporary entities used during the migration.334DROP INDEX index_tmp_atf_test_cases_multivalues_by_test_case_id;335DROP INDEX index_tmp_metadatas_by_test_program_id;336DROP INDEX index_tmp_metadatas_by_test_case_id;337DROP TABLE tmp_metadatas;338339340--341-- Drop obsolete tables.342--343344345DROP TABLE atf_test_cases;346DROP TABLE atf_test_cases_multivalues;347DROP TABLE plain_test_programs;348349350--351-- Update the metadata version.352--353354355INSERT INTO metadata (timestamp, schema_version)356VALUES (strftime('%s', 'now'), 2);357358359