Collation error

I am unable to update the Original post below are the executed scripts

---- LIST ALL THE COLLATION OF TABLES

 USE UserDB
    GO
    SELECT s.name as 'Schema_Name', t.name as Table_Name,
    c.name AS Column_Name,
    c.collation_name AS Collation
    FROM sys.schemas s
    INNER JOIN sys.tables t
    ON t.schema_id = s.schema_id
    INNER JOIN sys.columns c
    ON c.object_id = t.object_id
    WHERE collation_name is not null
    ORDER BY Column_Name

---CHANGE COLLATION WILL CHANGE THE MAXIUM COLLATION SOME REMAIN SO FIX MANUAL BY NEXT METHOD

CREATE PROCEDURE CHANGE_COLLATION
    AS
    BEGIN
    DECLARE @collate nvarchar(100);
    declare @schema nvarchar(255);
    DECLARE @table nvarchar(255);
    DECLARE @column_name nvarchar(255);
    DECLARE @column_id int;
    DECLARE @data_type nvarchar(255);
    DECLARE @max_length varchar(100);
    DECLARE @row_id int;
    DECLARE @sql nvarchar(max);
    DECLARE @sql_column nvarchar(max);

    SET @collate = 'SQL_Latin1_General_CP1_CS_AS';

    DECLARE tbl_cursor CURSOR FOR SELECT (s.[name])schemaName, (o.[name])[tableName]
    FROM sysobjects sy 
    INNER JOIN sys.objects  o on o.name = sy.name
    INNER JOIN sys.schemas s ON o.schema_id = s.schema_id
    WHERE OBJECTPROPERTY(sy.id, N'IsUserTable') = 1

    OPEN tbl_cursor FETCH NEXT FROM tbl_cursor INTO @schema,@table

    WHILE @@FETCH_STATUS = 0
    BEGIN
        DECLARE tbl_cursor_changed CURSOR FOR
            SELECT ROW_NUMBER() OVER (ORDER BY c.column_id) AS row_id
                , c.name column_name
                , t.Name data_type
                , c.max_length
                , c.column_id
            FROM sys.columns c
            JOIN sys.types t ON c.system_type_id = t.system_type_id
            LEFT OUTER JOIN sys.index_columns ic ON ic.object_id = c.object_id AND ic.column_id = c.column_id
            LEFT OUTER JOIN sys.indexes i ON ic.object_id = i.object_id AND ic.index_id = i.index_id
        WHERE c.object_id like OBJECT_ID(@schema+'.'+@table)
        ORDER BY c.column_id


        OPEN tbl_cursor_changed 
         FETCH NEXT FROM tbl_cursor_changed
        INTO @row_id, @column_name, @data_type, @max_length, @column_id



        WHILE @@FETCH_STATUS = 0
        BEGIN
        IF (@max_length = -1) SET @max_length = 'MAX';
            IF (@data_type LIKE '%char%')
            BEGIN TRY
                SET @sql = 'ALTER TABLE ' +@schema+'.'+ @table + ' ALTER COLUMN ' + @column_name + ' ' + @data_type + '(' + CAST(@max_length AS nvarchar(100)) + ') COLLATE ' + @collate
                print @sql
                EXEC sp_executesql @sql
            END TRY
            BEGIN CATCH
              PRINT 'ERROR:'
              PRINT @sql
            END CATCH

            FETCH NEXT FROM tbl_cursor_changed
            INTO @row_id, @column_name, @data_type, @max_length, @column_id

        END

        CLOSE tbl_cursor_changed
        DEALLOCATE tbl_cursor_changed

        FETCH NEXT FROM tbl_cursor
        INTO @schema, @table

    END

    CLOSE tbl_cursor
    DEALLOCATE tbl_cursor

    PRINT 'Collation For All Tables Done!'
    END

    EXEC  CHANGE_COLLATION

---Some collation does not changed due to contraint so i already changed by using Alter statement
checking more which collation of the column other then the default collation
--- MAKE A SCRIPT TO ALL THE TABLES COLUMNS WHICH SHOWS THE NOT IN 'SQL_Latin1_General_CP1_CS_AS' COLLATION

CREATE procedure test2 
as
DECLARE @collate SYSNAME
SELECT @collate = 'SQL_Latin1_General_CP1_CS_AS'

SELECT 
  '[' + SCHEMA_NAME(o.[schema_id]) + '].[' + o.name + '] -> ' + c.name
, 'ALTER TABLE [' + SCHEMA_NAME(o.[schema_id]) + '].[' + o.name + ']
    ALTER COLUMN [' + c.name + '] ' +
    UPPER(t.name) + 
    CASE WHEN t.name NOT IN ('ntext', 'text') 
        THEN '(' + 
            CASE 
                WHEN t.name IN ('nchar', 'nvarchar') AND c.max_length != -1 
                    THEN CAST(c.max_length / 2 AS VARCHAR(10))
                WHEN t.name IN ('char', 'varchar') AND c.max_length != -1 
                    THEN CAST(c.max_length AS VARCHAR(10))
                WHEN t.name IN ('nchar', 'nvarchar', 'char', 'varchar') AND c.max_length = -1 
                    THEN 'MAX'
                ELSE CAST(c.max_length AS VARCHAR(10)) 
            END + ')' 
        ELSE '' 
    END + ' COLLATE ' + @collate + 
    CASE WHEN c.is_nullable = 1 
        THEN ' NULL'
        ELSE ' NOT NULL'
    END
FROM sys.columns c WITH(NOLOCK)
    JOIN sys.objects o WITH(NOLOCK) ON c.[object_id] = o.[object_id]
    JOIN sys.types t WITH(NOLOCK) ON c.system_type_id = t.system_type_id AND c.user_type_id = t.user_type_id
WHERE t.name IN ('char', 'varchar', 'text', 'nvarchar', 'ntext', 'nchar')
    AND c.collation_name != @collate
    AND o.[type] = 'U'

	exec test2

Manual collation change by Alter command

ALTER TABLE [dbo].[RESULTS]
DROP CONSTRAINT [CONSTRAINT_RESULTS]
GO
ALTER TABLE [dbo].[RESULTS]      ALTER COLUMN [Column_1] VARCHAR(10) COLLATE SQL_Latin1_General_CP1_CS_AS NOT NULL
GO
ALTER TABLE [dbo].[RESULTS] ADD  CONSTRAINT [CONSTRAINT_RESULTS] PRIMARY KEY CLUSTERED 
(
	[Column_1] ASC,
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
GO