Class: PgSlice::Client
- Inherits:
-
Thor
- Object
- Thor
- PgSlice::Client
- Defined in:
- lib/pgslice/client.rb
Constant Summary collapse
- SQL_FORMAT =
{ day: "YYYYMMDD", month: "YYYYMM", year: "YYYY" }
Class Method Summary collapse
Instance Method Summary collapse
- #add_partitions(table) ⇒ Object
- #analyze(table) ⇒ Object
- #fill(table) ⇒ Object
-
#initialize(*args) ⇒ Client
constructor
A new instance of Client.
- #prep(table, column = nil, period = nil) ⇒ Object
- #swap(table) ⇒ Object
- #unprep(table) ⇒ Object
- #unswap(table) ⇒ Object
- #version ⇒ Object
Constructor Details
#initialize(*args) ⇒ Client
Returns a new instance of Client.
20 21 22 23 24 25 |
# File 'lib/pgslice/client.rb', line 20 def initialize(*args) $client = self $stdout.sync = true $stderr.sync = true super end |
Class Method Details
.exit_on_failure? ⇒ Boolean
10 11 12 |
# File 'lib/pgslice/client.rb', line 10 def self.exit_on_failure? true end |
Instance Method Details
#add_partitions(table) ⇒ Object
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 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 |
# File 'lib/pgslice/client.rb', line 123 def add_partitions(table) original_table = qualify_table(table) table = [:intermediate] ? original_table.intermediate_table : original_table trigger_name = original_table.trigger_name abort "Table not found: #{table}" unless table.exists? future = [:future] past = [:past] range = (-1 * past)..future period, field, cast, needs_comment, declarative = settings_from_trigger(original_table, table) unless period = "No settings found: #{table}" = "#{}\nDid you mean to use --intermediate?" unless [:intermediate] abort end queries = [] if needs_comment queries << "COMMENT ON TRIGGER #{quote_ident(trigger_name)} ON #{quote_table(table)} is 'column:#{field},period:#{period},cast:#{cast}';" end # today = utc date today = round_date(DateTime.now.new_offset(0).to_date, period) schema_table = if !declarative table elsif [:intermediate] original_table else Table.new(original_table.existing_partitions(period).last) end # indexes automatically propagate in Postgres 11+ index_defs = if !declarative || server_version_num < 110000 schema_table.index_defs else [] end fk_defs = schema_table.foreign_keys primary_key = schema_table.primary_key added_partitions = [] range.each do |n| day = advance_date(today, period, n) partition_name = Table.new("#{original_table}_#{day.strftime(name_format(period))}") next if partition_name.exists? added_partitions << partition_name.to_s if declarative queries << <<-SQL CREATE TABLE #{quote_table(partition_name)} PARTITION OF #{quote_table(table)} FOR VALUES FROM (#{sql_date(day, cast, false)}) TO (#{sql_date(advance_date(day, period, 1), cast, false)}); SQL else queries << <<-SQL CREATE TABLE #{quote_table(partition_name)} (CHECK (#{quote_ident(field)} >= #{sql_date(day, cast)} AND #{quote_ident(field)} < #{sql_date(advance_date(day, period, 1), cast)})) INHERITS (#{quote_table(table)}); SQL end queries << "ALTER TABLE #{quote_table(partition_name)} ADD PRIMARY KEY (#{primary_key.map { |k| quote_ident(k) }.join(", ")});" if primary_key.any? index_defs.each do |index_def| queries << index_def.sub(/ ON \S+ USING /, " ON #{quote_table(partition_name)} USING ").sub(/ INDEX .+ ON /, " INDEX ON ") + ";" end fk_defs.each do |fk_def| queries << "ALTER TABLE #{quote_table(partition_name)} ADD #{fk_def};" end end unless declarative # update trigger based on existing partitions current_defs = [] future_defs = [] past_defs = [] name_format = self.name_format(period) existing_tables = original_table.existing_partitions(period) existing_tables = (existing_tables + added_partitions).uniq.sort existing_tables.each do |existing_table| day = DateTime.strptime(existing_table.split("_").last, name_format) partition_name = "#{original_table}_#{day.strftime(name_format(period))}" sql = "(NEW.#{quote_ident(field)} >= #{sql_date(day, cast)} AND NEW.#{quote_ident(field)} < #{sql_date(advance_date(day, period, 1), cast)}) THEN INSERT INTO #{quote_table(partition_name)} VALUES (NEW.*);" if day.to_date < today past_defs << sql elsif advance_date(day, period, 1) < today current_defs << sql else future_defs << sql end end # order by current period, future periods asc, past periods desc trigger_defs = current_defs + future_defs + past_defs.reverse if trigger_defs.any? queries << <<-SQL CREATE OR REPLACE FUNCTION #{quote_ident(trigger_name)}() RETURNS trigger AS $$ BEGIN IF #{trigger_defs.join("\n ELSIF ")} ELSE RAISE EXCEPTION 'Date out of range. Ensure partitions are created.'; END IF; RETURN NULL; END; $$ LANGUAGE plpgsql; SQL end end run_queries(queries) if queries.any? end |
#analyze(table) ⇒ Object
397 398 399 400 401 402 403 404 |
# File 'lib/pgslice/client.rb', line 397 def analyze(table) table = qualify_table(table) parent_table = [:swapped] ? table : table.intermediate_table existing_tables = table.existing_partitions analyze_list = existing_tables + [parent_table] run_queries_without_transaction(analyze_list.map { |t| "ANALYZE VERBOSE #{quote_table(t)};" }) end |
#fill(table) ⇒ Object
256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 |
# File 'lib/pgslice/client.rb', line 256 def fill(table) table = qualify_table(table) source_table = qualify_table([:source_table]) if [:source_table] dest_table = qualify_table([:dest_table]) if [:dest_table] if [:swapped] source_table ||= table.retired_table dest_table ||= table else source_table ||= table dest_table ||= table.intermediate_table end abort "Table not found: #{source_table}" unless source_table.exists? abort "Table not found: #{dest_table}" unless dest_table.exists? period, field, cast, _needs_comment, declarative = settings_from_trigger(table, dest_table) if period name_format = self.name_format(period) existing_tables = table.existing_partitions(period) if existing_tables.any? starting_time = DateTime.strptime(existing_tables.first.split("_").last, name_format) ending_time = advance_date(DateTime.strptime(existing_tables.last.split("_").last, name_format), period, 1) end end schema_table = period && declarative ? Table.new(existing_tables.last) : table primary_key = schema_table.primary_key[0] abort "No primary key" unless primary_key max_source_id = nil begin max_source_id = source_table.max_id(primary_key) rescue PG::UndefinedFunction abort "Only numeric primary keys are supported" end max_dest_id = if [:start] [:start] elsif [:swapped] dest_table.max_id(primary_key, where: [:where], below: max_source_id) else dest_table.max_id(primary_key, where: [:where]) end if max_dest_id == 0 && ![:swapped] min_source_id = source_table.min_id(primary_key, field, cast, starting_time, [:where]) max_dest_id = min_source_id - 1 if min_source_id end starting_id = max_dest_id fields = source_table.columns.map { |c| quote_ident(c) }.join(", ") batch_size = [:batch_size] i = 1 batch_count = ((max_source_id - starting_id) / batch_size.to_f).ceil if batch_count == 0 log_sql "/* nothing to fill */" end while starting_id < max_source_id where = "#{quote_ident(primary_key)} > #{starting_id} AND #{quote_ident(primary_key)} <= #{starting_id + batch_size}" if starting_time where << " AND #{quote_ident(field)} >= #{sql_date(starting_time, cast)} AND #{quote_ident(field)} < #{sql_date(ending_time, cast)}" end if [:where] where << " AND #{[:where]}" end query = <<-SQL /* #{i} of #{batch_count} */ INSERT INTO #{quote_table(dest_table)} (#{fields}) SELECT #{fields} FROM #{quote_table(source_table)} WHERE #{where} SQL run_query(query) starting_id += batch_size i += 1 if [:sleep] && starting_id <= max_source_id sleep([:sleep]) end end end |
#prep(table, column = nil, period = nil) ⇒ Object
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 |
# File 'lib/pgslice/client.rb', line 30 def prep(table, column=nil, period=nil) table = qualify_table(table) intermediate_table = table.intermediate_table trigger_name = table.trigger_name unless [:partition] abort "Usage: \"pgslice prep TABLE --no-partition\"" if column || period abort "Can't use --trigger-based and --no-partition" if [:trigger_based] end abort "Table not found: #{table}" unless table.exists? abort "Table already exists: #{intermediate_table}" if intermediate_table.exists? if [:partition] abort "Usage: \"pgslice prep TABLE COLUMN PERIOD\"" if !(column && period) abort "Column not found: #{column}" unless table.columns.include?(column) abort "Invalid period: #{period}" unless SQL_FORMAT[period.to_sym] end queries = [] declarative = server_version_num >= 100000 && ![:trigger_based] if declarative && [:partition] queries << <<-SQL CREATE TABLE #{quote_table(intermediate_table)} (LIKE #{quote_table(table)} INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING STORAGE INCLUDING COMMENTS) PARTITION BY RANGE (#{quote_table(column)}); SQL if server_version_num >= 110000 index_defs = table.index_defs index_defs.each do |index_def| queries << index_def.sub(/ ON \S+ USING /, " ON #{quote_table(intermediate_table)} USING ").sub(/ INDEX .+ ON /, " INDEX ON ") + ";" end end # add comment cast = table.column_cast(column) queries << <<-SQL COMMENT ON TABLE #{quote_table(intermediate_table)} is 'column:#{column},period:#{period},cast:#{cast}'; SQL else queries << <<-SQL CREATE TABLE #{quote_table(intermediate_table)} (LIKE #{quote_table(table)} INCLUDING ALL); SQL table.foreign_keys.each do |fk_def| queries << "ALTER TABLE #{quote_table(intermediate_table)} ADD #{fk_def};" end end if [:partition] && !declarative queries << <<-SQL CREATE FUNCTION #{quote_ident(trigger_name)}() RETURNS trigger AS $$ BEGIN RAISE EXCEPTION 'Create partitions first.'; END; $$ LANGUAGE plpgsql; SQL queries << <<-SQL CREATE TRIGGER #{quote_ident(trigger_name)} BEFORE INSERT ON #{quote_table(intermediate_table)} FOR EACH ROW EXECUTE PROCEDURE #{quote_ident(trigger_name)}(); SQL cast = table.column_cast(column) queries << <<-SQL COMMENT ON TRIGGER #{quote_ident(trigger_name)} ON #{quote_table(intermediate_table)} is 'column:#{column},period:#{period},cast:#{cast}'; SQL end run_queries(queries) end |
#swap(table) ⇒ Object
350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 |
# File 'lib/pgslice/client.rb', line 350 def swap(table) table = qualify_table(table) intermediate_table = table.intermediate_table retired_table = table.retired_table abort "Table not found: #{table}" unless table.exists? abort "Table not found: #{intermediate_table}" unless intermediate_table.exists? abort "Table already exists: #{retired_table}" if retired_table.exists? queries = [ "ALTER TABLE #{quote_table(table)} RENAME TO #{quote_no_schema(retired_table)};", "ALTER TABLE #{quote_table(intermediate_table)} RENAME TO #{quote_no_schema(table)};" ] table.sequences.each do |sequence| queries << "ALTER SEQUENCE #{quote_ident(sequence["sequence_name"])} OWNED BY #{quote_table(table)}.#{quote_ident(sequence["related_column"])};" end queries.unshift("SET LOCAL lock_timeout = '#{[:lock_timeout]}';") if server_version_num >= 90300 run_queries(queries) end |
#unprep(table) ⇒ Object
105 106 107 108 109 110 111 112 113 114 115 116 117 |
# File 'lib/pgslice/client.rb', line 105 def unprep(table) table = qualify_table(table) intermediate_table = table.intermediate_table trigger_name = table.trigger_name abort "Table not found: #{intermediate_table}" unless intermediate_table.exists? queries = [ "DROP TABLE #{quote_table(intermediate_table)} CASCADE;", "DROP FUNCTION IF EXISTS #{quote_ident(trigger_name)}();" ] run_queries(queries) end |
#unswap(table) ⇒ Object
374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 |
# File 'lib/pgslice/client.rb', line 374 def unswap(table) table = qualify_table(table) intermediate_table = table.intermediate_table retired_table = table.retired_table abort "Table not found: #{table}" unless table.exists? abort "Table not found: #{retired_table}" unless retired_table.exists? abort "Table already exists: #{intermediate_table}" if intermediate_table.exists? queries = [ "ALTER TABLE #{quote_table(table)} RENAME TO #{quote_no_schema(intermediate_table)};", "ALTER TABLE #{quote_table(retired_table)} RENAME TO #{quote_no_schema(table)};" ] table.sequences.each do |sequence| queries << "ALTER SEQUENCE #{quote_ident(sequence["sequence_name"])} OWNED BY #{quote_table(table)}.#{quote_ident(sequence["related_column"])};" end run_queries(queries) end |