1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
|
# encoding: UTF-8
#-- vim:sw=2:et
#++
#
# :title: journal backend for postgresql
require 'pg'
require 'json'
# as a replacement for CREATE INDEX IF NOT EXIST that is not in postgres.
# define function to be able to create an index in case it doesnt exist:
# source: http://stackoverflow.com/a/26012880
CREATE_INDEX = <<-EOT
CREATE OR REPLACE FUNCTION create_index(table_name text, index_name text, column_name text) RETURNS void AS $$
declare
l_count integer;
begin
select count(*)
into l_count
from pg_indexes
where schemaname = 'public'
and tablename = lower(table_name)
and indexname = lower(index_name);
if l_count = 0 then
execute 'create index ' || index_name || ' on ' || table_name || '(' || column_name || ')';
end if;
end;
$$ LANGUAGE plpgsql;
EOT
module Irc
class Bot
module Journal
module Storage
class PostgresStorage < AbstractStorage
attr_reader :conn
def initialize(opts={})
@uri = opts[:uri] || 'postgresql://localhost/rbot'
@conn = PG.connect(@uri)
@conn.exec('set client_min_messages = warning')
@conn.exec(CREATE_INDEX)
@version = @conn.exec('SHOW server_version;')[0]['server_version']
@version.gsub!(/^(\d+\.\d+)$/, '\1.0')
log 'journal storage: postgresql connected to version: ' + @version
version = @version.split('.')[0,3].join.to_i
if version < 930
raise StorageError.new(
'PostgreSQL Version too old: %s, supported: >= 9.3' % [@version])
end
@jsonb = (version >= 940)
log 'journal storage: no jsonb support, consider upgrading postgres' unless @jsonb
drop if opts[:drop]
create_table
create_index('topic_index', 'topic')
end
def create_table
@conn.exec('
CREATE TABLE IF NOT EXISTS journal
(id UUID PRIMARY KEY,
topic TEXT NOT NULL,
timestamp TIMESTAMP WITH TIME ZONE NOT NULL,
payload %s NOT NULL)' % [@jsonb ? 'JSONB' : 'JSON'])
end
def create_index(index_name, column_name)
debug 'journal postges backend: create index %s for %s' % [
index_name, column_name]
@conn.exec_params('SELECT create_index($1, $2, $3)', [
'journal', index_name, column_name])
end
def create_payload_index(key)
index_name = 'idx_payload_' + key.gsub('.', '_')
column = sql_payload_selector(key)
create_index(index_name, column)
end
def ensure_index(key)
create_payload_index(key)
end
def insert(m)
@conn.exec_params('INSERT INTO journal VALUES ($1, $2, $3, $4);',
[m.id, m.topic, m.timestamp, JSON.generate(m.payload)])
end
def find(query=nil, limit=100, offset=0)
if query
sql, params = query_to_sql(query)
sql = 'SELECT * FROM journal WHERE ' + sql + ' LIMIT %d OFFSET %d' % [limit.to_i, offset.to_i]
else
sql = 'SELECT * FROM journal LIMIT %d OFFSET %d' % [limit.to_i, offset.to_i]
params = []
end
res = @conn.exec_params(sql, params)
res.map do |row|
timestamp = DateTime.strptime(row['timestamp'], '%Y-%m-%d %H:%M:%S%z')
JournalMessage.new(id: row['id'], timestamp: timestamp,
topic: row['topic'], payload: JSON.parse(row['payload']))
end
end
# returns the number of messages that match the query
def count(query=nil)
if query
sql, params = query_to_sql(query)
sql = 'SELECT COUNT(*) FROM journal WHERE ' + sql
else
sql = 'SELECT COUNT(*) FROM journal'
params = []
end
res = @conn.exec_params(sql, params)
res[0]['count'].to_i
end
def remove(query=nil)
if query
sql, params = query_to_sql(query)
sql = 'DELETE FROM journal WHERE ' + sql
else
sql = 'DELETE FROM journal;'
params = []
end
res = @conn.exec_params(sql, params)
end
def drop
@conn.exec('DROP TABLE journal;') rescue nil
end
def sql_payload_selector(key)
selector = 'payload'
k = key.to_s.split('.')
k.each_index { |i|
if i >= k.length-1
selector += '->>\'%s\'' % [@conn.escape_string(k[i])]
else
selector += '->\'%s\'' % [@conn.escape_string(k[i])]
end
}
selector
end
def query_to_sql(query)
params = []
placeholder = Proc.new do |value|
params << value
'$%d' % [params.length]
end
sql = {op: 'AND', list: []}
# ID query OR condition
unless query.id.empty?
sql[:list] << {
op: 'OR',
list: query.id.map { |id|
'id = ' + placeholder.call(id)
}
}
end
# Topic query OR condition
unless query.topic.empty?
sql[:list] << {
op: 'OR',
list: query.topic.map { |topic|
'topic ILIKE ' + placeholder.call(topic.gsub('*', '%'))
}
}
end
# Timestamp range query AND condition
if query.timestamp[:from] or query.timestamp[:to]
list = []
if query.timestamp[:from]
list << 'timestamp >= ' + placeholder.call(query.timestamp[:from])
end
if query.timestamp[:to]
list << 'timestamp <= ' + placeholder.call(query.timestamp[:to])
end
sql[:list] << {
op: 'AND',
list: list
}
end
# Payload query
unless query.payload.empty?
list = []
query.payload.each_pair do |key, value|
selector = sql_payload_selector(key)
list << selector + ' = ' + placeholder.call(value)
end
sql[:list] << {
op: 'OR',
list: list
}
end
sql = sql[:list].map { |stmt|
'(' + stmt[:list].join(' %s ' % [stmt[:op]]) + ')'
}.join(' %s ' % [sql[:op]])
[sql, params]
end
end
end
end # Journal
end # Bot
end # Irc
|