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
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
247
248
249
250
251
252
253
254
255
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
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
CREATE OR REPLACE FUNCTION tools.change_polling_record_differences_perl( 
	target_table_id INTEGER, 
	run_instance_id INTEGER
)
RETURNS polling_record_differences_result AS $$
	BEGIN { strict->import(); }
	#use Data::Dumper;
	
	#  Get all the relevant parameters from change_polling_meta_info_and_status
	#  and cs_materialized_views before invoking the more specific version of this function:
	
	#	FUNCTION tools.change_polling_record_differences_perl( 
	#		target_table_id INTEGER, 
	#		run_instance_id INTEGER,
	#		target_mv_id INTEGER,
	#		target_mv_schema_name TEXT,  
	#		target_mv_name TEXT, 	 
	#		target_schema_name TEXT,  
	#		target_table_name TEXT
	#	)
	#	RETURNS polling_record_differences_result

	#  SAMPLE USAGE
	#	
	#   SELECT * FROM tools.change_polling_record_differences(3 , 467);
	#
	#    The target_table_id corresponds to the monitored_table_id field
	#	 of table tools.change_polling_meta_info_and_status
	#
	#	 The run_instance_id is a unique value for each invocation generated from
	#    the sequence tools.change_polling_processing_log_run_instance_id_seq.
	#
  	
	my ($target_table_id, $run_instance_id) = @_;
	my $rv  = {};
	my $sql_command_text = "SELECT  monitored_table_schema, monitored_table_name, " 
       	. "mv_schema, mv_name, mat_views_id, latest_run_instance_id "
       	. "FROM tools.change_polling_meta_info_and_status "
	    . "WHERE monitored_table_id = " 
	    . $target_table_id;
  
    $rv = spi_exec_query($sql_command_text);
    
    if($rv->{processed} > 0){
    	#elog( DEBUG, "monitored table info = " . Dumper($rv) );
    	my $r = $rv->{rows}[0];
    	#elog(DEBUG, " = " . Dumper($rv) );
    	my $target_schema_name = $r->{'monitored_table_schema'};
    	my $target_table_name = $r->{'monitored_table_name'};
    	my $target_mv_schema_name = $r->{'mv_schema'};
		my $target_mv_name	= $r->{'mv_name'};
		my $target_mv_id = $r->{'mat_views_id'};
		my $latest_run_instance_id = $r->{'latest_run_instance_id'};
		# Invoke the more specific version of the function.
    
		$sql_command_text = "SELECT * FROM tools.change_polling_record_differences_perl("
				. $target_table_id . ","
				. $run_instance_id . ","
				. $target_mv_id. ","
				. "'$target_mv_schema_name',"
				. "'$target_mv_name',"
				. "'$target_schema_name',"
				. "'$target_table_name')";
    }
    else {
    		elog( ERROR, "Can't find needed information to monitor this table" );
    }
    $rv = spi_exec_query($sql_command_text);
    return $rv->{rows}[0];
	
$$ LANGUAGE 'plperl';


CREATE OR REPLACE FUNCTION tools.change_polling_record_differences_perl( 
	target_table_id INTEGER, 
	run_instance_id INTEGER,
	target_mv_id INTEGER,
	target_mv_schema_name TEXT,  
	target_mv_name TEXT, 	 
	target_schema_name TEXT,  
	target_table_name TEXT
)
RETURNS polling_record_differences_result AS $$

	BEGIN { strict->import(); }
	#use Data::Dumper;

# SAMPLE USAGE
#
#   SELECT * FROM tools.change_polling_record_differences(
#	3, 
#	467,
#	26,
#	'matviews',
#	'my_poll_mv', 
#	'public', 
#	'joe_project_expense');


# 1. Find the differences between the newest and previous versions of the materialized view
# table that represents the 'monitored table' as defined by the target_schema_name
# and target_table_name parameters.
# 2. Record the differences, delinated by the type of
# difference - INSERT, UPDATE, or DELETE - into a pair of data change event tables,
# and a table-specific history table.
# Return as a BOOLEAN whether any difference between the two versions of the
# materialized view was detected and how many row changes were of a certain type. 

	# ASSUME that these two tables exist where we will store the data:
	#   tools.data_change_events
	#   tools.data_change_event_details
		
	# ASSUME a history table exists for the monitored table - of the form:
	#  $target_mv_name . '_hist';

# As generated by the tools.cs_refresh_mviews(integer) function, if the target_mv_name
# were 'my_materialized_view', then the names of the newest and previous versions of
# that table where data is stored would be 'my_materialized_view' and
# 'my_materialized_view0', respectively.

# For a monitored table, add entries for a changed record to a pair of event tables.
	my ($target_table_id, $run_instance_id,	$target_mv_id, $target_mv_schema_name, $target_mv_name,$target_schema_name, $target_table_name) = @_;

	my $event_table   = 'tools.data_change_events';
	my $details_table = 'tools.data_change_event_details';
	my $mv_schema     = $target_mv_schema_name;
	my $newer_mv_name = $target_mv_name;
	my $older_mv_name = $target_mv_name . '0';
	my $history_table = $target_mv_name . '_hist';
	my %one_row       = {};
	my $one_key       = "";
	my $primary_keys  = "";
	my @primary_keys_list  = ();
	my %changed_row;
	my $sql_command_text = "";
	my $change_detected  = 0;
	my $rv               = {};

	# Abort with an ERROR if the needed tables don't exist.
	
	$sql_command_text =
	  "SELECT * FROM tools.does_table_exist('$mv_schema', '$older_mv_name')";
	$rv = spi_exec_query($sql_command_text);
	if ( $rv->{rows}[0]->{'does_table_exist'} eq 'f' ) {
		elog( ERROR,
			    "Change Poller: Older MV copy = "
			  . $older_mv_name
			  . " DOES NOT EXIST" );
	}

	$sql_command_text =
	  "SELECT * FROM tools.does_table_exist('$mv_schema', '$newer_mv_name')";
	$rv = spi_exec_query($sql_command_text);
	if ( $rv->{rows}[0]->{'does_table_exist'} eq 'f' ) {
		elog( ERROR,
			    "Change Poller: Newer MV copy = "
			  . $newer_mv_name
			  . " DOES NOT EXIST" );
	}

	$sql_command_text =
	  "SELECT * FROM tools.get_primary_keys('$mv_schema','$newer_mv_name')";
	$rv = spi_exec_query($sql_command_text);

	# elog(DEBUG,"tools.get_primary_keys =". Dumper(\$rv));
    
	foreach my $one_row ( @{ $rv->{rows} } ) {		
		$one_key = $one_row->{'get_primary_keys'};
		$primary_keys .= $one_key . ",";
		push(@primary_keys_list,$one_key);
	}
	chop($primary_keys);

	# elog(DEBUG,"primary keys=$primary_keys");

	# Get a list of the column names for the polled table
	$sql_command_text =
	    "SELECT column_name FROM information_schema.columns "
	  . "WHERE table_schema='"
	  . $mv_schema . "' "
	  . "AND table_name='"
	  . $newer_mv_name . "' "
	  . "ORDER BY ordinal_position";
	$rv = spi_exec_query($sql_command_text);
	my @cols = map { $_->{column_name} } @{ $rv->{rows} };

	# Get the user name
	$sql_command_text = "SELECT session_user";
	$rv               = spi_exec_query($sql_command_text);
	my $user = $rv->{rows}->[0]->{session_user};
		
	######################################
	# _escape_sql
	# used for text data that is going to be put into an sql table # can't ==> 'can''t'
	# <empty> ==> NULL
	my $escape_sql =
		sub {
    		my ($s) = @_;
    		$s =~ s/\'/\'\'/g;
    		return $s ? "'$s'" : "NULL";
		};

	# Define subroutine for recording differences between old and new versions of a row
	my $record_changes = 
	sub {			
		my ($action_id, $sql_query_new_rows, $sql_query_old_rows) = @_;
		my $new_rv = {};
		my $old_rv = {};
		my $num_affected_rows = 0;
		elog(DEBUG, "Action=" . $action_id."\n");
		#elog(DEBUG, "New rows query=" . $sql_query_new_rows."\n");
		#elog(DEBUG, "Old rows query=" . $sql_query_old_rows ."\n");
					
		# Get new version of rows
		if($sql_query_new_rows){
			$new_rv = spi_exec_query($sql_query_new_rows);
			$num_affected_rows = $new_rv->{processed};
		}
		else {
			undef($new_rv);
		}
		
		#Get old version of rows
		if($sql_query_old_rows){
			$old_rv = spi_exec_query($sql_query_old_rows);
			$num_affected_rows = $old_rv->{processed};
		}
		else {
			undef($old_rv);
		}		
		# Process each affected row.
		for ( my $row_index = 0 ; $row_index < $num_affected_rows ; $row_index++ ) {
			my $newer_row = "";
			my $older_row = "";
			# The $changed_row contains the values we will save in the history table.
			my $changed_row = "";
			if(defined($new_rv)){
				$newer_row = $new_rv->{rows}[$row_index];
				#elog(DEBUG, "NEWER ROW = " . Dumper($newer_row) );
			}
			if(defined($old_rv)){
				$older_row = $old_rv->{rows}[$row_index];
				#elog(DEBUG, "OLDER ROW = " . Dumper($older_row) );
			}
			if(defined($new_rv)){
				$changed_row = $newer_row;
			}
			else {
				# In the case of DELETE's, there is no newer row to work with.
				$changed_row = $older_row;
			}
			
			my $primary_key_values = "";
			foreach my $pk (@primary_keys_list) {	
				my $v = $changed_row->{$pk};
				$v =~ s/\'/\'\'/g;
				$v =~ s/\\/\\\\/g;
				$primary_key_values .= "'$v',";

			}
			chop($primary_key_values);

			# Find the latest version for the row.
			my $new_version = 0;
			my $version_sql = "SELECT change_version FROM $mv_schema.$history_table "
		  		. " WHERE ($primary_keys) = ($primary_key_values) "
				. " ORDER BY change_version DESC LIMIT 1";
			
			elog(DEBUG,"Get version command = " . $version_sql);
			my $version_rv = spi_exec_query($version_sql);
	    	#elog(DEBUG, "Previous Version, raw result value = " . Dumper($version_rv) );
			my $old_version = $version_rv->{rows}->[0]->{change_version};
			elog(DEBUG, "Previous Version = " . $old_version );
		
			if(defined($old_version)) {
		  		$new_version = $old_version + 1;
		  		elog(DEBUG, "Previous Version defined. New version= " . $new_version );
			}

			# Add an entry to the $event_table for the newly detected event
			my $event_query = "($primary_keys) = ($primary_key_values)";
			#my $event_query = "\($primary_keys\) = \($primary_key_values\)";		
			my $escaped_event_query = $escape_sql->($event_query);
			
			my $sql_insert_event_command =
		  	  "INSERT INTO "
		 	 . $event_table
			  . "(event_type, event_source_id, originating_event, event_time, database_user, monitored_schema, monitored_table, event_text, event_query, change_version)"
			  . " VALUES ("
			  . "'p', "
			  . "'$run_instance_id' , "
			  . "'CHANGE POLLING', "
			  . "now(), "
			  . "'$user', "
			  . "'$target_schema_name', "
			  . "' $target_table_name', "
			  . "'$action_id', "
			  . "$escaped_event_query, "
			  . "'$new_version' "
			  . ") RETURNING event_id ";
			#	E'$primary_key_values'
			#  . "E'($primary_keys) = ($primary_key_values)', "
			
			elog(DEBUG,"Ugly command follows:".$sql_insert_event_command);
			
			my $insert_event_command_rv = spi_exec_query($sql_insert_event_command);

			# Extract the primary key for the just inserted row.
			my $event_id = $insert_event_command_rv->{rows}->[0]->{event_id};

			# Insert a row to the data_change_details table
			# for each changed field/column.

			# TODO
			#   Batch all these inserts into one INSERT statement
			#   Add an index on the $details_table for the foreign key event_id.

			foreach my $column (@cols) {
				my $new_value;
				my $old_value;
			
				if(defined($new_rv)){
					$new_value = $newer_row->{$column};
					$new_value =~ s/\'/\'\'/g;
					$new_value =~ s/\\/\\\\/g;
				}
				else {
					$new_value = 'NULL';
				}
				if(defined($old_rv)){
					$old_value = $older_row->{$column};
					$old_value =~ s/\'/\'\'/g;
					$old_value =~ s/\\/\\\\/g;
				}
				else {
					$old_value = 'NULL';
				}

				if ( $new_value ne $old_value ) {

			   		# elog(DEBUG,"INSERTED field = " . $column . " with value = " . $new_value );
					$sql_insert_event_command =
					    "INSERT INTO $details_table " . "("
					  . "column_name, old_val, new_val, fkey_event_id) "
					  . "VALUES ( "
					  . "'$column', "
				  	. "E'$old_value', "
				  	. "E'$new_value', "
				  	. "$event_id " . ")";
					spi_exec_query($sql_insert_event_command);
				}
			}

			# Add an entry to the $history_table for the newly detected event.
		
			my $sql_insert_history_command = "INSERT INTO $mv_schema.$history_table (";
			my $sql_insert_history_command_part_2 = ") VALUES (";
			foreach my $column (@cols) {
				my $value = $changed_row->{$column};

				if(defined($value)){
					# elog(DEBUG,"INSERTED field = " . $column . " with value = " . $value );
					$sql_insert_history_command .= "$column, ";
					#$sql_insert_history_command .= "'$column', ";
					
					$value =~ s/\'/\'\'/g;
					$value =~ s/\\/\\\\/g;
					#$sql_insert_history_command_part_2 .= "'$value', ";

					$sql_insert_history_command_part_2 .= "E'$value', ";
				}
				else {
					elog(DEBUG,"No value defined for field = " . $column);
				}

			}
			my $combined_insert_history_command = $sql_insert_history_command 
											. "change_type, change_version"
											. $sql_insert_history_command_part_2
											."'$action_id', $new_version)";
			elog(DEBUG,"INSERT History command = " . $combined_insert_history_command);									
			spi_exec_query($combined_insert_history_command);
		}
		elog(DEBUG, "Number of Rows=" . $num_affected_rows."\n");
		return $num_affected_rows;
	};
	
	# Fetch and process INSERT'd rows
	my $action = 'I';
	my $query_new_rows =
	    "SELECT * FROM $mv_schema.$newer_mv_name"
	  . " WHERE ($primary_keys) NOT IN"
	  . " (SELECT $primary_keys FROM $mv_schema.$older_mv_name"
	  . " WHERE ($primary_keys) IS NOT NULL)";

	my $query_old_rows = ""; # Or undefined		
	my $num_inserted_rows = $record_changes->($action, $query_new_rows, $query_old_rows);

	# Fetch and process UPDATE'd rows
	$action = 'U';
	$query_new_rows = "SELECT * FROM $mv_schema.$newer_mv_name"
	  . " WHERE ($primary_keys) IN"
	  . " (SELECT $primary_keys FROM $mv_schema.$older_mv_name"
	  . " WHERE ($primary_keys) IS NOT NULL)"
	  . " EXCEPT SELECT * FROM $mv_schema.$older_mv_name";
	$query_old_rows = "SELECT * FROM $mv_schema.$older_mv_name"
	  . " WHERE ($primary_keys) IN"
	  . " (SELECT $primary_keys FROM $mv_schema.$newer_mv_name"
	  . " WHERE ($primary_keys) IS NOT NULL)"
	  . " EXCEPT SELECT * FROM $mv_schema.$newer_mv_name";		
	my $num_updated_rows = $record_changes->($action, $query_new_rows, $query_old_rows);
	
	# Fetch and process DELETE'd rows
	$action = 'D';
	$query_new_rows = "";
	$query_old_rows = "SELECT * FROM $mv_schema.$older_mv_name"
	  . " WHERE ($primary_keys) NOT IN"
	  . " (SELECT $primary_keys FROM $mv_schema.$newer_mv_name"
	  . " WHERE ($primary_keys) IS NOT NULL)";		
	my $num_deleted_rows = $record_changes->($action, $query_new_rows, $query_old_rows);
    
	if(($num_inserted_rows + $num_updated_rows + $num_deleted_rows) > 0 ){
		$change_detected = 1;
	}
	else {
		$change_detected = 0;
	}

	return {
		executed_without_error => 1,
		change_detected => $change_detected,
		inserted_count => $num_inserted_rows,
		updated_count => $num_updated_rows,
		deleted_count => $num_deleted_rows};
		
$$ LANGUAGE 'plperl'  SECURITY DEFINER;


ALTER FUNCTION tools.change_polling_record_differences_perl(integer, integer) OWNER TO finance;
GRANT EXECUTE ON FUNCTION tools.change_polling_record_differences_perl(integer, integer) OWNER TO slangley;
GRANT EXECUTE ON FUNCTION tools.change_polling_record_differences_perl(integer, integer, integer, text, text, text, text) TO finance;