DB.pm 5.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150
  1. package Test::Mapper::DB;
  2. use strict;
  3. use warnings;
  4. # ABSTRACT: Persistent storage for what test maps where for what build.
  5. # We hold possibly multiple DBHes to support testing multiple products.
  6. my $dbh = {};
  7. sub dbh {
  8. my ( $dbname ) = @_;
  9. my $schema = join("\n",(readline(DATA)));
  10. $dbh //= {};
  11. return $dbh->{$dbname} if $dbh->{$dbname};
  12. File::Touch::touch($dbname) unless -f $dbname;
  13. my $db = DBI->connect( "dbi:SQLite:dbname=$dbname", "", "" );
  14. if ($schema) {
  15. die "No such schema file '$schema' !" unless -f $schema;
  16. my $qq = File::Slurper::read_text($schema);
  17. $db->{sqlite_allow_multiple_statements} = 1;
  18. $db->do($qq) or die "Could not ensure database consistency: " . $db->errstr;
  19. $db->{sqlite_allow_multiple_statements} = 0;
  20. }
  21. $dbh->{$dbname} = $db;
  22. # Turn on fkeys
  23. $db->do("PRAGMA foreign_keys = ON") or die "Could not enable foreign keys";
  24. # Turn on WALmode
  25. $db->do("PRAGMA journal_mode = WAL") or die "Could not enable WAL mode";
  26. return $db;
  27. }
  28. 1;
  29. __DATA__
  30. -- Should be pretty self-explanatory, DRY
  31. CREATE TABLE IF NOT EXISTS product (
  32. id INTEGER PRIMARY KEY AUTOINCREMENT,
  33. product TEXT NOT NULL UNIQUE
  34. );
  35. CREATE TABLE IF NOT EXISTS environment (
  36. id INTEGER PRIMARY KEY AUTOINCREMENT,
  37. environment TEXT NOT NULL,
  38. product_id INTEGER NOT NULL REFERENCES product(id) ON DELETE CASCADE,
  39. UNIQUE(environment, product_id) ON CONFLICT IGNORE
  40. );
  41. CREATE TABLE build (
  42. id INTEGER PRIMARY KEY AUTOINCREMENT,
  43. build TEXT NOT NULL,
  44. product_id INTEGER NOT NULL REFERENCES product(id) ON DELETE CASCADE,
  45. UNIQUE(build, product_id) ON CONFLICT IGNORE
  46. );
  47. CREATE TABLE route (
  48. id INTEGER PRIMARY KEY AUTOINCREMENT,
  49. route TEXT NOT NULL,
  50. product_id INTEGER NOT NULL REFERENCES product(id) ON DELETE CASCADE,
  51. UNIQUE(route, product_id) ON CONFLICT IGNORE
  52. );
  53. CREATE TABLE test (
  54. id INTEGER PRIMARY KEY AUTOINCREMENT,
  55. filename TEXT NOT NULL,
  56. product_id INTEGER NOT NULL REFERENCES product(id) ON DELETE CASCADE,
  57. UNIQUE(filename, product_id) ON CONFLICT IGNORE
  58. );
  59. -- run_by is used to coordinate running, what hasn't been taken yet etc
  60. -- result is a result code that visualization programs can use for historical charts
  61. -- The idea here is that 'people just wanna see what failed', and this helps narrow that down
  62. -- start/finish is so you can figure historical data/charts
  63. CREATE TABLE test_for_build (
  64. build_id INTEGER PRIMARY KEY REFERENCES build(id),
  65. test_id INTEGER REFERENCES test(id),
  66. run_by TEXT,
  67. result INTEGER,
  68. start INTEGER NOT NULL DEFAULT CURRENT_TIMESTAMP,
  69. finish INTEGER DEFAULT NULL,
  70. UNIQUE(build_id, test_id) ON CONFLICT ROLLBACK
  71. );
  72. -- Actually do the mapping of test -> what files changing trigger its running
  73. -- One tends to use differing resources on different environments.
  74. -- It is however assumed that the tests (or the cron inserting resources/tests) discriminates in this regard.
  75. CREATE TABLE resource (
  76. resource_id INTEGER PRIMARY KEY AUTOINCREMENT,
  77. environment_id INTEGER NOT NULL REFERENCES environment(id),
  78. filename TEXT NOT NULL,
  79. UNIQUE(environment_id, filename) ON CONFLICT IGNORE
  80. );
  81. -- Indexed by resource_id, as that's how a build is done "I have x changed resources, wat run?"
  82. CREATE TABLE tested_by (
  83. resource_id INTEGER PRIMARY KEY REFERENCES resource(id),
  84. test_id INTEGER NOT NULL REFERENCES test(id),
  85. UNIQUE(resource_id, test_id) ON CONFLICT IGNORE
  86. );
  87. -- Lifecycle:
  88. -- Have list of files from `git log`
  89. -- Run analysis script that returns hash test_file => [source_file, ...]
  90. -- INSERT INTO to_run (test_file,source_file, environment) VALUES (...);
  91. CREATE VIEW to_run AS SELECT (
  92. t.filename AS test_file,
  93. t.test_id AS test_id,
  94. r.filename AS source_file,
  95. e.environment AS environment
  96. ) FROM resource AS r
  97. JOIN tested_by AS tb ON tb.resource_id=r.resource_id
  98. JOIN test AS t ON t.id=tb.test_id
  99. JOIN environment ON e.id=r.environment_id
  100. ;
  101. -- TODO: make writable view for above intended for cron dumpage
  102. -- Lifecycle:
  103. -- Cron dumps rows into resource/tested_by, when time comes to run we grab the list of stuff:
  104. -- SELECT test_file FROM to_run WHERE source_file IN (...) GROUP BY test_file;
  105. -- We make a run
  106. -- INSERT INTO run (product, environment, build, filename) VALUES SELECT ('fooProduct', 'MsWin32', 'someSha', test_file) FROM to_run WHERE source_file IN (...) GROUP BY test_file;
  107. -- We run a test
  108. -- UPDATE run SET run_by='processid:90210' WHERE product='fooProduct' AND environment='MsWin32' AND build='someSha' AND test_file='actually_being_run.t';
  109. -- It completes. The end.
  110. -- UPDATE run SET result=1, finish=CURRENT_TIMESTAMP WHERE ...
  111. CREATE VIEW run AS SELECT (
  112. p.product,
  113. e.environment,
  114. b.build,
  115. r.route,
  116. t.filename,
  117. tb.run_by,
  118. tb.result
  119. ) FROM product AS p
  120. JOIN build AS b ON p.id=b.product_id
  121. JOIN test_for_build AS tb ON b.id=tb.build_id
  122. JOIN environment AS e on p.id=e.product_id
  123. JOIN route AS r ON p.id=r.product_id
  124. JOIN test AS t ON tb.test_id=t.id
  125. ;
  126. -- TODO: writable view to_run to make above lifecycle a real boy