Important alert: (current site time 9/21/2014 5:46:35 AM EDT)
 

VB icon

Calculating the Mode, Mean and Median of a dataset

Email
Submitted on: 2/5/2002 8:09:56 PM
By: James Travis  
Level: Intermediate
User Rating: By 7 Users
Compatibility: SQL Server 7.0
Views: 10326
author picture
(About the author)
 
     To get the mode, mean and median of a queired dataset.
 
code:
Can't Copy and Paste this?
Click here for a copy-and-paste friendly version of this code!
 
Terms of Agreement:   
By using this code, you agree to the following terms...   
  1. You may use this code in your own programs (and may compile it into a program and distribute it in compiled format for languages that allow it) freely and with no charge.
  2. You MAY NOT redistribute this code (for example to a web site) without written permission from the original author. Failure to do so is a violation of copyright laws.   
  3. You may link to this code from another website, but ONLY if it is not wrapped in a frame. 
  4. You will abide by any additional copyright restrictions which the author may have placed in the code or code's description.
				
--**************************************
-- Name: Calculating the Mode, Mean and Median of a dataset
-- Description:To get the mode, mean and median of a queired dataset.
-- By: James Travis
--
-- Assumes:Note: you can put these in subqueries that you can join back to the overall dataset if you want to identify or output in conjunction with other data.
--
--This code is copyrighted and has-- limited warranties.Please see http://www.Planet-Source-Code.com/vb/scripts/ShowCode.asp?txtCodeId=400&lngWId=5--for details.--**************************************

-- MODE
SELECT [id] AS MODE FROM tblHA GROUP BY [id] HAVING COUNT(*) = (
SELECT MAX(CNT) AS MaxCNT FROM (
SELECT count(*) AS CNT FROM tblHa GROUP BY [id]) AS base)
-- MEAN
SELECT AVG(CAST([id] AS FLOAT)) AS MEAN FROM tblHA
--MEDIAN
DECLARE @cnt INT
DECLARE @fpos INT
DECLARE @output FLOAT
DECLARE @SQLState VARCHAR(200)
SELECT @cnt = COUNT(*) FROM tblHa
IF ( @cnt % 2 ) = 0
BEGIN
	SET @fpos = @cnt / 2
	SELECT @output = avg(cast([id] as float)) FROM (
				SELECT (select count(*) + 1 from tblHa b where b.[id] < a.[id]) AS ROW, a.[id] FROM tblHa a
			) AS Built
	WHERE ROW IN (@fpos, @fpos + 1)
END
ELSE
BEGIN
	SET @fpos = ( ( ( @cnt - 1 ) / 2 ) + 1 )
	SELECT @output = [id] FROM (
				SELECT (select count(*) + 1 from tblHa b where b.[id] < a.[id]) AS ROW, a.[id] FROM tblHa a
			) AS Built
	WHERE ROW = @fpos
END
SELECT @output AS MEDIAN


Other 20 submission(s) by this author

 


Report Bad Submission
Use this form to tell us if this entry should be deleted (i.e contains no code, is a virus, etc.).
This submission should be removed because:

Your Vote

What do you think of this code (in the Intermediate category)?
(The code with your highest vote will win this month's coding contest!)
Excellent  Good  Average  Below Average  Poor (See voting log ...)
 

Other User Comments

4/2/2004 8:27:25 AMmohamedz

I thought it was good, there seems to be a problem if there are repeated values in the index.
(If this comment was disrespectful, please report it.)

 

Add Your Feedback
Your feedback will be posted below and an email sent to the author. Please remember that the author was kind enough to share this with you, so any criticisms must be stated politely, or they will be deleted. (For feedback not related to this particular code, please click here instead.)
 

To post feedback, first please login.