mig/doc/data.rst.html

751 строка
44 KiB
HTML
Исходник Обычный вид История

<?xml version="1.0" encoding="utf-8" ?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd">
<html xmlns="http://www.w3.org/1999/xhtml" xml:lang="en" lang="en">
2014-09-11 07:56:53 +04:00
<head>
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
<meta name="generator" content="Docutils 0.11: http://docutils.sourceforge.net/" />
<title>MIG Data</title>
<meta name="author" content="Julien Vehent &lt;jvehent&#64;mozilla.com&gt;" />
<style type="text/css">
/*
:Author: David Goodger (goodger@python.org)
:Id: $Id: html4css1.css 7614 2013-02-21 15:55:51Z milde $
:Copyright: This stylesheet has been placed in the public domain.
Default cascading style sheet for the HTML output of Docutils.
See http://docutils.sf.net/docs/howto/html-stylesheets.html for how to
customize this style sheet.
*/
/* used to remove borders from tables and images */
.borderless, table.borderless td, table.borderless th {
border: 0 }
table.borderless td, table.borderless th {
/* Override padding for "table.docutils td" with "! important".
The right padding separates the table cells. */
padding: 0 0.5em 0 0 ! important }
.first {
/* Override more specific margin styles with "! important". */
margin-top: 0 ! important }
.last, .with-subtitle {
margin-bottom: 0 ! important }
.hidden {
display: none }
a.toc-backref {
text-decoration: none ;
color: black }
blockquote.epigraph {
margin: 2em 5em ; }
dl.docutils dd {
margin-bottom: 0.5em }
object[type="image/svg+xml"], object[type="application/x-shockwave-flash"] {
overflow: hidden;
}
/* Uncomment (and remove this text!) to get bold-faced definition list terms
dl.docutils dt {
font-weight: bold }
*/
div.abstract {
margin: 2em 5em }
div.abstract p.topic-title {
font-weight: bold ;
text-align: center }
div.admonition, div.attention, div.caution, div.danger, div.error,
div.hint, div.important, div.note, div.tip, div.warning {
margin: 2em ;
border: medium outset ;
padding: 1em }
div.admonition p.admonition-title, div.hint p.admonition-title,
div.important p.admonition-title, div.note p.admonition-title,
div.tip p.admonition-title {
font-weight: bold ;
font-family: sans-serif }
div.attention p.admonition-title, div.caution p.admonition-title,
div.danger p.admonition-title, div.error p.admonition-title,
div.warning p.admonition-title, .code .error {
color: red ;
font-weight: bold ;
font-family: sans-serif }
/* Uncomment (and remove this text!) to get reduced vertical space in
compound paragraphs.
div.compound .compound-first, div.compound .compound-middle {
margin-bottom: 0.5em }
div.compound .compound-last, div.compound .compound-middle {
margin-top: 0.5em }
*/
div.dedication {
margin: 2em 5em ;
text-align: center ;
font-style: italic }
div.dedication p.topic-title {
font-weight: bold ;
font-style: normal }
div.figure {
margin-left: 2em ;
margin-right: 2em }
div.footer, div.header {
clear: both;
font-size: smaller }
div.line-block {
display: block ;
margin-top: 1em ;
margin-bottom: 1em }
div.line-block div.line-block {
margin-top: 0 ;
margin-bottom: 0 ;
margin-left: 1.5em }
div.sidebar {
margin: 0 0 0.5em 1em ;
border: medium outset ;
padding: 1em ;
background-color: #ffffee ;
width: 40% ;
float: right ;
clear: right }
div.sidebar p.rubric {
font-family: sans-serif ;
font-size: medium }
div.system-messages {
margin: 5em }
div.system-messages h1 {
color: red }
div.system-message {
border: medium outset ;
padding: 1em }
div.system-message p.system-message-title {
color: red ;
font-weight: bold }
div.topic {
margin: 2em }
h1.section-subtitle, h2.section-subtitle, h3.section-subtitle,
h4.section-subtitle, h5.section-subtitle, h6.section-subtitle {
margin-top: 0.4em }
h1.title {
text-align: center }
h2.subtitle {
text-align: center }
hr.docutils {
width: 75% }
img.align-left, .figure.align-left, object.align-left {
clear: left ;
float: left ;
margin-right: 1em }
img.align-right, .figure.align-right, object.align-right {
clear: right ;
float: right ;
margin-left: 1em }
img.align-center, .figure.align-center, object.align-center {
display: block;
margin-left: auto;
margin-right: auto;
}
.align-left {
text-align: left }
.align-center {
clear: both ;
text-align: center }
.align-right {
text-align: right }
/* reset inner alignment in figures */
div.align-right {
text-align: inherit }
/* div.align-center * { */
/* text-align: left } */
ol.simple, ul.simple {
margin-bottom: 1em }
ol.arabic {
list-style: decimal }
ol.loweralpha {
list-style: lower-alpha }
ol.upperalpha {
list-style: upper-alpha }
ol.lowerroman {
list-style: lower-roman }
ol.upperroman {
list-style: upper-roman }
p.attribution {
text-align: right ;
margin-left: 50% }
p.caption {
font-style: italic }
p.credits {
font-style: italic ;
font-size: smaller }
p.label {
white-space: nowrap }
p.rubric {
font-weight: bold ;
font-size: larger ;
color: maroon ;
text-align: center }
p.sidebar-title {
font-family: sans-serif ;
font-weight: bold ;
font-size: larger }
p.sidebar-subtitle {
font-family: sans-serif ;
font-weight: bold }
p.topic-title {
font-weight: bold }
pre.address {
margin-bottom: 0 ;
margin-top: 0 ;
font: inherit }
pre.literal-block, pre.doctest-block, pre.math, pre.code {
margin-left: 2em ;
margin-right: 2em }
pre.code .ln { color: grey; } /* line numbers */
pre.code, code { background-color: #eeeeee }
pre.code .comment, code .comment { color: #5C6576 }
pre.code .keyword, code .keyword { color: #3B0D06; font-weight: bold }
pre.code .literal.string, code .literal.string { color: #0C5404 }
pre.code .name.builtin, code .name.builtin { color: #352B84 }
pre.code .deleted, code .deleted { background-color: #DEB0A1}
pre.code .inserted, code .inserted { background-color: #A3D289}
span.classifier {
font-family: sans-serif ;
font-style: oblique }
span.classifier-delimiter {
font-family: sans-serif ;
font-weight: bold }
span.interpreted {
font-family: sans-serif }
span.option {
white-space: nowrap }
span.pre {
white-space: pre }
span.problematic {
color: red }
span.section-subtitle {
/* font-size relative to parent (h1..h6 element) */
font-size: 80% }
table.citation {
border-left: solid 1px gray;
margin-left: 1px }
table.docinfo {
margin: 2em 4em }
table.docutils {
margin-top: 0.5em ;
margin-bottom: 0.5em }
table.footnote {
border-left: solid 1px black;
margin-left: 1px }
table.docutils td, table.docutils th,
table.docinfo td, table.docinfo th {
padding-left: 0.5em ;
padding-right: 0.5em ;
vertical-align: top }
table.docutils th.field-name, table.docinfo th.docinfo-name {
font-weight: bold ;
text-align: left ;
white-space: nowrap ;
padding-left: 0 }
/* "booktabs" style (no vertical lines) */
table.docutils.booktabs {
border: 0px;
border-top: 2px solid;
border-bottom: 2px solid;
border-collapse: collapse;
}
table.docutils.booktabs * {
border: 0px;
}
table.docutils.booktabs th {
border-bottom: thin solid;
text-align: left;
}
h1 tt.docutils, h2 tt.docutils, h3 tt.docutils,
h4 tt.docutils, h5 tt.docutils, h6 tt.docutils {
font-size: 100% }
ul.auto-toc {
list-style-type: none }
</style>
2014-09-11 07:56:53 +04:00
</head>
<body>
<div class="document" id="mig-data">
<h1 class="title">MIG Data</h1>
<table class="docinfo" frame="void" rules="none">
<col class="docinfo-name" />
<col class="docinfo-content" />
<tbody valign="top">
<tr><th class="docinfo-name">Author:</th>
<td>Julien Vehent &lt;<a class="reference external" href="mailto:jvehent&#64;mozilla.com">jvehent&#64;mozilla.com</a>&gt;</td></tr>
</tbody>
</table>
<div class="contents topic" id="table-of-contents">
<p class="topic-title first">Table of Contents</p>
<ul class="auto-toc simple">
<li><a class="reference internal" href="#scheduler-spool" id="id1">1&nbsp;&nbsp;&nbsp;Scheduler Spool</a></li>
<li><a class="reference internal" href="#postgresql-schema" id="id2">2&nbsp;&nbsp;&nbsp;Postgresql Schema</a><ul class="auto-toc">
<li><a class="reference internal" href="#entity-relationship-diagram" id="id3">2.1&nbsp;&nbsp;&nbsp;Entity-Relationship Diagram</a></li>
<li><a class="reference internal" href="#structure-tables" id="id4">2.2&nbsp;&nbsp;&nbsp;Structure &amp; Tables</a></li>
<li><a class="reference internal" href="#database-creation-script" id="id5">2.3&nbsp;&nbsp;&nbsp;Database creation script</a></li>
</ul>
</li>
<li><a class="reference internal" href="#queries" id="id6">3&nbsp;&nbsp;&nbsp;Queries</a><ul class="auto-toc">
<li><a class="reference internal" href="#adding-investigators" id="id7">3.1&nbsp;&nbsp;&nbsp;Adding Investigators</a></li>
<li><a class="reference internal" href="#finding-offline-agents" id="id8">3.2&nbsp;&nbsp;&nbsp;Finding offline agents</a></li>
<li><a class="reference internal" href="#finding-double-agents" id="id9">3.3&nbsp;&nbsp;&nbsp;Finding double agents</a></li>
</ul>
</li>
</ul>
</div>
<div class="section" id="scheduler-spool">
<h1><a class="toc-backref" href="#id1">1&nbsp;&nbsp;&nbsp;Scheduler Spool</a></h1>
<p>MIG data is stored both on the file system of the scheduler, and in mongodb. On
the scheduler, each action and command are stored individually in a text file in
/var/cache/mig (by default).</p>
<pre class="code bash literal-block">
<span class="name variable">$ </span>tree -d /var/cache/mig/
2014-09-11 07:56:53 +04:00
/var/cache/mig/
├── action
&nbsp;&nbsp; ├── <span class="keyword">done</span>
&nbsp;&nbsp; ├── inflight
&nbsp;&nbsp; ├── invalid
&nbsp;&nbsp; └── new
└── <span class="name builtin">command</span>
├── <span class="keyword">done</span>
├── inflight
├── ready
└── returned
10 directories
</pre>
</div>
<div class="section" id="postgresql-schema">
<h1><a class="toc-backref" href="#id2">2&nbsp;&nbsp;&nbsp;Postgresql Schema</a></h1>
<div class="section" id="entity-relationship-diagram">
<h2><a class="toc-backref" href="#id3">2.1&nbsp;&nbsp;&nbsp;Entity-Relationship Diagram</a></h2>
<img alt=".files/ER-diagram.png" src=".files/ER-diagram.png" />
</div>
<div class="section" id="structure-tables">
<h2><a class="toc-backref" href="#id4">2.2&nbsp;&nbsp;&nbsp;Structure &amp; Tables</a></h2>
<p>The <cite>actions</cite> table contains the detail of each action ran by the MIG platform.
Its structure contains the base action fields found in the json format of an
action, plus a number of additional fields such as timestamps and counters.</p>
<pre class="code sql literal-block">
<span class="keyword">CREATE</span> <span class="keyword">TABLE</span> <span class="name">IF</span> <span class="keyword">NOT</span> <span class="keyword">EXISTS</span> <span class="name">actions</span> <span class="punctuation">(</span>
<span class="name">id</span> <span class="name builtin">numeric</span> <span class="keyword">PRIMARY</span> <span class="keyword">KEY</span><span class="punctuation">,</span>
<span class="name">name</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">2048</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">target</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">2048</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">description</span> <span class="name">json</span><span class="punctuation">,</span>
<span class="name">threat</span> <span class="name">json</span><span class="punctuation">,</span>
<span class="name">operations</span> <span class="name">json</span><span class="punctuation">,</span>
<span class="name">validfrom</span> <span class="keyword">timestamp</span> <span class="keyword">with</span> <span class="name">time</span> <span class="keyword">zone</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">expireafter</span> <span class="keyword">timestamp</span> <span class="keyword">with</span> <span class="name">time</span> <span class="keyword">zone</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">starttime</span> <span class="keyword">timestamp</span> <span class="keyword">with</span> <span class="name">time</span> <span class="keyword">zone</span><span class="punctuation">,</span>
<span class="name">finishtime</span> <span class="keyword">timestamp</span> <span class="keyword">with</span> <span class="name">time</span> <span class="keyword">zone</span><span class="punctuation">,</span>
<span class="name">lastupdatetime</span> <span class="keyword">timestamp</span> <span class="keyword">with</span> <span class="name">time</span> <span class="keyword">zone</span><span class="punctuation">,</span>
<span class="name">status</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">256</span><span class="punctuation">),</span>
<span class="name">sentctr</span> <span class="name builtin">integer</span><span class="punctuation">,</span>
<span class="name">returnedctr</span> <span class="name builtin">integer</span><span class="punctuation">,</span>
<span class="name">donectr</span> <span class="name builtin">integer</span><span class="punctuation">,</span>
<span class="name">cancelledctr</span> <span class="name builtin">integer</span><span class="punctuation">,</span>
<span class="name">failedctr</span> <span class="name builtin">integer</span><span class="punctuation">,</span>
<span class="name">timeoutctr</span> <span class="name builtin">integer</span><span class="punctuation">,</span>
<span class="name">pgpsignatures</span> <span class="name">json</span><span class="punctuation">,</span>
<span class="name">syntaxversion</span> <span class="name builtin">integer</span>
<span class="punctuation">);</span>
</pre>
<p>The <cite>agents</cite> table contains the registrations of each agents known of the MIG
platform.</p>
<pre class="code sql literal-block">
<span class="keyword">CREATE</span> <span class="keyword">TABLE</span> <span class="name">IF</span> <span class="keyword">NOT</span> <span class="keyword">EXISTS</span> <span class="name">agents</span> <span class="punctuation">(</span>
<span class="name">id</span> <span class="name builtin">numeric</span> <span class="keyword">PRIMARY</span> <span class="keyword">KEY</span><span class="punctuation">,</span>
<span class="name">name</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">2048</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">queueloc</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">2048</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">os</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">2048</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="keyword">version</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">2048</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">pid</span> <span class="name builtin">integer</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">starttime</span> <span class="keyword">timestamp</span> <span class="keyword">with</span> <span class="name">time</span> <span class="keyword">zone</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">destructiontime</span> <span class="keyword">timestamp</span> <span class="keyword">with</span> <span class="name">time</span> <span class="keyword">zone</span><span class="punctuation">,</span>
<span class="name">heartbeattime</span> <span class="keyword">timestamp</span> <span class="keyword">with</span> <span class="name">time</span> <span class="keyword">zone</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">status</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">256</span><span class="punctuation">),</span>
<span class="name">environment</span> <span class="name">json</span><span class="punctuation">,</span>
<span class="name">tags</span> <span class="name">json</span>
<span class="punctuation">);</span>
</pre>
<p>The <cite>commands</cite> table contains each action sent to each agent.</p>
<pre class="code sql literal-block">
<span class="keyword">CREATE</span> <span class="keyword">TABLE</span> <span class="name">IF</span> <span class="keyword">NOT</span> <span class="keyword">EXISTS</span> <span class="name">commands</span> <span class="punctuation">(</span>
<span class="name">id</span> <span class="name builtin">numeric</span> <span class="keyword">PRIMARY</span> <span class="keyword">KEY</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">actionid</span> <span class="name builtin">numeric</span> <span class="keyword">references</span> <span class="name">actions</span><span class="punctuation">(</span><span class="name">id</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">agentid</span> <span class="name builtin">numeric</span> <span class="keyword">references</span> <span class="name">agents</span><span class="punctuation">(</span><span class="name">id</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">status</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">256</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">results</span> <span class="name">json</span><span class="punctuation">,</span>
<span class="name">starttime</span> <span class="keyword">timestamp</span> <span class="keyword">with</span> <span class="name">time</span> <span class="keyword">zone</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">finishtime</span> <span class="keyword">timestamp</span> <span class="keyword">with</span> <span class="name">time</span> <span class="keyword">zone</span>
<span class="punctuation">);</span>
</pre>
<p><cite>investigators</cite> have a table that contains their public PGP key, and can be
used when verifying signatures and generating ACLs.</p>
<pre class="code sql literal-block">
<span class="keyword">CREATE</span> <span class="keyword">TABLE</span> <span class="name">IF</span> <span class="keyword">NOT</span> <span class="keyword">EXISTS</span> <span class="name">investigators</span> <span class="punctuation">(</span>
<span class="name">id</span> <span class="name builtin">numeric</span> <span class="keyword">PRIMARY</span> <span class="keyword">KEY</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">name</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">1024</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">pgpfingerprint</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">128</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">publickey</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">65536</span><span class="punctuation">)</span>
<span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">UNIQUE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">investigators</span> <span class="punctuation">(</span><span class="name">pgpfingerprint</span><span class="punctuation">);</span>
</pre>
<p>The <cite>signatures</cite> table is a junction between an action and the investigators
that signed the action.</p>
<pre class="code sql literal-block">
<span class="keyword">CREATE</span> <span class="keyword">TABLE</span> <span class="name">IF</span> <span class="keyword">NOT</span> <span class="keyword">EXISTS</span> <span class="name">signatures</span> <span class="punctuation">(</span>
<span class="name">actionid</span> <span class="name builtin">numeric</span> <span class="keyword">references</span> <span class="name">actions</span><span class="punctuation">(</span><span class="name">id</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">investigatorid</span> <span class="name builtin">numeric</span> <span class="keyword">references</span> <span class="name">investigators</span><span class="punctuation">(</span><span class="name">id</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">pgpsignature</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">4096</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span>
<span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">UNIQUE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">signatures</span> <span class="punctuation">(</span><span class="name">actionid</span><span class="punctuation">,</span> <span class="name">investigatorid</span><span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">signatures</span> <span class="punctuation">(</span><span class="name">actionid</span><span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">signatures</span> <span class="punctuation">(</span><span class="name">investigatorid</span><span class="punctuation">);</span>
</pre>
<p>Agents modules are registered in the <cite>modules</cite> table.</p>
<pre class="code sql literal-block">
<span class="keyword">CREATE</span> <span class="keyword">TABLE</span> <span class="name">IF</span> <span class="keyword">NOT</span> <span class="keyword">EXISTS</span> <span class="name">modules</span> <span class="punctuation">(</span>
<span class="name">id</span> <span class="name builtin">numeric</span> <span class="keyword">PRIMARY</span> <span class="keyword">KEY</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">name</span> <span class="name builtin">varchar</span><span class="punctuation">(</span><span class="literal number integer">256</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span>
<span class="punctuation">);</span>
</pre>
<p>ACLs are managed in two junction tables. First, the <cite>agtmodreq</cite> table contains
the minimum weight an action must have to run a particular module on a given
agent.</p>
<pre class="code sql literal-block">
<span class="keyword">CREATE</span> <span class="keyword">TABLE</span> <span class="name">IF</span> <span class="keyword">NOT</span> <span class="keyword">EXISTS</span> <span class="name">agtmodreq</span> <span class="punctuation">(</span>
<span class="name">moduleid</span> <span class="name builtin">numeric</span> <span class="keyword">references</span> <span class="name">modules</span><span class="punctuation">(</span><span class="name">id</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">agentid</span> <span class="name builtin">numeric</span> <span class="keyword">references</span> <span class="name">agents</span><span class="punctuation">(</span><span class="name">id</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">minimumweight</span> <span class="name builtin">integer</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span>
<span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">UNIQUE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">agtmodreq</span> <span class="punctuation">(</span><span class="name">moduleid</span><span class="punctuation">,</span> <span class="name">agentid</span><span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">agtmodreq</span> <span class="punctuation">(</span><span class="name">moduleid</span><span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">agtmodreq</span> <span class="punctuation">(</span><span class="name">agentid</span><span class="punctuation">);</span>
</pre>
<p>Second, the <cite>invagtmodperm</cite> table give a weight to an investigator for a module
on an agent. This model allows for very fine grained permissions management.</p>
<pre class="code sql literal-block">
<span class="keyword">CREATE</span> <span class="keyword">TABLE</span> <span class="name">IF</span> <span class="keyword">NOT</span> <span class="keyword">EXISTS</span> <span class="name">invagtmodperm</span> <span class="punctuation">(</span>
<span class="name">investigatorid</span> <span class="name builtin">numeric</span> <span class="keyword">references</span> <span class="name">investigators</span><span class="punctuation">(</span><span class="name">id</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">agentid</span> <span class="name builtin">numeric</span> <span class="keyword">references</span> <span class="name">agents</span><span class="punctuation">(</span><span class="name">id</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">moduleid</span> <span class="name builtin">numeric</span> <span class="keyword">references</span> <span class="name">modules</span><span class="punctuation">(</span><span class="name">id</span><span class="punctuation">)</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span><span class="punctuation">,</span>
<span class="name">weight</span> <span class="name builtin">integer</span> <span class="keyword">NOT</span> <span class="keyword">NULL</span>
<span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">UNIQUE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">invagtmodperm</span> <span class="punctuation">(</span><span class="name">investigatorid</span><span class="punctuation">,</span> <span class="name">agentid</span><span class="punctuation">,</span> <span class="name">moduleid</span><span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">invagtmodperm</span> <span class="punctuation">(</span><span class="name">investigatorid</span><span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">invagtmodperm</span> <span class="punctuation">(</span><span class="name">agentid</span><span class="punctuation">);</span>
<span class="keyword">CREATE</span> <span class="keyword">INDEX</span> <span class="keyword">ON</span> <span class="name">invagtmodperm</span> <span class="punctuation">(</span><span class="name">moduleid</span><span class="punctuation">);</span>
</pre>
</div>
<div class="section" id="database-creation-script">
<h2><a class="toc-backref" href="#id5">2.3&nbsp;&nbsp;&nbsp;Database creation script</a></h2>
<pre class="code bash literal-block">
<span class="comment">#! /usr/bin/env bash
</span><span class="operator">[</span> ! -x <span class="keyword">$(</span>which sudo<span class="keyword">)</span> <span class="operator">]</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">echo</span> <span class="literal string double">&quot;sudo isn't available, that won't work&quot;</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">exit </span>1
<span class="keyword">for </span>user in <span class="literal string double">&quot;migadmin&quot;</span> <span class="literal string double">&quot;migapi&quot;</span> <span class="literal string double">&quot;migscheduler&quot;</span>; <span class="keyword">do
</span><span class="name variable">pass</span><span class="operator">=</span><span class="keyword">$(</span>&lt; /dev/urandom tr -dc _A-Z-a-z-0-9 | head -c<span class="keyword">${</span><span class="name variable">1</span><span class="keyword">:-</span><span class="name variable">32</span><span class="keyword">})</span>
sudo su postgres -c <span class="literal string double">&quot;psql -c 'CREATE ROLE $user;'&quot;</span> 1&gt;/dev/null
<span class="operator">[</span> <span class="name variable">$?</span> -ne 0 <span class="operator">]</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">echo</span> <span class="literal string double">&quot;ERROR: user creation failed.&quot;</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">exit </span>123
sudo su postgres -c <span class="literal string double">&quot;psql -c \&quot;ALTER ROLE $user WITH NOSUPERUSER INHERIT NOCREATEROLE NOCREATEDB LOGIN PASSWORD '$pass';\&quot;&quot;</span> 1&gt;/dev/null
<span class="operator">[</span> <span class="name variable">$?</span> -ne 0 <span class="operator">]</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">echo</span> <span class="literal string double">&quot;ERROR: user creation failed.&quot;</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">exit </span>123
<span class="name builtin">echo</span> <span class="literal string double">&quot;Created user $user with password '$pass'&quot;</span>
<span class="keyword">done
</span>sudo su postgres -c <span class="literal string double">&quot;psql -c 'CREATE DATABASE mig OWNER migadmin;'&quot;</span> 1&gt;/dev/null
<span class="operator">[</span> <span class="name variable">$?</span> -ne 0 <span class="operator">]</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">echo</span> <span class="literal string double">&quot;ERROR: database creation failed.&quot;</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">exit </span>123
<span class="name variable">createdbtemp</span><span class="operator">=</span><span class="keyword">$(</span>mktemp<span class="keyword">)</span>
cat &gt; <span class="name variable">$createdbtemp</span> <span class="literal string">&lt;&lt; EOF
2014-09-11 07:56:53 +04:00
CREATE TABLE actions (
id numeric NOT NULL,
name character varying(2048) NOT NULL,
target character varying(2048) NOT NULL,
description json,
threat json,
operations json,
validfrom timestamp with time zone NOT NULL,
expireafter timestamp with time zone NOT NULL,
starttime timestamp with time zone,
finishtime timestamp with time zone,
lastupdatetime timestamp with time zone,
status character varying(256),
sentctr integer,
returnedctr integer,
donectr integer,
cancelledctr integer,
failedctr integer,
timeoutctr integer,
pgpsignatures json,
syntaxversion integer
);
ALTER TABLE public.actions OWNER TO migadmin;
ALTER TABLE ONLY actions
ADD CONSTRAINT actions_pkey PRIMARY KEY (id);
CREATE TABLE agents (
id numeric NOT NULL,
name character varying(2048) NOT NULL,
queueloc character varying(2048) NOT NULL,
os character varying(2048) NOT NULL,
version character varying(2048) NOT NULL,
pid integer NOT NULL,
starttime timestamp with time zone NOT NULL,
destructiontime timestamp with time zone,
heartbeattime timestamp with time zone NOT NULL,
status character varying(255),
environment json
);
ALTER TABLE public.agents OWNER TO migadmin;
ALTER TABLE ONLY agents
ADD CONSTRAINT agents_pkey PRIMARY KEY (id);
CREATE INDEX agents_heartbeattime_idx ON agents(heartbeattime DESC);
CREATE INDEX agents_queueloc_pid_idx ON agents(queueloc, pid);
CREATE TABLE agtmodreq (
moduleid numeric NOT NULL,
agentid numeric NOT NULL,
minimumweight integer NOT NULL
);
ALTER TABLE public.agtmodreq OWNER TO migadmin;
CREATE UNIQUE INDEX agtmodreq_moduleid_agentid_idx ON agtmodreq USING btree (moduleid, agentid);
CREATE INDEX agtmodreq_agentid_idx ON agtmodreq USING btree (agentid);
CREATE INDEX agtmodreq_moduleid_idx ON agtmodreq USING btree (moduleid);
CREATE TABLE commands (
id numeric NOT NULL,
actionid numeric NOT NULL,
agentid numeric NOT NULL,
status character varying(255) NOT NULL,
results json,
starttime timestamp with time zone NOT NULL,
finishtime timestamp with time zone
);
ALTER TABLE public.commands OWNER TO migadmin;
ALTER TABLE ONLY commands
ADD CONSTRAINT commands_pkey PRIMARY KEY (id);
CREATE TABLE invagtmodperm (
investigatorid numeric NOT NULL,
agentid numeric NOT NULL,
moduleid numeric NOT NULL,
weight integer NOT NULL
);
ALTER TABLE public.invagtmodperm OWNER TO migadmin;
CREATE UNIQUE INDEX invagtmodperm_investigatorid_agentid_moduleid_idx ON invagtmodperm USING btree (investigatorid, agentid, moduleid);
CREATE INDEX invagtmodperm_agentid_idx ON invagtmodperm USING btree (agentid);
CREATE INDEX invagtmodperm_investigatorid_idx ON invagtmodperm USING btree (investigatorid);
CREATE INDEX invagtmodperm_moduleid_idx ON invagtmodperm USING btree (moduleid);
CREATE TABLE investigators (
id bigserial NOT NULL,
name character varying(1024) NOT NULL,
pgpfingerprint character varying(128),
publickey bytea
);
ALTER TABLE public.investigators OWNER TO migadmin;
ALTER TABLE ONLY investigators
ADD CONSTRAINT investigators_pkey PRIMARY KEY (id);
CREATE UNIQUE INDEX investigators_pgpfingerprint_idx ON investigators USING btree (pgpfingerprint);
CREATE TABLE modules (
id numeric NOT NULL,
name character varying(256) NOT NULL
);
ALTER TABLE public.modules OWNER TO migadmin;
ALTER TABLE ONLY modules
ADD CONSTRAINT modules_pkey PRIMARY KEY (id);
CREATE TABLE signatures (
actionid numeric NOT NULL,
investigatorid numeric NOT NULL,
pgpsignature character varying(4096) NOT NULL
);
ALTER TABLE public.signatures OWNER TO migadmin;
CREATE UNIQUE INDEX signatures_actionid_investigatorid_idx ON signatures USING btree (actionid, investigatorid);
CREATE INDEX signatures_actionid_idx ON signatures USING btree (actionid);
CREATE INDEX signatures_investigatorid_idx ON signatures USING btree (investigatorid);
ALTER TABLE ONLY agtmodreq
ADD CONSTRAINT agtmodreq_moduleid_fkey FOREIGN KEY (moduleid) REFERENCES modules(id);
ALTER TABLE ONLY commands
ADD CONSTRAINT commands_actionid_fkey FOREIGN KEY (actionid) REFERENCES actions(id);
ALTER TABLE ONLY commands
ADD CONSTRAINT commands_agentid_fkey FOREIGN KEY (agentid) REFERENCES agents(id);
ALTER TABLE ONLY invagtmodperm
ADD CONSTRAINT invagtmodperm_agentid_fkey FOREIGN KEY (agentid) REFERENCES agents(id);
ALTER TABLE ONLY invagtmodperm
ADD CONSTRAINT invagtmodperm_investigatorid_fkey FOREIGN KEY (investigatorid) REFERENCES investigators(id);
ALTER TABLE ONLY invagtmodperm
ADD CONSTRAINT invagtmodperm_moduleid_fkey FOREIGN KEY (moduleid) REFERENCES modules(id);
ALTER TABLE ONLY signatures
ADD CONSTRAINT signatures_actionid_fkey FOREIGN KEY (actionid) REFERENCES actions(id);
ALTER TABLE ONLY signatures
ADD CONSTRAINT signatures_investigatorid_fkey FOREIGN KEY (investigatorid) REFERENCES investigators(id);
EOF</span>
chmod 777 <span class="name variable">$createdbtemp</span>
sudo su postgres -c <span class="literal string double">&quot;psql -d mig -f $createdbtemp&quot;</span> 1&gt;/dev/null
<span class="operator">[</span> <span class="name variable">$?</span> -ne 0 <span class="operator">]</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">echo</span> <span class="literal string double">&quot;ERROR: tables creation failed.&quot;</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">exit </span>123
rm <span class="literal string double">&quot;$createdbtemp&quot;</span>
2014-09-11 07:56:53 +04:00
<span class="name variable">granttmp</span><span class="operator">=</span><span class="keyword">$(</span>mktemp<span class="keyword">)</span>
cat &gt; <span class="name variable">$granttmp</span> <span class="literal string">&lt;&lt; EOF
2014-09-11 07:56:53 +04:00
GRANT ALL PRIVILEGES ON DATABASE mig TO migadmin;
\c mig
GRANT SELECT ON ALL TABLES IN SCHEMA public TO migscheduler;
GRANT INSERT, UPDATE ON actions, commands, agents, signatures TO migscheduler;
GRANT SELECT ON ALL TABLES IN SCHEMA public TO migapi;
GRANT INSERT ON actions, signatures TO migapi;
EOF</span>
chmod 777 <span class="name variable">$granttmp</span>
sudo su postgres -c <span class="literal string double">&quot;psql -f $granttmp&quot;</span> 1&gt;/dev/null
<span class="operator">[</span> <span class="name variable">$?</span> -ne 0 <span class="operator">]</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">echo</span> <span class="literal string double">&quot;ERROR: grants failed.&quot;</span> <span class="operator">&amp;&amp;</span> <span class="name builtin">exit </span>123
rm <span class="literal string double">&quot;$granttmp&quot;</span>
<span class="name builtin">echo</span> <span class="literal string double">&quot;MIG Database created successfully.&quot;</span>
</pre>
</div>
</div>
<div class="section" id="queries">
<h1><a class="toc-backref" href="#id6">3&nbsp;&nbsp;&nbsp;Queries</a></h1>
<div class="section" id="adding-investigators">
<h2><a class="toc-backref" href="#id7">3.1&nbsp;&nbsp;&nbsp;Adding Investigators</a></h2>
<p>In the future, this will probably be automated via the API. But for now, and
until we have a strong authentication mechanism for API calls, it must be done
manually in the database.</p>
<p>Adapt the query below to add a new investigator.</p>
<pre class="code sql literal-block">
<span class="keyword">INSERT</span> <span class="keyword">INTO</span> <span class="name">investigators</span> <span class="punctuation">(</span><span class="name">name</span><span class="punctuation">,</span> <span class="name">pgpfingerprint</span><span class="punctuation">)</span>
<span class="keyword">VALUES</span> <span class="punctuation">(</span><span class="literal string single">'Bob Kelso'</span><span class="punctuation">,</span> <span class="literal string single">'E608......'</span><span class="punctuation">);</span>
</pre>
</div>
<div class="section" id="finding-offline-agents">
<h2><a class="toc-backref" href="#id8">3.2&nbsp;&nbsp;&nbsp;Finding offline agents</a></h2>
<p>The following query retrieves a list of agents that have been online over the
last 30 days, but have not sent a heartbeat in the last 5 minutes.</p>
<pre class="code sql literal-block">
<span class="keyword">SELECT</span> <span class="keyword">DISTINCT</span><span class="punctuation">(</span><span class="name">name</span><span class="punctuation">)</span> <span class="keyword">FROM</span> <span class="name">agents</span>
<span class="keyword">WHERE</span> <span class="name">name</span> <span class="keyword">IN</span> <span class="punctuation">(</span>
<span class="keyword">SELECT</span> <span class="keyword">DISTINCT</span><span class="punctuation">(</span><span class="name">name</span><span class="punctuation">)</span> <span class="keyword">FROM</span> <span class="name">agents</span>
<span class="keyword">WHERE</span> <span class="name">heartbeattime</span> <span class="operator">&gt;=</span> <span class="name">NOW</span><span class="punctuation">()</span> <span class="operator">-</span> <span class="name builtin">interval</span> <span class="literal string single">'30 days'</span>
<span class="punctuation">)</span> <span class="keyword">AND</span> <span class="name">name</span> <span class="keyword">NOT</span> <span class="keyword">IN</span> <span class="punctuation">(</span>
<span class="keyword">SELECT</span> <span class="keyword">DISTINCT</span><span class="punctuation">(</span><span class="name">name</span><span class="punctuation">)</span> <span class="keyword">FROM</span> <span class="name">agents</span>
<span class="keyword">WHERE</span> <span class="name">heartbeattime</span> <span class="operator">&gt;=</span> <span class="name">NOW</span><span class="punctuation">()</span> <span class="operator">-</span> <span class="name builtin">interval</span> <span class="literal string single">'5 minutes'</span>
<span class="punctuation">)</span> <span class="keyword">ORDER</span> <span class="keyword">BY</span> <span class="name">name</span><span class="punctuation">;</span>
</pre>
</div>
<div class="section" id="finding-double-agents">
<h2><a class="toc-backref" href="#id9">3.3&nbsp;&nbsp;&nbsp;Finding double agents</a></h2>
<p>Sometimes during upgrades the older agent isn't shut down. You can find these
endpoints with double agents in the database because each agent sends separate
heartbeats for the same endpoint:</p>
<pre class="code sql literal-block">
<span class="keyword">SELECT</span> <span class="keyword">COUNT</span><span class="punctuation">(</span><span class="name">queueloc</span><span class="punctuation">),</span> <span class="name">queueloc</span> <span class="keyword">FROM</span> <span class="name">agents</span>
<span class="keyword">WHERE</span> <span class="name">heartbeattime</span> <span class="operator">&gt;=</span> <span class="name">NOW</span><span class="punctuation">()</span> <span class="operator">-</span> <span class="name builtin">INTERVAL</span> <span class="literal string single">'10 minutes'</span>
<span class="keyword">GROUP</span> <span class="keyword">BY</span> <span class="name">queueloc</span> <span class="keyword">HAVING</span> <span class="keyword">COUNT</span><span class="punctuation">(</span><span class="name">queueloc</span><span class="punctuation">)</span> <span class="operator">&gt;</span> <span class="literal number integer">1</span>
<span class="keyword">ORDER</span> <span class="keyword">BY</span> <span class="keyword">count</span><span class="punctuation">(</span><span class="name">queueloc</span><span class="punctuation">)</span> <span class="keyword">DESC</span><span class="punctuation">;</span>
</pre>
<p>This query will list all the agents sorted by the count of agents heartbeatting
on each endpoint:</p>
<pre class="literal-block">
| count | name
2014-09-11 07:56:53 +04:00
|--------+--------------------------------------
| 3 | puppet3.private.dc1.example.net
| 2 | mv1.mv.example.net
| 2 | memcache1.webapp.dc1.example.net
| 2 | ip2.dc.example.net
| 2 | command.private.corp.dc1.example.net
</pre>
</div>
</div>
</div>
2014-09-11 07:56:53 +04:00
</body>
</html>