May 3, 2023 at 5:51 pm
One of the tasks I perform monthly involves taking the contents of a table, and basically dumping the contents into the same table on another server - that has no direct connection to the first server, and no direct connection is allowed for reasons.
What I've been doing is just going into the Generate Scripts inside of SSMS on the first server, picking the table, and in the settings telling it to generate the data but not the schema. This generates the insert scripts, which I save as a file and then run the script on the second server.
Easy enough. But I am laz... er, I mean I am looking to be more efficient. I was wondering, is there a way to easily do this via T-SQL? Like an undocumented stored procedure where you'd give it the name of the table and tell it "data" and it generates the script? Or has anyone written something or come across something that does this?
I've been thinking of trying it myself, but was curious what other folks around these parts might know.
May 4, 2023 at 11:47 am
Have a look at Copy-DBATable of the ( free ) DBATools module in Powershell
Johan
Learn to play, play to learn !
Dont drive faster than your guardian angel can fly ...
but keeping both feet on the ground wont get you anywhere :w00t:
- How to post Performance Problems
- How to post data/code to get the best help[/url]
- How to prevent a sore throat after hours of presenting ppt
press F1 for solution, press shift+F1 for urgent solution 😀
Need a bit of Powershell? How about this
Who am I ? Sometimes this is me but most of the time this is me
May 4, 2023 at 1:19 pm
Why not take a backup, transfer that, restore it? I'm lazy too.
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
- Theodore Roosevelt
Author of:
SQL Server Execution Plans
SQL Server Query Performance Tuning
May 4, 2023 at 9:25 pm
Well - you obviously have access to both instances. Is that access from the same workstation - or do you need to access the other instance through a different method?
Assuming access to both - you could use one of the following methods:
Jeffrey Williams
“We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”
― Charles R. Swindoll
How to post questions to get better answers faster
Managing Transaction Logs
May 4, 2023 at 11:49 pm
I just use BCP OUT using the Native format and then either BCP or BULK INSERT to import it on the target. Obviously, there needs to be a folder somewhere that both can "see".
--Jeff Moden
Change is inevitable... Change for the better is not.
May 5, 2023 at 10:35 am
Can't remember where I got this script from but it will generate insert statements for all the rows in a table:
To generate inserts from a table just call it something like this:
EXEC INFGenerateInserts @table_name='MyTable';
-- ***********************************************************************************************************
-- Procedure: INFGenerateInserts
--
-- Purpose: To generate INSERT statements from existing data.
-- These INSERTS can be executed to regenerate the data at some other location.
-- This procedure is also useful to create a database setup, where in you can
-- script your data along with your table definitions.
--
-- NOTE: This procedure may not work with tables with too many columns.
-- Results can be unpredictable with huge text columns or SQL Server 2000's sql_variant data types
-- Whenever possible, Use @include_column_list parameter to ommit column list in the INSERT statement, for better results
-- IMPORTANT: This procedure is not tested with internation data (Extended characters or Unicode). If needed
-- you might want to Convert the datatypes of character variables in this procedure to their respective unicode counterparts
-- like nchar and nvarchar
--
-- Example 1: To generate INSERT statements for table 'titles':
--
-- EXEC INFGenerateInserts 'titles'
--
-- Example 2: To ommit the column list in the INSERT statement: (Column list is included by default)
-- IMPORTANT: If you have too many columns, you are advised to ommit column list, as shown below,
-- to avoid erroneous results
--
-- EXEC INFGenerateInserts 'titles', @include_column_list = 0
--
-- Example 3: To generate INSERT statements for 'titlesCopy' table from 'titles' table:
--
-- EXEC INFGenerateInserts 'titles', 'titlesCopy'
--
-- Example 4: To generate INSERT statements for 'titles' table for only those titles
-- which contain the word 'Computer' in them:
-- NOTE: Do not complicate the FROM or WHERE clause here. It's assumed that you are good with T-SQL if you are using this parameter
--
-- EXEC INFGenerateInserts 'titles', @from = "from titles where title like '%Computer%'"
--
-- Example 5: To specify that you want to include TIMESTAMP column's data as well in the INSERT statement:
-- (By default TIMESTAMP column's data is not scripted)
--
-- EXEC INFGenerateInserts 'titles', @include_timestamp = 1
--
-- Example 6: To print the debug information:
--
-- EXEC INFGenerateInserts 'titles', @debug_mode = 1
--
-- Example 7: If you are not the owner of the table, use @owner parameter to specify the owner name
-- To use this option, you must have SELECT permissions on that table
--
-- EXEC INFGenerateInserts Nickstable, @owner = 'Nick'
--
-- Example 8: To generate INSERT statements for the rest of the columns excluding images
-- When using this otion, DO NOT set @include_column_list parameter to 0.
--
-- EXEC INFGenerateInserts imgtable, @ommit_images = 1
--
-- Example 9: To generate INSERT statements excluding (ommiting) IDENTITY columns:
-- (By default IDENTITY columns are included in the INSERT statement)
--
-- EXEC INFGenerateInserts mytable, @ommit_identity = 1
--
-- Example 10: To generate INSERT statements for the TOP 10 rows in the table:
--
-- EXEC INFGenerateInserts mytable, @top = 10
--
-- Example 11: To generate INSERT statements with only those columns you want:
--
-- EXEC INFGenerateInserts titles, @cols_to_include = "'title','title_id','au_id'"
--
-- Example 12: To generate INSERT statements by omitting certain columns:
--
-- EXEC INFGenerateInserts titles, @cols_to_exclude = "'title','title_id','au_id'"
--
-- Example 13: To avoid checking the foreign key constraints while loading data with INSERT statements:
--
-- EXEC INFGenerateInserts titles, @disable_constraints = 1
--
-- Example 14: To exclude computed columns from the INSERT statement:
-- EXEC INFGenerateInserts MyTable, @ommit_computed_cols = 1
-- ***********************************************************************************************************
ALTER PROC [dbo].[INFGenerateInserts]
(
@table_name varchar(776), -- The table/view for which the INSERT statements will be generated using the existing data
@target_table varchar(776) = NULL, -- Use this parameter to specify a different table name into which the data will be inserted
@include_column_list bit = 1, -- Use this parameter to include/ommit column list in the generated INSERT statement
@from varchar(800) = NULL, -- Use this parameter to filter the rows based on a filter condition (using WHERE)
@include_timestamp bit = 0, -- Specify 1 for this parameter, if you want to include the TIMESTAMP/ROWVERSION column's data in the INSERT statement
@debug_mode bit = 0, -- If @debug_mode is set to 1, the SQL statements constructed by this procedure will be printed for later examination
@owner varchar(64) = NULL, -- Use this parameter if you are not the owner of the table
@ommit_images bit = 0, -- Use this parameter to generate INSERT statements by omitting the 'image' columns
@ommit_identity bit = 0, -- Use this parameter to ommit the identity columns
@top int = NULL, -- Use this parameter to generate INSERT statements only for the TOP n rows
@cols_to_include varchar(8000) = NULL, -- List of columns to be included in the INSERT statement
@cols_to_exclude varchar(8000) = NULL, -- List of columns to be excluded from the INSERT statement
@disable_constraints bit = 0, -- When 1, disables foreign key constraints and enables them after the INSERT statements
@ommit_computed_cols bit = 0 -- When 1, computed columns will not be included in the INSERT statement
)
AS
BEGIN
SET NOCOUNT ON
--Making sure user only uses either @cols_to_include or @cols_to_exclude
IF ((@cols_to_include IS NOT NULL) AND (@cols_to_exclude IS NOT NULL))
BEGIN
RAISERROR('Use either @cols_to_include or @cols_to_exclude. Do not use both the parameters at once',16,1)
RETURN -1 --Failure. Reason: Both @cols_to_include and @cols_to_exclude parameters are specified
END
--END IF
--Making sure the @cols_to_include and @cols_to_exclude parameters are receiving values in proper format
IF ((@cols_to_include IS NOT NULL) AND (PatIndex('''%''',@cols_to_include) = 0))
BEGIN
RAISERROR('Invalid use of @cols_to_include property',16,1)
--PRINT 'Specify column names surrounded by single quotes and separated by commas'
--PRINT 'Eg: EXEC INFGenerateInserts titles, @cols_to_include = "''title_id'',''title''"'
RETURN -1 --Failure. Reason: Invalid use of @cols_to_include property
END
--END IF
IF ((@cols_to_exclude IS NOT NULL) AND (PatIndex('''%''',@cols_to_exclude) = 0))
BEGIN
RAISERROR('Invalid use of @cols_to_exclude property',16,1)
--PRINT 'Specify column names surrounded by single quotes and separated by commas'
--PRINT 'Eg: EXEC INFGenerateInserts titles, @cols_to_exclude = "''title_id'',''title''"'
RETURN -1 --Failure. Reason: Invalid use of @cols_to_exclude property
END
--END IF
--Checking to see if the database name is specified along wih the table name
--Your database context should be local to the table for which you want to generate INSERT statements
--specifying the database name is not allowed
IF (ParseName(@table_name,3)) IS NOT NULL
BEGIN
RAISERROR('Do not specify the database name. Be in the required database and just specify the table name.',16,1)
RETURN -1 --Failure. Reason: Database name is specified along with the table name, which is not allowed
END
--END IF
--Checking for the existence of 'user table' or 'view'
--This procedure is not written to work on system tables
--To script the data in system tables, just create a view on the system tables and script the view instead
IF @owner IS NULL
BEGIN
IF ((Object_Id(@table_name,'U') IS NULL) AND (Object_Id(@table_name,'V') IS NULL))
BEGIN
RAISERROR('User table or view not found.',16,1)
--PRINT 'You may see this error, if you are not the owner of this table or view. In that case use @owner parameter to specify the owner name.'
--PRINT 'Make sure you have SELECT permission on that table or view.'
RETURN -1 --Failure. Reason: There is no user table or view with this name
END
--END IF
END
ELSE
BEGIN
IF NOT EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = @table_name AND (TABLE_TYPE = 'BASE TABLE' OR TABLE_TYPE = 'VIEW') AND TABLE_SCHEMA = @owner)
BEGIN
RAISERROR('User table or view not found.',16,1)
--PRINT 'You may see this error, if you are not the owner of this table. In that case use @owner parameter to specify the owner name.'
--PRINT 'Make sure you have SELECT permission on that table or view.'
RETURN -1 --Failure. Reason: There is no user table or view with this name
END
--END IF
END
--Variable declarations
DECLARE @Column_ID int,
@Column_List varchar(8000),
@Column_Name varchar(128),
@Start_Insert varchar(786),
@Data_Type varchar(128),
@Actual_Values varchar(8000), --This is the string that will be finally executed to generate INSERT statements
@IDN varchar(128) --Will contain the IDENTITY column's name in the table
--Variable Initialization
SET @IDN = ''
SET @Column_ID = 0
SET @Column_Name = ''
SET @Column_List = ''
SET @Actual_Values = ''
IF @owner IS NULL
BEGIN
SET @Start_Insert = 'INSERT INTO ' + '[' + RTrim(Coalesce(@target_table,@table_name)) + ']'
END
ELSE
BEGIN
SET @Start_Insert = 'INSERT ' + '[' + LTrim(RTrim(@owner)) + '].' + '[' + RTrim(Coalesce(@target_table,@table_name)) + ']'
END
--END IF
--To get the first column's ID
SELECT @Column_ID = Min(ORDINAL_POSITION)
FROM INFORMATION_SCHEMA.COLUMNS WITH (NOLOCK)
WHERE TABLE_NAME = @table_name
AND (@owner IS NULL
OR TABLE_SCHEMA = @owner)
--Loop through all the columns of the table, to get the column names and their data types
WHILE @Column_ID IS NOT NULL
BEGIN
SELECT @Column_Name = QuoteName(COLUMN_NAME),
@Data_Type = DATA_TYPE
FROM INFORMATION_SCHEMA.COLUMNS WITH (NOLOCK)
WHERE ORDINAL_POSITION = @Column_ID
AND TABLE_NAME = @table_name
AND (@owner IS NULL
OR TABLE_SCHEMA = @owner)
IF @cols_to_include IS NOT NULL --Selecting only user specified columns
BEGIN
IF CharIndex( '''' + Substring(@Column_Name,2,Len(@Column_Name)-2) + '''',@cols_to_include) = 0
BEGIN
GOTO SKIP_LOOP
END
END
--END IF
IF @cols_to_exclude IS NOT NULL --Selecting only user specified columns
BEGIN
IF CharIndex( '''' + Substring(@Column_Name, 2, Len(@Column_Name) - 2) + '''', @cols_to_exclude) <> 0
BEGIN
GOTO SKIP_LOOP
END
END
--END IF
--Making sure to output SET IDENTITY_INSERT ON/OFF in case the table has an IDENTITY column
IF (SELECT ColumnProperty(Object_Id(QuoteName(Coalesce(@owner, User_Name())) + '.' + @table_name), Substring(@Column_Name, 2, Len(@Column_Name) - 2), 'IsIdentity')) = 1
BEGIN
IF @ommit_identity = 0 --Determing whether to include or exclude the IDENTITY column
SET @IDN = @Column_Name
ELSE
GOTO SKIP_LOOP
END
--END IF
--Making sure whether to output computed columns or not
IF @ommit_computed_cols = 1
BEGIN
IF (SELECT ColumnProperty(Object_Id(QuoteName(Coalesce(@owner, User_Name())) + '.' + @table_name), Substring(@Column_Name, 2, Len(@Column_Name) - 2), 'IsComputed')) = 1
BEGIN
GOTO SKIP_LOOP
END
END
--END IF
--Tables with columns of IMAGE data type are not supported for obvious reasons
IF(@Data_Type IN ('image'))
BEGIN
IF (@ommit_images = 0)
BEGIN
RAISERROR('Tables with image columns are not supported.',16,1)
--PRINT 'Use @ommit_images = 1 parameter to generate INSERTs for the rest of the columns.'
--PRINT 'DO NOT ommit Column List in the INSERT statements. If you ommit column list using @include_column_list=0, the generated INSERTs will fail.'
RETURN -1 --Failure. Reason: There is a column with image data type
END
ELSE
BEGIN
GOTO SKIP_LOOP
END
--END IF
END
--END IF
-- Determining the data type of the column and depending on the data type, the VALUES part of
-- the INSERT statement is generated. Care is taken to handle columns with NULL values. Also
-- making sure, not to lose any data from flot, real, money, smallmomey, datetime columns
SET @Actual_Values = @Actual_Values +
CASE
WHEN @Data_Type IN ('char','varchar','nchar','nvarchar')
THEN
'Coalesce('''''''' + Replace(' + @Column_Name + ','''''''','''''''''''')+'''''''',''NULL'')'
WHEN @Data_Type IN ('date', 'datetime','datetime2','smalldatetime')
THEN
'Coalesce('''''''' + RTrim(Convert(char,' + @Column_Name + ',109))+'''''''',''NULL'')'
WHEN @Data_Type IN ('uniqueidentifier')
THEN
'Coalesce('''''''' + Replace(Convert(char(255),RTrim(' + @Column_Name + ')),'''''''','''''''''''')+'''''''',''NULL'')'
WHEN @Data_Type IN ('text','ntext')
THEN
'Coalesce('''''''' + Replace(Convert(char(8000),' + @Column_Name + '),'''''''','''''''''''')+'''''''',''NULL'')'
WHEN @Data_Type IN ('binary','varbinary')
THEN
'Coalesce(RTrim(Convert(char,' + 'Convert(int,' + @Column_Name + '))),''NULL'')'
WHEN @Data_Type IN ('timestamp','rowversion')
THEN
CASE
WHEN @include_timestamp = 0 THEN '''DEFAULT'''
ELSE
'Coalesce(RTrim(Convert(char,' + 'Convert(int,' + @Column_Name + '))),''NULL'')'
END
WHEN @Data_Type IN ('float','real','money','smallmoney')
THEN
'Coalesce(LTrim(RTrim(' + 'Convert(char, ' + @Column_Name + ',2)' + ')),''NULL'')'
ELSE
'Coalesce(LTrim(RTrim(' + 'Convert(char, ' + @Column_Name + ')' + ')),''NULL'')'
END + '+' + ''',''' + ' + '
--END SET
--Generating the column list for the INSERT statement
SET @Column_List = @Column_List + @Column_Name + ','
SKIP_LOOP: --The label used in GOTO
SELECT @Column_ID = Min(ORDINAL_POSITION)
FROM INFORMATION_SCHEMA.COLUMNS WITH (NOLOCK)
WHERE TABLE_NAME = @table_name
AND ORDINAL_POSITION > @Column_ID
AND (@owner IS NULL
OR TABLE_SCHEMA = @owner)
--Loop ends here!
END
--END WHILE
--To get rid of the extra characters that got concatenated during the last run through the loop
SET @Column_List = LEFT(@Column_List, Len(@Column_List) - 1)
SET @Actual_Values = LEFT(@Actual_Values, Len(@Actual_Values) - 6)
IF LTrim(@Column_List) = ''
BEGIN
RAISERROR('No columns to select. There should at least be one column to generate the output',16,1)
RETURN -1 --Failure. Reason: Looks like all the columns are ommitted using the @cols_to_exclude parameter
END
--END IF
--Forming the final string that will be executed, to output the INSERT statements
IF (@include_column_list <> 0)
BEGIN
SET @Actual_Values =
'SELECT ' +
CASE WHEN @top IS NULL OR @top < 0 THEN ''
ELSE ' TOP ' + LTrim(Str(@top)) + ' '
END +
'''' + RTrim(@Start_Insert) +
' ''+' + '''(' + RTrim(@Column_List) + '''+' + ''')''' +
' +''VALUES(''+ ' + @Actual_Values + '+'')''' + ' ' +
Coalesce(@from,' FROM ' +
CASE WHEN @owner IS NULL THEN ''
ELSE '[' + LTrim(RTrim(@owner)) + '].'
END + '[' + RTrim(@table_name) + ']' + 'WITH (NOLOCK)')
END
ELSE IF (@include_column_list = 0)
BEGIN
SET @Actual_Values =
'SELECT ' +
CASE WHEN @top IS NULL OR @top < 0 THEN ''
ELSE ' TOP ' + LTrim(Str(@top)) + ' '
END +
'''' + RTrim(@Start_Insert) +
' '' +''VALUES(''+ ' + @Actual_Values + '+'')''' + ' ' +
Coalesce(@from,' FROM ' +
CASE WHEN @owner IS NULL THEN ''
ELSE '[' + LTrim(RTrim(@owner)) + '].'
END + '[' + RTrim(@table_name) + ']' + 'WITH (NOLOCK)')
END
--END IF
--Determining whether to ouput any debug information
IF @debug_mode =1
BEGIN
PRINT '/*****START OF DEBUG INFORMATION*****'
PRINT 'Beginning of the INSERT statement:'
PRINT @Start_Insert
PRINT ''
PRINT 'The column list:'
PRINT @Column_List
PRINT ''
PRINT 'The SELECT statement executed to generate the INSERTs'
PRINT @Actual_Values
PRINT ''
PRINT '*****END OF DEBUG INFORMATION*****/'
PRINT ''
END
--END IF
PRINT ''
PRINT 'SET NOCOUNT ON'
PRINT ''
--Determining whether to print IDENTITY_INSERT or not
IF (@IDN <> '')
BEGIN
PRINT 'SET IDENTITY_INSERT ' + QuoteName(Coalesce(@owner,User_Name())) + '.' + QuoteName(@table_name) + ' ON'
PRINT 'GO'
PRINT ''
END
--END IF
IF @disable_constraints = 1 AND (Object_Id(QuoteName(Coalesce(@owner,User_Name())) + '.' + @table_name, 'U') IS NOT NULL)
BEGIN
IF @owner IS NULL
BEGIN
SELECT 'ALTER TABLE ' + QuoteName(Coalesce(@target_table, @table_name)) + ' NOCHECK CONSTRAINT ALL' AS '--Code to disable constraints temporarily'
END
ELSE
BEGIN
SELECT 'ALTER TABLE ' + QuoteName(@owner) + '.' + QuoteName(Coalesce(@target_table, @table_name)) + ' NOCHECK CONSTRAINT ALL' AS '--Code to disable constraints temporarily'
END
PRINT 'GO'
END
--END IF
PRINT ''
PRINT 'PRINT ''Inserting values into ' + '[' + RTrim(Coalesce(@target_table,@table_name)) + ']' + ''''
CREATE TABLE #temp
(
x varchar(Max)
)
INSERT INTO #temp
EXEC (@Actual_Values)
DECLARE myCursor CURSOR FOR
SELECT x FROM #temp
--All the hard work pays off here!!! You'll get your INSERT statements, when the next line executes!
DECLARE @InsertLine varchar(Max)
OPEN myCursor
FETCH NEXT
FROM myCursor
INTO @InsertLine
WHILE @@Fetch_Status = 0
BEGIN
PRINT @InsertLine
FETCH NEXT
FROM myCursor
INTO @InsertLine
END
--END WHILE
-- Close and deallocate the cursor
CLOSE myCursor
DEALLOCATE myCursor
DROP TABLE #temp
-- PRINT '-- Done'
PRINT ''
IF @disable_constraints = 1 AND (Object_Id(QuoteName(Coalesce(@owner,User_Name())) + '.' + @table_name, 'U') IS NOT NULL)
BEGIN
IF @owner IS NULL
BEGIN
--SELECT 'ALTER TABLE ' + QuoteName(Coalesce(@target_table, @table_name)) + ' CHECK CONSTRAINT ALL' AS '--Code to enable the previously disabled constraints'
PRINT 'ALTER TABLE ' + QuoteName(Coalesce(@target_table, @table_name)) + ' CHECK CONSTRAINT ALL' --AS '--Code to enable the previously disabled constraints'
END
ELSE
BEGIN
--SELECT 'ALTER TABLE ' + QuoteName(@owner) + '.' + QuoteName(Coalesce(@target_table, @table_name)) + ' CHECK CONSTRAINT ALL' AS '--Code to enable the previously disabled constraints'
PRINT 'ALTER TABLE ' + QuoteName(@owner) + '.' + QuoteName(Coalesce(@target_table, @table_name)) + ' CHECK CONSTRAINT ALL' --AS '--Code to enable the previously disabled constraints'
END
PRINT 'GO'
END
--END IF
PRINT ''
IF (@IDN <> '')
BEGIN
PRINT 'SET IDENTITY_INSERT ' + QuoteName(Coalesce(@owner,User_Name())) + '.' + QuoteName(@table_name) + ' OFF'
PRINT 'GO'
PRINT 'DBCC CHECKIDENT (' + QuoteName(@table_name) + ', RESEED)'
PRINT 'GO'
END
--END IF
PRINT 'SET NOCOUNT OFF'
SET NOCOUNT OFF
RETURN 0 --Success. We are done!
END
GO
May 5, 2023 at 12:49 pm
Thanks all for the replies...
The second server in this case is on an environment that is essentially an exact snapshot of our production environment, which is taken over the weekend. Only the IP range is different. However, because of this, it's prevented from communicating directly with our production environment. I can access it via RDP but even that is over two steps - I RDP into a bridge server, then from there RDP into the SQL box. Any other communication is blocked by firewall magic.
So anything that requires a direct link, or even a shared folder, gets blocked.
The database in question is too big to do the backup/restore unfortunately.
Jonathan's proc seems very promising - I tried it and it works great, except that one of the number columns is just slightly off from when I use the script that SSRS generates. It's a float column, so probably just need to tweak how it's handling float.
May 5, 2023 at 1:17 pm
The second server in this case is on an environment that is essentially an exact snapshot of our production environment, which is taken over the weekend.
I'm totally confused now... It sounds to me that that table you're talking about is updated weekly. Why would you need to overwrite it on a monthly basis? Is the table in question not a part of the "production environment"?
--Jeff Moden
Change is inevitable... Change for the better is not.
May 5, 2023 at 3:30 pm
The table in question is truncated and repopulated in the production environment at the end of each month. It contains data that is compiled in other systems; the exact date and time varies month to month depending on the workloads in various departments, etc. The process of populating the table is somewhat involved, and has to take place in the production environment.
The table is basically the input for a larger process.
We run that process in test first, to make sure that everything works as expected, because backing out changes to multiple systems would be very time consuming, and because the process sends all sort of emails and other notifications to people - these are essentially trapped because the test environment cannot send anything outside of itself.
So, the results are vetted in the test environment; and once we get notification that everything looks good, we run the exact same process in production.
It's a process that I inherited. I know it sounds awfully convoluted, and it is... and I'm slowly reengineering it so that we can do everything including the test run in production; but for now I'm kind of stuck with what we have.
I decided to simplify my original post because the only relevant part was needing to move the contents of a single table ;D
May 5, 2023 at 4:20 pm
how big is the table?
if only a few thousand rows then a script with insert statements would likely work fine as mentioned before.
but for anything with volumes BCP or powershell outputting to a true CSV file are likely better options.
whatever situation you are in you still need to transfer a file from server A to B - multiple hops from what you stated, but when on the Bridge server you should have access to shares on both the Left and Right side of the firewall.
May 5, 2023 at 5:15 pm
The table is usually between 1500-3000 rows, so not big at all. It's fairly simple to just cut and paste an INSERT from SSMS.
I was just trying to avoid those incredibly strenuous mouse-clicks in the SSRS wizard :b
I think that at least for now, the procedure Jonathan provided will work just fine. I may actually try doing BCP via the bridge server just for fun, though.
May 5, 2023 at 5:24 pm
how big is the table?
if only a few thousand rows then a script with insert statements would likely work fine as mentioned before.
but for anything with volumes BCP or powershell outputting to a true CSV file are likely better options.
whatever situation you are in you still need to transfer a file from server A to B - multiple hops from what you stated, but when on the Bridge server you should have access to shares on both the Left and Right side of the firewall.
Just a suggestion...
If it's SQL Server to SQL Server, use the "Native" format. It's much faster, uses much smaller data, and has none of the problems associated with any CSV.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply