Snitz Forums 2000
Snitz Forums 2000
Home | Profile | Register | Active Topics | Members | Search | FAQ
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 Help Groups for Snitz Forums 2000 Users
 Help: Database: MS SQL Server
 Borderline Emergency, need manual archive / delete
 New Topic  Topic Locked
 Printer Friendly
Author Previous Topic Topic Next Topic  

Comicozzi
Starting Member

49 Posts

Posted - 16 May 2006 :  09:25:12  Show Profile
I am running 3.4.05

Stats:
You last visited on 05/16/2006 07:34:05 AM
3059 of 4464 Members have made 102372 posts in 1 forum, with the last post on 05/16/2006 08:25:36 AM by: Win3855.
There are currently 8804 topics and 8 active topics since you last visited.
There are 77119 archived posts in 8557 archived topics
Please welcome our newest member: Dude.
-------------------------

I help a guy with his forums and there are some screwy items going on, not matter how I try to clean up and delete or archive, I continously get timeouts. I have try to expand the timeout everywhere it makes since with no success. IS there a snippet of code I can get my hands on to archive then delete or just delete anthing older than a year then archive anything older than 6 months?

I am using SQL 2000 and IIS 6.0 on two different boxes. Is the timeout closing at the boxes talking to eachother? I have updated my timeouts and still see no increase in time alloted to the archive / delete times.. still always get a timeout at admin_forum.asp

As you can tell, maintenence on the forums has been neglected.

Any help is appreciated.

Here is the message:
----------------------
Microsoft OLE DB Provider for SQL Server error '80004005'

Timeout expired

/admin_forums.asp, line 489
--------------------------

laser
Advanced Member

Australia
3859 Posts

Posted - 16 May 2006 :  09:33:00  Show Profile
Try to archive in smaller slices, or just retry, retry, retry ... it's not the best way but if the page times out there's not much you can do, and it could timeout because there's just too much data to archive.

I used to have this problem, but I just archive more regularly now, but to get to my current position I had to do a lot of smaller archiving "bites"
Go to Top of Page

Comicozzi
Starting Member

49 Posts

Posted - 16 May 2006 :  09:34:17  Show Profile
I have been trying to do the "slices" but it still no success... just too big.

Anyone else with any ideas? it is appreciated
Go to Top of Page

ruirib
Snitz Forums Admin

Portugal
26364 Posts

Posted - 16 May 2006 :  09:38:12  Show Profile  Send ruirib a Yahoo! Message
You can try this script: http://forum.snitz.com/forum/topic.asp?ARCHIVE=true&TOPIC_ID=47702&SearchTerms=archive

Beware that you need to adjust the SQL to your own table structure.


Snitz 3.4 Readme | Like the support? Support Snitz too
Go to Top of Page

Comicozzi
Starting Member

49 Posts

Posted - 17 May 2006 :  07:56:31  Show Profile
thank you, I will check it out.
Go to Top of Page

Comicozzi
Starting Member

49 Posts

Posted - 17 May 2006 :  09:25:00  Show Profile
I am getting an error when running the script... line 18, says invalid object....
I am going to see if I can wade through it or research more.
Go to Top of Page

ruirib
Snitz Forums Admin

Portugal
26364 Posts

Posted - 17 May 2006 :  09:26:32  Show Profile  Send ruirib a Yahoo! Message
What's line 18?


Snitz 3.4 Readme | Like the support? Support Snitz too
Go to Top of Page

Comicozzi
Starting Member

49 Posts

Posted - 17 May 2006 :  09:42:26  Show Profile
---------------------------------------------
Here is the error:
Server: Msg 208, Level 16, State 1, Line 18
Invalid object name 'FORUM_TOPICS'.
Server: Msg 208, Level 16, State 1, Line 18
Invalid object name 'FORUM_REPLY'.
-----------------------------------
Seems strange to me as this is a very vanilla snitz install, any help is appreciated. I am not a skilled debugger.

Edited by - Comicozzi on 17 May 2006 09:44:18
Go to Top of Page

Comicozzi
Starting Member

49 Posts

Posted - 17 May 2006 :  09:43:45  Show Profile
DECLARE
	@ArchiveDate nvarchar(14),
	@ArchiveForumID int

SET
	@ArchiveDate = '20050517000000'  -- Date to archive from (YYYYMMDDHHMMSS)
SET
	@ArchiveForumID = 2  -- Forum ID to Archive


-- Create temp table that will hold TOPIC_ID's to archive
CREATE TABLE #TOPIC_IDs
(
	TOPIC_ID int
)

-- Fill temp table with TOPIC_ID's to archive
INSERT INTO
	#TOPIC_IDs
-- Query finds topics started (and edited) before archive date
SELECT
	TOPIC_ID
FROM
	FORUM_TOPICS AS FT
WHERE
	T_DATE < @ArchiveDate
AND
	-- If no last edit date (NULL), return lowest date possible
	ISNULL(T_LAST_EDIT,'00000000000000') < @ArchiveDate
	
AND
	FORUM_ID = @ArchiveForumID
AND
	-- Subquery to determine if any replies (or edits) are 
	--  AFTER the archive date.  If so, do not archive topic.
	(SELECT
		COUNT(*)
	FROM
		FORUM_REPLY AS FR
	WHERE
		(R_DATE >= @ArchiveDate
		OR
		-- If no last edit date (NULL), return lowest date possible
		ISNULL(R_LAST_EDIT,'00000000000000') >= @ArchiveDate)
	AND
		FR.TOPIC_ID = FT.TOPIC_ID
	) = 0


-- Copy TOPIC's to archive table
INSERT INTO
	FORUM_A_TOPICS
	(CAT_ID,
	FORUM_ID,
	TOPIC_ID,
	T_STATUS,
	T_MAIL,
	T_SUBJECT,
	T_MESSAGE,
	T_AUTHOR,
	T_REPLIES,
	T_UREPLIES,
	T_VIEW_COUNT,
	T_LAST_POST,
	T_DATE,
	T_LAST_POSTER,
	T_IP,
	T_LAST_POST_AUTHOR,
	T_LAST_POST_REPLY_ID,
	T_ARCHIVE_FLAG,
	T_LAST_EDIT,
	T_LAST_EDITBY,
	T_STICKY,
	T_SIG)
SELECT
	CAT_ID,
	FORUM_ID,
	TOPIC_ID,
	0,
	T_MAIL,
	T_SUBJECT,
	T_MESSAGE,
	T_AUTHOR,
	T_REPLIES,
	T_UREPLIES,
	T_VIEW_COUNT,
	T_LAST_POST,
	T_DATE,
	T_LAST_POSTER,
	T_IP,
	T_LAST_POST_AUTHOR,
	T_LAST_POST_REPLY_ID,
	T_ARCHIVE_FLAG,
	T_LAST_EDIT,
	T_LAST_EDITBY,
	T_STICKY,
	T_SIG
FROM
	FORUM_TOPICS
WHERE
	TOPIC_ID
	IN
	(SELECT
		TOPIC_ID
	FROM
		#TOPIC_IDs)


-- Copy REPLY's to archive table
INSERT INTO
	FORUM_A_REPLY
	(CAT_ID,
	FORUM_ID,
	TOPIC_ID,
	REPLY_ID,
	R_MAIL,
	R_AUTHOR,
	R_MESSAGE,
	R_DATE,
	R_IP,
	R_STATUS,
	R_LAST_EDIT,
	R_LAST_EDITBY,
	R_SIG)
SELECT
	CAT_ID,
	FORUM_ID,
	TOPIC_ID,
	REPLY_ID,
	R_MAIL,
	R_AUTHOR,
	R_MESSAGE,
	R_DATE,
	R_IP,
	R_STATUS,
	R_LAST_EDIT,
	R_LAST_EDITBY,
	R_SIG
FROM
	FORUM_REPLY
WHERE
	TOPIC_ID
	IN
	(SELECT
		TOPIC_ID
	FROM
		#TOPIC_IDs)

-- Delete TOPIC's from main table
DELETE
FROM
	FORUM_TOPICS
WHERE
	TOPIC_ID
	IN
	(SELECT
		TOPIC_ID
	FROM
		#TOPIC_IDs)

-- Delete REPLY's from main table
DELETE
FROM
	FORUM_REPLY
WHERE
	TOPIC_ID
	IN
	(SELECT
		TOPIC_ID
	FROM
		#TOPIC_IDs)

DROP TABLE #TOPIC_IDs

-- Update FORUM_TOTALS Counts
UPDATE
	FORUM_TOTALS
SET
	P_COUNT = (
		SELECT
			COUNT(*)
		FROM
			FORUM_REPLY
		),
	P_A_COUNT = (
		SELECT
			COUNT(*)
		FROM
			FORUM_A_REPLY
		),
	T_COUNT = (
		SELECT
			COUNT(*)
		FROM
			FORUM_TOPICS
		),
	T_A_COUNT = (
		SELECT
			COUNT(*)
		FROM
			FORUM_A_TOPICS
		)

-- Update Specific Forum Counts
UPDATE
	FORUM_FORUM
SET
	F_TOPICS = (
		SELECT
			COUNT(*)
		FROM
			FORUM_TOPICS
		WHERE
			FORUM_ID = @ArchiveForumID
		),
	F_COUNT = (
		SELECT
			COUNT(*)
		FROM
			FORUM_REPLY
		WHERE
			FORUM_ID = @ArchiveForumID
		),
	F_A_TOPICS = (
		SELECT
			COUNT(*)
		FROM
			FORUM_A_TOPICS
		WHERE
			FORUM_ID = @ArchiveForumID
		),
	F_A_COUNT = (
		SELECT
			COUNT(*)
		FROM
			FORUM_A_REPLY
		WHERE
			FORUM_ID = @ArchiveForumID
		)
WHERE
	FORUM_ID = @ArchiveForumID
								

GO
Go to Top of Page

ruirib
Snitz Forums Admin

Portugal
26364 Posts

Posted - 17 May 2006 :  09:57:12  Show Profile  Send ruirib a Yahoo! Message
Who's the owner of your tables?


Snitz 3.4 Readme | Like the support? Support Snitz too
Go to Top of Page

Comicozzi
Starting Member

49 Posts

Posted - 17 May 2006 :  09:58:53  Show Profile
sa I believe, if not, another name....
Go to Top of Page

Comicozzi
Starting Member

49 Posts

Posted - 17 May 2006 :  09:59:55  Show Profile
Do I need to change it on the live DB or run this script in another fashion? I am connecting and querying as the SA on a remote session on the actual server..

two users, SA and another one, are listed as public and owner as the only items

Edited by - Comicozzi on 17 May 2006 10:01:11
Go to Top of Page

ruirib
Snitz Forums Admin

Portugal
26364 Posts

Posted - 17 May 2006 :  10:01:45  Show Profile  Send ruirib a Yahoo! Message
You'd need to check who is the actual table owner. It should show in Enterprise Manager something.Forum_topics...
The something is the owner...


Snitz 3.4 Readme | Like the support? Support Snitz too
Go to Top of Page

Comicozzi
Starting Member

49 Posts

Posted - 17 May 2006 :  10:04:07  Show Profile
yes, its a name, not SA, XXXXX.forum.topics
I logged into query analyzer with SA account, should I login as the XXXXXX name and then run it?

I apperciate your help, I am sure that you have better use for your time than babysitting this puke.
Go to Top of Page

Comicozzi
Starting Member

49 Posts

Posted - 17 May 2006 :  10:05:50  Show Profile
scratch that, i logged in as the XXXXX user and it did fine. Thank you very much
Go to Top of Page

ruirib
Snitz Forums Admin

Portugal
26364 Posts

Posted - 17 May 2006 :  11:23:05  Show Profile  Send ruirib a Yahoo! Message
Glad you made it.


Snitz 3.4 Readme | Like the support? Support Snitz too
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Topic Locked
 Printer Friendly
Jump To:
Snitz Forums 2000 © 2000-2021 Snitz™ Communications Go To Top Of Page
This page was generated in 0.23 seconds. Powered By: Snitz Forums 2000 Version 3.4.07